Newer
Older
$PostgreSQL: pgsql/doc/src/sgml/ref/create_table.sgml,v 1.116 2009/09/18 05:00:41 petere Exp $
Thomas G. Lockhart
committed
PostgreSQL documentation
<refentry id="SQL-CREATETABLE">
<refmeta>
<refentrytitle id="sql-createtable-title">CREATE TABLE</refentrytitle>
<manvolnum>7</manvolnum>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
Peter Eisentraut
committed
Peter Eisentraut
committed
<refname>CREATE TABLE</refname>
<refpurpose>define a new table</refpurpose>
</refnamediv>
Peter Eisentraut
committed
<indexterm zone="sql-createtable">
<primary>CREATE TABLE</primary>
</indexterm>
Peter Eisentraut
committed
<synopsis>
CREATE [ [ GLOBAL | 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> ] [ <replaceable class="PARAMETER">column_constraint</replaceable> [ ... ] ]
| <replaceable>table_constraint</replaceable>
| LIKE <replaceable>parent_table</replaceable> [ { INCLUDING | EXCLUDING } { DEFAULTS | CONSTRAINTS | INDEXES } ] ... }
Peter Eisentraut
committed
[ INHERITS ( <replaceable>parent_table</replaceable> [, ... ] ) ]
[ WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] ) | WITH OIDS | WITHOUT OIDS ]
[ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ]
[ TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable> ]
Peter Eisentraut
committed
<phrase>where <replaceable class="PARAMETER">column_constraint</replaceable> is:</phrase>
Peter Eisentraut
committed
[ CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> ]
UNIQUE <replaceable class="PARAMETER">index_parameters</replaceable> |
PRIMARY KEY <replaceable class="PARAMETER">index_parameters</replaceable> |
CHECK ( <replaceable class="PARAMETER">expression</replaceable> ) |
REFERENCES <replaceable class="PARAMETER">reftable</replaceable> [ ( <replaceable class="PARAMETER">refcolumn</replaceable> ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ]
Peter Eisentraut
committed
[ ON DELETE <replaceable class="parameter">action</replaceable> ] [ ON UPDATE <replaceable class="parameter">action</replaceable> ] }
[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
<phrase>and <replaceable class="PARAMETER">table_constraint</replaceable> is:</phrase>
[ CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> ]
{ UNIQUE ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) <replaceable class="PARAMETER">index_parameters</replaceable> |
PRIMARY KEY ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] ) <replaceable class="PARAMETER">index_parameters</replaceable> |
Peter Eisentraut
committed
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 | MATCH SIMPLE ] [ ON DELETE <replaceable class="parameter">action</replaceable> ] [ ON UPDATE <replaceable class="parameter">action</replaceable> ] }
Peter Eisentraut
committed
[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
<phrase><replaceable class="PARAMETER">index_parameters</replaceable> in <literal>UNIQUE</literal> and <literal>PRIMARY KEY</literal> constraints are:</phrase>
[ WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] ) ]
[ USING INDEX TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable> ]
Peter Eisentraut
committed
</synopsis>
Peter Eisentraut
committed
<refsect1 id="SQL-CREATETABLE-description">
<title>Description</title>
Peter Eisentraut
committed
<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
</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. Temporary
tables exist in a special schema, so a schema name cannot be given
when creating a temporary table. The name of the table must be
distinct from the name of any other table, sequence, index, or view
in the same schema.
Peter Eisentraut
committed
<command>CREATE TABLE</command> also automatically creates a data
type that represents the composite type corresponding
Peter Eisentraut
committed
to one row of the table. Therefore, tables cannot have the same
name as any existing data type in the same schema.
</para>
<para>
The optional constraint clauses specify constraints (tests) that
Peter Eisentraut
committed
new or updated rows must satisfy for an insert or update operation
to succeed. A constraint is an SQL object that helps define the
set of valid values in the table in various ways.
</para>
Peter Eisentraut
committed
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 for use when the
Peter Eisentraut
committed
constraint only affects one column.
</para>
</refsect1>
Peter Eisentraut
committed
<refsect1>
<title>Parameters</title>
Peter Eisentraut
committed
<variablelist>
Peter Eisentraut
committed
<varlistentry>
<term><literal>TEMPORARY</> or <literal>TEMP</></term>
Peter Eisentraut
committed
<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 <literal>ON COMMIT</literal> 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.
Peter Eisentraut
committed
</para>
Peter Eisentraut
committed
<para>
Optionally, <literal>GLOBAL</literal> or <literal>LOCAL</literal>
can be written before <literal>TEMPORARY</> or <literal>TEMP</>.
This makes no difference in <productname>PostgreSQL</>, but see
Peter Eisentraut
committed
<xref linkend="sql-createtable-compatibility"
endterm="sql-createtable-compatibility-title">.
</para>
</listitem>
</varlistentry>
Peter Eisentraut
committed
<varlistentry>
<term><replaceable class="PARAMETER">table_name</replaceable></term>
<listitem>
<para>
The name (optionally schema-qualified) of the table to be created.
Peter Eisentraut
committed
</para>
</listitem>
</varlistentry>
Peter Eisentraut
committed
<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>
Peter Eisentraut
committed
<varlistentry>
<term><replaceable class="PARAMETER">data_type</replaceable></term>
<listitem>
<para>
The data type of the column. This can include array
specifiers. For more information on the data types supported by
<productname>PostgreSQL</productname>, refer to <xref
linkend="datatype">.
Peter Eisentraut
committed
</para>
</listitem>
</varlistentry>
Peter Eisentraut
committed
<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 (subqueries and cross-references
Peter Eisentraut
committed
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>
Peter Eisentraut
committed
<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.
Peter Eisentraut
committed
</para>
</listitem>
</varlistentry>
Peter Eisentraut
committed
<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.
</para>
<para>
Use of <literal>INHERITS</> creates a persistent relationship
between the new child table and its parent table(s). Schema
modifications to the parent(s) normally propagate to children
as well, and by default the data of the child table is included in
scans of the parent(s).
</para>
<para>
If the same column name exists in more than one parent
Peter Eisentraut
committed
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 name that is also inherited, the data type must
Peter Eisentraut
committed
likewise match the inherited column(s), and the column
definitions are merged into one. If the
Peter Eisentraut
committed
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>
<literal>CHECK</> constraints are merged in essentially the same way as
columns: if multiple parent tables and/or the new table definition
contain identically-named <literal>CHECK</> constraints, these
constraints must all have the same check expression, or an error will be
reported. Constraints having the same name and expression will
be merged into one copy. Notice that an unnamed <literal>CHECK</>
constraint in the new table will never be merged, since a unique name
will always be chosen for it.
</para>
Peter Eisentraut
committed
<!--
<para>
<productname>PostgreSQL</> automatically allows the
Thomas G. Lockhart
committed
created table to inherit
Peter Eisentraut
committed
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>
<term><literal>LIKE <replaceable>parent_table</replaceable> [ { INCLUDING | EXCLUDING } { DEFAULTS | CONSTRAINTS | INDEXES } ]</literal></term>
<listitem>
<para>
The <literal>LIKE</literal> clause specifies a table from which
the new table automatically copies all column names, their data types,
and their not-null constraints.
</para>
<para>
Unlike <literal>INHERITS</literal>, the new table and original table
are completely decoupled after creation is complete. Changes to the
original table will not be applied to the new table, and it is not
possible to include data of the new table in scans of the original
table.
</para>
<para>
Default expressions for the copied column definitions will only be
copied if <literal>INCLUDING DEFAULTS</literal> is specified. The
default behavior is to exclude default expressions, resulting in the
copied columns in the new table having null defaults.
Not-null constraints are always copied to the new table.
<literal>CHECK</literal> constraints will only be copied if
<literal>INCLUDING CONSTRAINTS</literal> is specified; other types of
constraints will never be copied. Also, no distinction is made between
column constraints and table constraints — when constraints are
requested, all check constraints are copied.
<para>
Any indexes on the original table will not be created on the new
table, unless the <literal>INCLUDING INDEXES</literal> clause is
specified.
</para>
Note also that unlike <literal>INHERITS</literal>, copied columns and
constraints are not merged with similarly named columns and constraints.
If the same name is specified explicitly or in another
<literal>LIKE</literal> clause, an error is signalled.
Peter Eisentraut
committed
<term><literal>CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable></literal></term>
<listitem>
<para>
An optional name for a column or table constraint. If the
constraint is violated, the constraint name is present in error messages,
so constraint names like <literal>col must be positive</> can be used
to communicate helpful constraint information to client applications.
(Double-quotes are needed to specify constraint names that contain spaces.)
If a constraint name is not specified, the system generates a name.
Peter Eisentraut
committed
</para>
</listitem>
</varlistentry>
Peter Eisentraut
committed
<varlistentry>
<term><literal>NOT NULL</></term>
<listitem>
<para>
The column is not allowed to contain null values.
Peter Eisentraut
committed
</para>
</listitem>
</varlistentry>
Peter Eisentraut
committed
<varlistentry>
<term><literal>NULL</></term>
<listitem>
<para>
The column is allowed to contain null values. This is the default.
Peter Eisentraut
committed
</para>
Peter Eisentraut
committed
<para>
This clause is only provided for compatibility with
Peter Eisentraut
committed
non-standard SQL databases. Its use is discouraged in new
applications.
</para>
</listitem>
</varlistentry>
Peter Eisentraut
committed
<varlistentry>
<term><literal>UNIQUE</> (column constraint)</term>
<term><literal>UNIQUE ( <replaceable class="PARAMETER">column_name</replaceable> [, ... ] )</> (table constraint)</term>
Peter Eisentraut
committed
<listitem>
<para>
The <literal>UNIQUE</literal> constraint specifies that a
group of one or more columns of a table can contain
Peter Eisentraut
committed
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>
Peter Eisentraut
committed
<para>
For the purpose of a unique constraint, null values are not
Peter Eisentraut
committed
considered equal.
</para>
Peter Eisentraut
committed
<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>
Peter Eisentraut
committed
<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
can contain only unique (non-duplicate), nonnull values.
Peter Eisentraut
committed
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
metadata about the design of the schema, as a primary key
Peter Eisentraut
committed
implies that other tables
can rely on this set of columns as a unique identifier for rows.
Peter Eisentraut
committed
</para>
Peter Eisentraut
committed
<para>
Only one primary key can be specified for a table, whether as a
column constraint or a table constraint.
</para>
Peter Eisentraut
committed
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.
Peter Eisentraut
committed
</listitem>
</varlistentry>
Peter Eisentraut
committed
<varlistentry>
<term><literal>CHECK ( <replaceable class="PARAMETER">expression</replaceable> )</literal></term>
Peter Eisentraut
committed
<listitem>
<para>
The <literal>CHECK</> clause specifies an expression producing a
Boolean result which new or updated rows must satisfy for an
insert or update operation to succeed. Expressions evaluating
to TRUE or UNKNOWN succeed. Should any row of an insert or
update operation produce a FALSE result an error exception is
raised and the insert or update does not alter the database. A
check constraint specified as a column constraint should
reference that column's value only, while an expression
appearing in a table constraint can reference multiple columns.
Peter Eisentraut
committed
</para>
Peter Eisentraut
committed
<para>
Currently, <literal>CHECK</literal> expressions cannot contain
subqueries nor refer to variables other than columns of the
Peter Eisentraut
committed
current row.
</para>
</listitem>
</varlistentry>
Peter Eisentraut
committed
<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>
Peter Eisentraut
committed
<term><literal>FOREIGN KEY ( <replaceable class="parameter">column</replaceable> [, ... ] )
REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> [, ... ] ) ]
Peter Eisentraut
committed
[ MATCH <replaceable class="parameter">matchtype</replaceable> ]
[ ON DELETE <replaceable class="parameter">action</replaceable> ]
Peter Eisentraut
committed
[ ON UPDATE <replaceable class="parameter">action</replaceable> ]</literal>
(table constraint)</term>
Peter Eisentraut
committed
<listitem>
<para>
These clauses specify a foreign key constraint, which requires
Peter Eisentraut
committed
that a group of one or more columns of the new table must only
contain values that match values in the referenced
column(s) of some row of the referenced table. If <replaceable
Peter Eisentraut
committed
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 non-deferrable
unique or primary key constraint in the referenced table. Note that
foreign key constraints cannot be defined between temporary tables and
permanent tables.
Peter Eisentraut
committed
</para>
Peter Eisentraut
committed
<para>
A value inserted into the referencing column(s) 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 <literal>MATCH
SIMPLE</literal>, which is also the default. <literal>MATCH
FULL</> will not allow one column of a multicolumn foreign key
to be null unless all foreign key columns are null.
<literal>MATCH SIMPLE</literal> 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.
Peter Eisentraut
committed
</para>
Peter Eisentraut
committed
<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 perform when a referenced row in the referenced table is
Peter Eisentraut
committed
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. Referential actions other than the
<literal>NO ACTION</literal> check cannot be deferred, even if
the constraint is declared deferrable. There are the following possible
Peter Eisentraut
committed
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.
If the constraint is deferred, this
error will be produced at constraint check time if there still
exist any referencing rows. This is the default action.
Peter Eisentraut
committed
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>RESTRICT</literal></term>
<listitem>
<para>
Produce an error indicating that the deletion or update
would create a foreign key constraint violation.
This is the same as <literal>NO ACTION</literal> except that
Peter Eisentraut
committed
</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(s) to null.
Peter Eisentraut
committed
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>SET DEFAULT</literal></term>
<listitem>
<para>
Set the referencing column(s) to their default values.
Peter Eisentraut
committed
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
<para>
If the referenced column(s) are changed frequently, it might be wise to
add an index to the foreign key column so that referential actions
associated with the foreign key column can be performed more
efficiently.
</para>
Peter Eisentraut
committed
</listitem>
</varlistentry>
Peter Eisentraut
committed
<varlistentry>
<term><literal>DEFERRABLE</literal></term>
<term><literal>NOT DEFERRABLE</literal></term>
Peter Eisentraut
committed
<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 can 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.
Currently, only <literal>UNIQUE</>, <literal>PRIMARY KEY</>, and
<literal>REFERENCES</> (foreign key) constraints accept this
clause. <literal>NOT NULL</> and <literal>CHECK</> constraints are not
deferrable.
Peter Eisentraut
committed
</para>
</listitem>
</varlistentry>
Peter Eisentraut
committed
<varlistentry>
<term><literal>INITIALLY IMMEDIATE</literal></term>
<term><literal>INITIALLY DEFERRED</literal></term>
Peter Eisentraut
committed
<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.
Peter Eisentraut
committed
</para>
</listitem>
</varlistentry>
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
<varlistentry>
<term><literal>WITH ( <replaceable class="PARAMETER">storage_parameter</replaceable> [= <replaceable class="PARAMETER">value</replaceable>] [, ... ] )</literal></term>
<listitem>
<para>
This clause specifies optional storage parameters for a table or index;
see <xref linkend="sql-createtable-storage-parameters"
endterm="sql-createtable-storage-parameters-title"> for more
information. The <literal>WITH</> clause for a
table can also include <literal>OIDS=TRUE</> (or just <literal>OIDS</>)
to specify that rows of the new table
should have OIDs (object identifiers) assigned to them, or
<literal>OIDS=FALSE</> to specify that the rows should not have OIDs.
If <literal>OIDS</> is not specified, the default setting depends upon
the <xref linkend="guc-default-with-oids"> configuration parameter.
(If the new table inherits from any tables that have OIDs, then
<literal>OIDS=TRUE</> is forced even if the command says
<literal>OIDS=FALSE</>.)
</para>
<para>
If <literal>OIDS=FALSE</literal> is specified or implied, the new
table does not store OIDs and no OID will be assigned for a row inserted
into it. This is generally considered worthwhile, since it
will reduce OID consumption and thereby postpone the wraparound
of the 32-bit OID counter. Once the counter wraps around, OIDs
can no longer be assumed to be unique, which makes them
considerably less useful. In addition, excluding OIDs from a
table reduces the space required to store the table on disk by
4 bytes per row (on most machines), slightly improving performance.
</para>
<para>
To remove OIDs from a table after it has been created, use <xref
linkend="sql-altertable" endterm="sql-altertable-title">.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>WITH OIDS</></term>
<term><literal>WITHOUT OIDS</></term>
<listitem>
<para>
These are obsolescent syntaxes equivalent to <literal>WITH (OIDS)</>
and <literal>WITH (OIDS=FALSE)</>, respectively. If you wish to give
both an <literal>OIDS</> setting and storage parameters, you must use
the <literal>WITH ( ... )</> syntax; see above.
</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" endterm="sql-truncate-title"> 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>
<varlistentry>
<term><literal>TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable></literal></term>
<listitem>
<para>
The <replaceable class="PARAMETER">tablespace</replaceable> is the name
of the tablespace in which the new table is to be created.
If not specified,
<xref linkend="guc-default-tablespace"> is consulted, or
<xref linkend="guc-temp-tablespaces"> if the table is temporary.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>USING INDEX TABLESPACE <replaceable class="PARAMETER">tablespace</replaceable></literal></term>
<listitem>
<para>
This clause allows selection of the tablespace in which the index
associated with a <literal>UNIQUE</literal> or <literal>PRIMARY
KEY</literal> constraint will be created.
If not specified,
<xref linkend="guc-default-tablespace"> is consulted, or
<xref linkend="guc-temp-tablespaces"> if the table is temporary.
</para>
</listitem>
</varlistentry>
</variablelist>
<refsect2 id="SQL-CREATETABLE-storage-parameters">
<title id="SQL-CREATETABLE-storage-parameters-title">Storage Parameters</title>
<indexterm zone="sql-createtable-storage-parameters">
<primary>storage parameters</primary>
</indexterm>
<para>
The <literal>WITH</> clause can specify <firstterm>storage parameters</>
for tables, and for indexes associated with a <literal>UNIQUE</literal> or
<literal>PRIMARY KEY</literal> constraint. Storage parameters for
indexes are documented in <xref linkend="SQL-CREATEINDEX"
endterm="sql-createindex-title">. The storage parameters currently
available for tables are listed below. For each parameter, there is an
additional, identically named parameter, prefixed with
<literal>toast.</literal> which can be used to control the behavior of the
supplementary storage table, if any; see <xref linkend="storage-toast">.
Note that the supplementary storage table inherits the
<literal>autovacuum</literal> values from its parent table, if there are
no <literal>toast.autovacuum_*</literal> settings set.
</para>
<variablelist>
<varlistentry>
<term><literal>fillfactor</>, <literal>toast.fillfactor</literal> (<type>integer</>)</term>
<listitem>
<para>
The fillfactor for a table is a percentage between 10 and 100.
100 (complete packing) is the default. When a smaller fillfactor
is specified, <command>INSERT</> operations pack table pages only
to the indicated percentage; the remaining space on each page is
reserved for updating rows on that page. This gives <command>UPDATE</>
a chance to place the updated copy of a row on the same page as the
original, which is more efficient than placing it on a different page.
For a table whose entries are never updated, complete packing is the
best choice, but in heavily updated tables smaller fillfactors are
appropriate.
</para>
</listitem>
</varlistentry>
<varlistentry>
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
<term><literal>autovacuum_enabled</>, <literal>toast.autovacuum_enabled</literal> (<type>boolean</>)</term>
<listitem>
<para>
Enables or disables the autovacuum daemon on a particular table.
If true, the autovacuum daemon will initiate a <command>VACUUM</> operation
on a particular table when the number of updated or deleted tuples exceeds
<literal>autovacuum_vacuum_threshold</> plus
<literal>autovacuum_vacuum_scale_factor</> times the number of live tuples
currently estimated to be in the relation.
Similarly, it will initiate an <command>ANALYZE</> operation when the
number of inserted, updated or deleted tuples exceeds
<literal>autovacuum_analyze_threshold</> plus
<literal>autovacuum_analyze_scale_factor</> times the number of live tuples
currently estimated to be in the relation.
If false, this table will not be autovacuumed, except to prevent
transaction Id wraparound. See <xref linkend="vacuum-for-wraparound"> for
more about wraparound prevention.
Observe that this variable inherits its value from the <xref
linkend="guc-autovacuum"> setting.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>autovacuum_vacuum_threshold</>, <literal>toast.autovacuum_vacuum_threshold</literal> (<type>integer</>)</term>
<listitem>
<para>
Minimum number of updated or deleted tuples before initiate a
<command>VACUUM</> operation on a particular table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>autovacuum_vacuum_scale_factor</>, <literal>toast.autovacuum_vacuum_scale_factor</literal> (<type>float4</>)</term>
<listitem>
<para>
Multiplier for <structfield>reltuples</> to add to
<literal>autovacuum_vacuum_threshold</>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>autovacuum_analyze_threshold</>, <literal>toast.autovacuum_analyze_threshold</literal> (<type>integer</>)</term>
<listitem>
<para>
Minimum number of inserted, updated, or deleted tuples before initiate an
<command>ANALYZE</> operation on a particular table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>autovacuum_analyze_scale_factor</>, <literal>toast.autovacuum_analyze_scale_factor</literal> (<type>float4</>)</term>
<listitem>
<para>
Multiplier for <structfield>reltuples</> to add to
<literal>autovacuum_analyze_threshold</>.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>autovacuum_vacuum_cost_delay</>, <literal>toast.autovacuum_vacuum_cost_delay</literal> (<type>integer</>)</term>
<listitem>
<para>
Custom <xref linkend="guc-autovacuum-vacuum-cost-delay"> parameter.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>autovacuum_vacuum_cost_limit</>, <literal>toast.autovacuum_vacuum_cost_limit</literal> (<type>integer</>)</term>
<listitem>
<para>
Custom <xref linkend="guc-autovacuum-vacuum-cost-limit"> parameter.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>autovacuum_freeze_min_age</>, <literal>toast.autovacuum_freeze_min_age</literal> (<type>integer</>)</term>
<listitem>
<para>
Custom <xref linkend="guc-vacuum-freeze-min-age"> parameter. Note that
autovacuum will ignore attempts to set a per-table
<literal>autovacuum_freeze_min_age</> larger than the half system-wide
<xref linkend="guc-autovacuum-freeze-max-age"> setting.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>autovacuum_freeze_max_age</>, <literal>toast.autovacuum_freeze_max_age</literal> (<type>integer</>)</term>
<listitem>
<para>
Custom <xref linkend="guc-autovacuum-freeze-max-age"> parameter. Note that
autovacuum will ignore attempts to set a per-table
<literal>autovacuum_freeze_max_age</> larger than the system-wide setting
(it can only be set smaller). Note that while you can set
<literal>autovacuum_freeze_max_age</> very small, or even zero, this is
usually unwise since it will force frequent vacuuming.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>autovacuum_freeze_table_age</literal> (<type>integer</type>)</term>
<listitem>
<para>
Custom <xref linkend="guc-vacuum-freeze-table-age"> parameter.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect2>
</refsect1>
Peter Eisentraut
committed
<refsect1 id="SQL-CREATETABLE-notes">
<title>Notes</title>
Using OIDs in new applications is not recommended: where
possible, using a <literal>SERIAL</literal> or other sequence
generator as the table's primary key is preferred. However, if
your application does make use of OIDs to identify specific
Peter Eisentraut
committed
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.
</para>
Peter Eisentraut
committed
<tip>
<para>
The use of <literal>OIDS=FALSE</literal> is not recommended
Peter Eisentraut
committed
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>
Peter Eisentraut
committed
<productname>PostgreSQL</productname> automatically creates an
index for each unique constraint and primary key constraint to
enforce uniqueness. Thus, it is not necessary to create an
index explicitly for primary key columns. (See <xref
linkend="sql-createindex" endterm="sql-createindex-title"> for more information.)
Peter Eisentraut
committed
Unique constraints and primary keys are not inherited in the
current implementation. This makes the combination of
inheritance and unique constraints rather dysfunctional.
<para>
A table cannot have more than 1600 columns. (In practice, the
effective limit is usually lower because of tuple-length constraints.)
</para>
Peter Eisentraut
committed
</refsect1>
Peter Eisentraut
committed
<refsect1 id="SQL-CREATETABLE-examples">
<title>Examples</title>
Peter Eisentraut
committed
Create table <structname>films</> and table
<structname>distributors</>:
Peter Eisentraut
committed
<programlisting>
CREATE TABLE films (
code char(5) CONSTRAINT firstkey PRIMARY KEY,
title varchar(40) NOT NULL,
did integer NOT NULL,
date_prod date,
kind varchar(10),
len interval hour to minute
Peter Eisentraut
committed
</programlisting>
Peter Eisentraut
committed
<programlisting>
CREATE TABLE distributors (
did integer PRIMARY KEY DEFAULT nextval('serial'),
name varchar(40) NOT NULL CHECK (name <> '')
Peter Eisentraut
committed
</programlisting>
<para>
Create a table with a 2-dimensional array:
Peter Eisentraut
committed
<programlisting>
CREATE TABLE array_int (
Peter Eisentraut
committed
);
</programlisting>
Define a unique table constraint for the table
<literal>films</literal>. Unique table constraints can be defined
on one or more columns of the table:
Peter Eisentraut
committed
<programlisting>
CREATE TABLE films (
code char(5),
title varchar(40),
did integer,
date_prod date,
kind varchar(10),
len interval hour to minute,
CONSTRAINT production UNIQUE(date_prod)
);
Peter Eisentraut
committed
</programlisting>
Peter Eisentraut
committed
Define a check column constraint:
Peter Eisentraut
committed
<programlisting>
CREATE TABLE distributors (
Peter Eisentraut
committed
</programlisting>
Peter Eisentraut
committed
Define a check table constraint:
Peter Eisentraut
committed
<programlisting>
CREATE TABLE distributors (
CONSTRAINT con1 CHECK (did > 100 AND name <> '')
Peter Eisentraut
committed
</programlisting>
Peter Eisentraut
committed
Define a primary key table constraint for the table
<structname>films</>:
Peter Eisentraut
committed
<programlisting>
CREATE TABLE films (
code char(5),
title varchar(40),
did integer,
date_prod date,
kind varchar(10),
len interval hour to minute,
CONSTRAINT code_title PRIMARY KEY(code,title)
);
Peter Eisentraut
committed
</programlisting>
Peter Eisentraut
committed
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 syntax:
Peter Eisentraut
committed
<programlisting>
CREATE TABLE distributors (