diff --git a/doc/src/sgml/ref/alter_table.sgml b/doc/src/sgml/ref/alter_table.sgml
index f5ac58705b..5907a64a6b 100644
--- a/doc/src/sgml/ref/alter_table.sgml
+++ b/doc/src/sgml/ref/alter_table.sgml
@@ -1,5 +1,5 @@
@@ -161,15 +161,14 @@ ALTER TABLE table
ALTER TABLE changes the definition of an existing table.
The ADD COLUMN form adds a new column to the table
- using the same syntax as .
+ using the same syntax as .
The ALTER COLUMN SET/DROP DEFAULT forms
allow you to set or remove the default for the column. Note that defaults
only apply to subsequent INSERT commands; they do not
cause rows already in the table to change.
The ALTER COLUMN SET STATISTICS form allows you to
set the statistics-gathering target for subsequent
- operations.
+ operations.
The RENAME clause causes the name of a table or column
to change without changing any of the data contained in
the affected table. Thus, the table or column will
@@ -177,7 +176,7 @@ ALTER TABLE table
executed.
The ADD table constraint definition clause
adds a new constraint to the table using the same syntax as .
+ linkend="SQL-CREATETABLE">.
The DROP CONSTRAINT constraint clause
drops all CHECK constraints on the table (and its children) that match constraint.
The OWNER clause changes the owner of the table to the user
@@ -205,18 +204,17 @@ ALTER TABLE table
You can use the SET DEFAULT form
of ALTER TABLE to set the default later.
(You may also want to update the already existing rows to the
- new default value, using .)
+ new default value, using .)
Currently only CHECK constraints can be dropped from a table. The RESTRICT
keyword is required, although dependencies are not checked. The CASCADE
option is unsupported. To remove a PRIMARY or UNIQUE constraint, drop the
- relevant index using the command.
+ relevant index using the command.
To remove FOREIGN KEY constraints you need to recreate
and reload the table, using other parameters to the
-
+
command.
diff --git a/doc/src/sgml/ref/create_table.sgml b/doc/src/sgml/ref/create_table.sgml
index 49bb05ea13..8607f895df 100644
--- a/doc/src/sgml/ref/create_table.sgml
+++ b/doc/src/sgml/ref/create_table.sgml
@@ -1,1976 +1,822 @@
-
- CREATE TABLE
-
+ CREATE TABLE
SQL - Language Statements
+
-
- CREATE TABLE
-
-
- define a new table
-
+ CREATE TABLE
+ define a new table
+
-
- 2001-01-11
-
-
-CREATE [ TEMPORARY | TEMP ] TABLE table_name (
- { column_name type [ column_constraint [ ... ] ]
- | table_constraint } [, ... ] )
- [ INHERITS ( parent_table [, ... ] ) ]
- [ WITH OIDS | WITHOUT OIDS ]
+
+CREATE [ [ LOCAL ] { TEMPORARY | TEMP } ] TABLE table_name (
+ { column_name data_type [ DEFAULT default_expr> ] [ column_constraint [, ... ] ]
+ | table_constraint } [, ... ]
+)
+[ INHERITS ( parent_table [, ... ] ) ]
+[ WITH OIDS | WITHOUT OIDS ]
+
+where column_constraint is:
-where column_constraint can be:
[ CONSTRAINT constraint_name ]
-{ NOT NULL | NULL | UNIQUE | PRIMARY KEY | DEFAULT value | CHECK (condition) |
- REFERENCES table [ ( column ) ] [ MATCH FULL | MATCH PARTIAL ]
- [ ON DELETE action ] [ ON UPDATE action ]
- [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
-}
+{ NOT NULL | NULL | UNIQUE | PRIMARY KEY |
+ CHECK (expression) |
+ REFERENCES reftable [ ( refcolumn ) ] [ MATCH FULL | MATCH PARTIAL ]
+ [ ON DELETE action ] [ ON UPDATE action ] }
+[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
+
+and table_constraint is:
-and table_constraint can be:
[ CONSTRAINT constraint_name ]
{ UNIQUE ( column_name [, ... ] ) |
PRIMARY KEY ( column_name [, ... ] ) |
- CHECK ( condition ) |
- FOREIGN KEY ( column_name [, ... ] ) REFERENCES table [ ( column [, ... ] ) ]
- [ MATCH FULL | MATCH PARTIAL ] [ ON DELETE action ] [ ON UPDATE action ]
- [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
-}
-
+ CHECK ( expression ) |
+ FOREIGN KEY ( column_name [, ... ] ) REFERENCES reftable [ ( refcolumn [, ... ] ) ]
+ [ MATCH FULL | MATCH PARTIAL ] [ ON DELETE action ] [ ON UPDATE action ] }
+[ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
+
-
-
- Inputs
-
-
-
-
-
-
- TEMPORARY or TEMP
-
-
- If specified, 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
- (in this session) while the temporary table exists.
- Any indexes created on a temporary table are automatically
- temporary as well.
-
-
-
-
-
- table_name
-
-
- The name of the new table to be created.
-
-
-
-
-
- column_name
-
-
- The name of a column to be created in the new table.
-
-
-
-
-
- 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.
-
-
-
-
-
- parent_table
-
-
- The optional INHERITS clause specifies a list of table
- names from which this table automatically inherits all fields.
-
-
-
-
-
- WITH OIDS or WITHOUT OIDS
-
-
- This optional clause specifies whether rows of the new table should
- have OIDs (object identifiers) assigned to them. The default is
- WITH OIDS. (If the new table inherits from any tables that have OIDs,
- then WITH OIDS is forced even if the command says WITHOUT OIDS.)
-
-
-
-
-
- constraint_name
-
-
- An optional name for a column or table constraint. If not specified,
- the system generates a name.
-
-
-
-
-
- value
-
-
- A default value for a column.
- See the DEFAULT clause for more information.
-
-
-
-
-
- condition
-
-
- 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.
-
-
-
-
-
- table
-
-
- The name of an existing table to be referenced by a foreign
- key constraint.
-
-
-
-
-
- column
-
-
- The name of a column in an existing table to be referenced by a
- foreign key constraint. If not specified, the primary key of
- the existing table is assumed.
-
-
-
-
-
- action
-
-
- A keyword indicating the action to take when a foreign key
- constraint is violated.
-
-
-
-
-
-
-
-
-
- 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.
-
-
-
-
-
-
-
-
- Description
-
+
+ Description
- CREATE TABLE will enter a new, initially empty table
- into the current database. The table will be owned by the user issuing the
+ CREATE TABLE will create a new, initially empty table
+ in the current database. 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
- .
+ CREATE TABLE 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.
-
-
- Consistent array dimensions within an
- attribute are not enforced. This will likely change in a future
- release.
-
-
+ A table cannot have 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.
- CREATE TABLE also automatically creates a data type
- that represents the tuple type (structure type) corresponding to one
- row of the table. Therefore, tables can't have the same name as any
- existing datatype.
+ 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.
- 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.
+ 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.
-
-
- INHERITS Clause
-
-
-
-INHERITS ( parent_table [, ... ] )
-
-
+
+ Parameters
-
- The optional INHERITS
- clause specifies a list of table names from which the new table
- automatically inherits all fields. If the same field name appears in
- more than one parent table, Postgres reports an error unless the field
- definitions match in each of the parent tables. If there is no
- definition conflict, then the duplicate fields are merged to form a single
- field of the new table. If the new table's own field list contains a
- field name that is also inherited, this declaration must likewise match
- the inherited field(s), and the field definitions are merged into one.
-
+
-
- Inherited and new field declarations of the same name must specify exactly
- the same data type to avoid an error. They 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 field, this default overrides any
- defaults from inherited declarations of the field. Otherwise, any parents
- that specify default values for the field must all specify the same
- default, or an error will be reported.
-
-
-
- Postgres automatically allows the created table to inherit functions on
- tables above it in the inheritance hierarchy; that is, if we create table
- foo inheriting from bar, then
- functions that accept the tuple type bar can also be
- applied to instances of foo. (Currently, this works
- reliably for functions on the first or only parent table, but not so well
- for functions on additional parents.)
-
-
-
-
-
- OIDS Clause
-
-
-
- WITH OIDS | WITHOUT OIDS
-
-
-
-
- This clause controls whether an OID (object ID) is generated and assigned
- to each row inserted into the table. The default is WITH OIDS.
- Specifying 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.
-
-
-
- Whenever an application makes use of OIDs to identify specific rows of
- a table, it is recommended that you create a unique index on OID for
- that table, to ensure that OIDs in the table will indeed uniquely
- identify rows even after counter wraparound. (An index on OID is needed
- anyway for fast lookup of rows by OID.) Avoid assuming that OIDs are
- unique across tables --- if you need a database-wide unique identifier,
- use the combination of tableoid and row OID for the purpose. (It is
- likely that future Postgres releases will use a separate OID counter
- for each table, so that it will be necessary> not optional
- to include tableoid to have a unique identifier database-wide.)
-
-
-
-
- WITHOUT OIDS 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.
-
-
-
-
-
-
- DEFAULT Clause
-
-
-
-DEFAULT value
-
-
-
-
- The DEFAULT clause assigns a default data value for the column whose
- column definition it appears within. The value is any variable-free
- expression (note that sub-selects and cross-references to other
- columns in the current table are not supported).
- The data type of a default value must match the column definition's
- data type.
-
-
-
- The DEFAULT expression will be used in any INSERT operation that does
- not specify a value for the column. If there is no DEFAULT clause,
- then the default is NULL.
-
-
-
-
- Usage
-
-
-
-
-CREATE TABLE distributors (
- name VARCHAR(40) DEFAULT 'luso films',
- did INTEGER DEFAULT NEXTVAL('distributors_serial'),
- modtime TIMESTAMP DEFAULT now()
-);
-
- The above assigns a literal constant default value for the column
- name, and arranges for the default value of column
- did to be generated by selecting the next value of a
- sequence object. The default value of modtime will
- be the time at which the row is inserted.
-
-
-
- It is worth remarking that
-
- modtime TIMESTAMP DEFAULT 'now'
-
- would produce a result that is probably not the intended one: the
- string 'now' will be coerced to a timestamp value
- immediately, and so the default value of modtime will
- always be the time of table creation. This difficulty is avoided by
- specifying the default value as a function call.
-
-
-
-
-
-
- Column Constraints
-
-
-
-[ CONSTRAINT constraint_name ] {
- NULL | NOT NULL | UNIQUE | PRIMARY KEY | CHECK condition |
- REFERENCES reftable [ ( refcolumn ) ]
- [ MATCH matchtype ]
- [ ON DELETE action ]
- [ ON UPDATE action ]
- [ [ NOT ] DEFERRABLE ]
- [ INITIALLY checktime ] }
-
-
-
-
-
- Inputs
-
-
-
-
-
- constraint_name
-
-
- An arbitrary name given to a constraint clause.
-
-
-
-
-
- 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 automatic creation of a unique index on the column.
-
-
-
-
-
- PRIMARY KEY
-
-
- This column is a primary key, which implies that other tables may rely
- on this column as a unique identifier for rows. Both UNIQUE and
- NOT NULL are implied by PRIMARY KEY. See PRIMARY KEY for more
- information.
-
-
-
-
-
-
-condition
-
-
-
- An arbitrary boolean-valued constraint condition.
-
-
-
-
-
-
-
-
-
- Description
-
-
-
- The optional constraint clauses specify constraints or tests which
- 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.
-
-
-
- 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 is explicitly given a name:
-
-
-CREATE TABLE distributors (
- did DECIMAL(3) CONSTRAINT no_null NOT NULL,
- name VARCHAR(40) NOT NULL
-);
-
-
-
-
-
-
-
- UNIQUE Constraint
-
-
-[ CONSTRAINT constraint_name ] UNIQUE
-
-
-
- Inputs
-
-
-
-
- constraint_name
-
-
- An arbitrary name given to a constraint clause.
-
-
-
-
-
-
-
-
- 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.
-
-
+
+ [LOCAL] TEMPORARY> or [LOCAL] TEMP>
+
- Postgres automatically creates a unique
- index for each UNIQUE constraint, to assure
- data integrity. See CREATE INDEX for more information.
+ If specified, the table is created as a temporary table.
+ Temporary tables are automatically dropped at the end of a
+ session. Existing persistent tables with the same name are not
+ visible to the current session while the temporary table exists.
+ Any indexes created on a temporary table are automatically
+ temporary as well.
-
-
-
-
- Usage
-
+
+ The LOCAL word is optional. But see under
+ .
+
+
+
-
- Defines a UNIQUE constraint for the name column:
-
-CREATE TABLE distributors (
- did DECIMAL(3),
- name VARCHAR(40) UNIQUE
-);
-
+
+ table_name
+
+
+ The name of the table to be created.
+
+
+
- which is equivalent to the following specified as a table constraint:
-
-CREATE TABLE distributors (
- did DECIMAL(3),
- name VARCHAR(40),
- UNIQUE(name)
-);
-
-
-
-
+
+ column_name
+
+
+ The name of a column to be created in the new table.
+
+
+
-
-
- The CHECK Constraint
-
-
-[ CONSTRAINT constraint_name ] CHECK ( condition )
-
-
- Inputs
-
+
+ data_type
+
+
+ The data type of the column. This may include array specifiers.
+ Refer to the User's Guide for further
+ information about data types and arrays.
+
+
+
-
-
- constraint_name
-
-
- An arbitrary name given to a constraint clause.
-
-
-
-
- condition
-
-
- Any valid conditional expression evaluating to a boolean result.
-
-
-
-
-
-
+
+ DEFAULT
+ default_expr
+
+
+ The 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.
+
-
-
- Outputs
-
-
+
+ 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.
+
+
+
-
-
- status
-
-
+
+ INHERITS ( parent_table [, ... ] )
+
+
+ The optional 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.
+
+
+
+
-
-
-
-ERROR: ExecAppend: rejected due to CHECK constraint "constraint_name".
-
-
-
- This error occurs at runtime if one tries to insert an illegal
- value into a column subject to a CHECK constraint.
-
-
-
-
-
-
-
-
-
-
+
+ WITH OIDS> or WITHOUT OIDS>
+
+
+ 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 WITH OIDS> is forced even
+ if the command says WITHOUT OIDS>.)
+
-
- Description
-
- The CHECK constraint specifies a generic restriction on allowed values
- within a column. The CHECK constraint is also allowed as a table
- constraint.
-
-
- CHECK specifies a general boolean expression involving one or more
- columns of a table. A new row will be rejected if the boolean
- expression evaluates to FALSE when applied to the row's values.
-
-
- Currently, CHECK expressions cannot contain sub-selects nor refer
- to variables other than fields of the current row.
-
-
- The SQL92 standard says that CHECK column constraints may only refer
- to the column they apply to; only CHECK table constraints may refer
- to multiple columns.
- Postgres does not enforce this restriction.
- It treats column and table CHECK constraints alike.
-
-
-
-
-
-
- PRIMARY KEY Constraint
-
-
-[ CONSTRAINT constraint_name ] PRIMARY KEY
-
+
+ Specifying 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.
+
+
+
-
- Inputs
-
-
-
- constraint_name
-
-
- An arbitrary name given to a constraint clause.
-
-
-
-
-
-
+
+ CONSTRAINT constraint_name
+
+
+ An optional name for a column or table constraint. If not specified,
+ the system generates a name.
+
+
+
-
- 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.
-
-
-
-
-
+
+ NOT NULL>
+
+
+ The column is not allowed to contain NULL values. This is
+ equivalent to the column constraint CHECK (column NOT NULL).
+
+
+
-
- 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, whether as a
- column constraint or a table constraint.
-
-
+
+ NULL>
+
+
+ The column is allowed to contain NULL values. This is the default.
+
-
-
- 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 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 given to a constraint clause.
-
-
-
-
-
- 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 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.
-
-
-
-
-
-
-
-
-
-
+
+ This clause is only available for compatibility with
+ non-standard SQL databases. Its use is discouraged in new
+ applications.
+
+
+
+
+ UNIQUE> (column constraint)
+ UNIQUE ( column_name [, ... ] )> (table constraint)
-
-
- 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.
-
-
-
-
-
-
-
-
-
-
+
+
+ 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.
+
-
- 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.
-
-
+
+ For the purpose of a unique constraint, NULL values are not
+ considered equal.
+
-
-
- 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 Constraints
-
-
-
-[ 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
-
+
+ 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.)
+
+
+
-
+
+ PRIMARY KEY> (column constraint)
+ PRIMARY KEY ( column_name [, ... ] )> (table constraint)
+
+
+ The primary key constraint specifies that a column or columns of a table
+ may contain only unique (non-duplicate), non-NULL values.
+ Technically, PRIMARY KEY is merely a
+ combination of UNIQUE> and 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.
+
-
-
- constraint_name
-
-
- An arbitrary name given to a constraint clause.
-
-
-
-
- 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 table. The four variations of Table
- Constraint
are:
-
- UNIQUE
- CHECK
- PRIMARY KEY
- FOREIGN KEY
-
-
-
-
-
-
- UNIQUE Constraint
-
-
-
-[ CONSTRAINT constraint_name ] UNIQUE ( column [, ... ] )
-
-
-
- Inputs
-
-
- constraint_name
-
-
- An arbitrary name given to a constraint clause.
-
-
-
-
- column
-
-
- A name of a column in a table.
-
-
-
-
-
+
+ Only one primary key can be specified for a table, whether as a
+ column constraint or a table 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
- 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.
-
-
+
+ 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.
+
+
+
-
-
- Usage
-
-
-
- Prevent duplicate rows in the table distributors:
-
-CREATE TABLE distributors (
- did DECIMAL(3),
- name VARCHAR(40),
- UNIQUE(did,name)
-);
-
-
-
-
+
+ CHECK (expression)
+
+
+ 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.
+
-
-
- PRIMARY KEY Constraint
-
-
-
-[ CONSTRAINT constraint_name ] PRIMARY KEY ( column [, ... ] )
-
-
-
- Inputs
-
+
+ Currently, CHECK expressions cannot contain
+ subselects nor refer to variables other than columns of the
+ current row.
+
-
-
- constraint_name
-
-
- An arbitrary name given to a constraint clause.
-
-
-
-
- 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 constraint_name ] FOREIGN KEY ( column [, ... ] )
+
+ REFERENCES reftable [ ( refcolumn ) ] [ MATCH matchtype ] [ ON DELETE action ] [ ON UPDATE action ] (column constraint)
+
+ 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 or set
- of column values is
- checked against the values in another table.
-
+ [ ON UPDATE action ]
+ (table constraint)
-
- Inputs
-
-
-
- constraint_name
-
-
- An arbitrary name given to a constraint clause.
-
-
-
-
- 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 columns 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 REFERENCES 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) refcolumn
+ of the referenced table reftable. If refcolumn is omitted, the
+ primary key of the reftable is used. The
+ referenced columns must be the columns of a unique or primary
+ key constraint 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.
-
-
+
+ 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: 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 not yet
+ implemented.
+
+
+
+ In addition, when the data in the referenced columns is changed,
+ certain actions are performed on the data in this table's
+ columns. The ON DELETE clause specifies the
+ action to do when a referenced row in the referenced table is
+ being deleted. Likewise, the ON UPDATE
+ 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:
+
+
+
+ NO ACTION
+
+
+ Produce an error indicating that the deletion or update
+ would create a foreign key constraint violation. This is
+ the default action.
+
+
+
+
+
+ RESTRICT
+
+
+ Same as NO ACTION.
+
+
+
+
+
+ CASCADE
+
+
+ Delete any rows referencing the deleted row, or update the
+ value of the referencing column to the new value of the
+ referenced column, respectively.
+
+
+
+
+
+ SET NULL
+
+
+ Set the referencing column values to NULL.
+
+
+
+
+
+ SET DEFAULT
+
+
+ Set the referencing column values to their default value.
+
+
+
+
+
+
+
+
-
+
+ DEFERRABLE or NOT DEFERRABLE
+
+
+ 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 command).
+ NOT DEFERRABLE is the default. Only foreign
+ key constraints currently accept this clause. All other
+ constraint types are not deferrable.
+
+
+
+
+ INITIALLY IMMEDIATE or INITIALLY DEFERRED
+
+
+ If a constraint is deferrable, this clause specifies the default
+ time to check the constraint. If the constraint is
+ INITIALLY IMMEDIATE, it is checked after each
+ statement. This is the default. If the constraint is
+ INITIALLY DEFERRED, it is checked only at the
+ end of the transaction. The constraint check time can be
+ altered with the command.
+
+
+
+
+
+
+
+
+ Diagnostics
+
+
+
+
+
+
+ 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.
+
+
+
+
-
-
-
- Usage
-
+
+
+
+ Notes
+
+
+
+
+ Whenever an application makes use of OIDs to identify specific
+ rows of a table, it is recommended to create a unique constraint
+ on the 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 tableoid> and row OID for the
+ purpose. (It is likely that future PostgreSQL>
+ releases will use a separate OID counter for each table, so that
+ it will be necessary>, not optional, to include
+ tableoid> to have a unique identifier
+ database-wide.)
+
+
+
+
+ The use of WITHOUT OIDS 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.
+
+
+
+
+
+
+ PostgreSQL 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 for more information.)
+
+
+
+
+
+ The SQL92 standard says that CHECK> column constraints
+ may only refer to the column they apply to; only
+ CHECK> table constraints may refer to multiple
+ columns. PostgreSQL does not enforce
+ this restriction; it treats column and table check constraints
+ alike.
+
+
+
+
+
+ Unique constraints and primary keys are not inherited in the
+ current implementation. This makes the combination of
+ inheritance and unique constraints rather disfunctional.
+
+
+
+
+
+
+
+ Examples
+
- Create table films and table distributors:
+ 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
+ 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 <> '')
+ 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[][]
- );
-
+
+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:
+ 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,
+ 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)
);
-
+
- Define a CHECK column constraint:
+ Define a check column constraint:
-
+
CREATE TABLE distributors (
- did DECIMAL(3) CHECK (did > 100),
- name VARCHAR(40)
+ did DECIMAL(3) CHECK (did > 100),
+ name VARCHAR(40)
);
-
+
- Define a CHECK table constraint:
+ Define a check table constraint:
-
+
CREATE TABLE distributors (
- did DECIMAL(3),
- name VARCHAR(40)
- CONSTRAINT con1 CHECK (did > 100 AND name > '')
+ 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:
+ 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,
+ 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)
);
-
+
- 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):
+ Define a primary key constraint for table
+ distributors>. The following two examples are
+ equivalent, the first using the table constraint syntax, the second
+ the column constraint notation.
-
+
CREATE TABLE distributors (
- did DECIMAL(3),
- name CHAR VARYING(40),
+ did DECIMAL(3),
+ name CHAR VARYING(40),
PRIMARY KEY(did)
);
-
+
-
+
CREATE TABLE distributors (
- did DECIMAL(3) PRIMARY KEY,
- name VARCHAR(40)
+ did DECIMAL(3) PRIMARY KEY,
+ name VARCHAR(40)
);
-
+
-
+
+
+ This assigns a literal constant default value for the column
+ name, and arranges for the default value of
+ column did to be generated by selecting the next
+ value of a sequence object. The default value of
+ modtime will be the time at which the row is
+ inserted.
+
+
+CREATE TABLE distributors (
+ name VARCHAR(40) DEFAULT 'luso films',
+ did INTEGER DEFAULT NEXTVAL('distributors_serial'),
+ modtime TIMESTAMP DEFAULT CURRENT_TIMESTAMP
+);
+
+
+
+
+ Define two NOT NULL> column constraints on the table
+ distributors, one of which is explicitly
+ given a name:
+
+
+CREATE TABLE distributors (
+ did DECIMAL(3) CONSTRAINT no_null NOT NULL,
+ name VARCHAR(40) NOT NULL
+);
+
+
+
+
+ Define a unique constraint for the name column:
+
+
+CREATE TABLE distributors (
+ did DECIMAL(3),
+ name VARCHAR(40) UNIQUE
+);
+
+
+ The above is equivalent to the following specified as a table constraint:
+
+
+CREATE TABLE distributors (
+ did DECIMAL(3),
+ name VARCHAR(40),
+ UNIQUE(name)
+);
+
+
+
-
-
- Compatibility
-
+
+ Compatibility
+
+
+ The CREATE TABLE conforms to SQL92 Intermediate
+ and to a subset of SQL99, with exceptions listed below and in the
+ descriptions above.
+
+
+
+ Temporary Tables
-
-
- 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 ]
-
+ In addition to the local temporary table, SQL92 also defines a
+ CREATE GLOBAL TEMPORARY TABLE statement.
+ Global temporary tables are also visible to other sessions.
- 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.
+ For temporary tables, there is an optional ON COMMIT clause:
+
+CREATE { GLOBAL | LOCAL } TEMPORARY TABLE table ( ... ) [ ON COMMIT { DELETE | PRESERVE } ROWS ]
+
+
+ The ON COMMIT clause specifies whether or not
+ the temporary table should be emptied of rows whenever
+ COMMIT is executed. If the ON
+ COMMIT> clause is omitted, SQL92 specifies that the default is
+ ON COMMIT DELETE ROWS>. However, the behavior of
+ PostgreSQL is always like ON
+ COMMIT PRESERVE ROWS.
+
+
+
+ NULL Constraint
+
- 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, SQL92
- specifies that the default is ON COMMIT DELETE ROWS. However,
- Postgres' behavior is always like
- ON COMMIT PRESERVE ROWS.
+ The NULL> constraint
(actually a
+ non-constraint) is a PostgreSQL
+ extension to SQL92 that is included for compatibility with some
+ other RDBMSes (and for symmetry with the NOT
+ NULL constraint). Since it is the default for any
+ column, its presence is simply noise.
-
-
-
- UNIQUE clause
-
-
- SQL92 specifies some additional capabilities for UNIQUE:
-
-
- Table Constraint definition:
-
-
-[ CONSTRAINT constraint_name ] UNIQUE ( column [, ... ] )
- [ { INITIALLY DEFERRED | INITIALLY IMMEDIATE } ]
- [ [ NOT ] DEFERRABLE ]
-
-
-
-
- Column Constraint definition:
-
-
-[ CONSTRAINT constraint_name ] UNIQUE
- [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
- [ [ NOT ] DEFERRABLE ]
-
-
-
+
-
-
- NULL clause
-
-
- The NULL constraint
(actually a non-constraint) is a
- Postgres extension to SQL92 that is
- included for symmetry with the NOT NULL clause (and for compatibility
- with some other RDBMSes). Since it is the
- default for any column, its presence is simply noise.
-
-[ CONSTRAINT constraint_name ] NULL
-
-
-
-
-
-
- NOT NULL clause
-
-
-
- SQL92 specifies some additional capabilities for NOT NULL:
-
-[ CONSTRAINT constraint_name ] NOT NULL
- [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
- [ [ NOT ] DEFERRABLE ]
-
-
-
-
-
+
+ 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 CREATE ASSERTION
+ statement as an alternate method for defining a constraint:
-
-
- 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 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 )
-
-
+
+
+
+
+ PostgreSQL> does not implement assertions at present.
+
+
+
+
-
- table constraint definition:
-
-[ CONSTRAINT constraint_name ]
- CHECK ( VALUE condition )
- [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
- [ [ NOT ] DEFERRABLE ]
-
-
+
+
+ Inheritance
-
- column constraint definition:
-
-[ CONSTRAINT 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 constraint_name ] PRIMARY KEY ( column [, ... ] )
- [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
- [ [ NOT ] DEFERRABLE ]
-
-
-
- Column Constraint definition:
-
-[ CONSTRAINT constraint_name ] PRIMARY KEY
- [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
- [ [ NOT ] DEFERRABLE ]
-
-
-
-
-
-
- Inheritance
-
-
- Multiple inheritance via the INHERITS clause is a
- Postgres language extension.
- SQL99 (but not SQL92) defines single inheritance using a different
- syntax and different semantics. SQL99-style inheritance is not yet
- supported by Postgres.
-
-
-
-
-
- Object IDs
-
-
- The Postgres concept of OIDs is not
- standard. SQL99 (but not SQL92) has a notion of object ID, but
- the syntax and semantics are different --- SQL99 associates OIDs
- with individual values, not with rows.
-
-
+ Multiple inheritance via the INHERITS clause is
+ a PostgreSQL language extension. SQL99
+ (but not SQL92) defines single inheritance using a different
+ syntax and different semantics. SQL99-style inheritance is not
+ yet supported by PostgreSQL.
+
+
+
+ Object IDs
+
+
+ The PostgreSQL concept of OIDs is not
+ standard.
+
+
+
+
+
+
+ See Also
+
+
+
+
+
diff --git a/doc/src/sgml/ref/create_table_as.sgml b/doc/src/sgml/ref/create_table_as.sgml
index a0144ab658..8ebc19c2a7 100644
--- a/doc/src/sgml/ref/create_table_as.sgml
+++ b/doc/src/sgml/ref/create_table_as.sgml
@@ -1,112 +1,26 @@
-
- CREATE TABLE AS
-
+ CREATE TABLE AS
SQL - Language Statements
+
-
- CREATE TABLE AS
-
-
- create a new table from the results of a query
-
+ CREATE TABLE AS
+ create a new table from the results of a query
+
-
- 2001-03-03
-
-
-CREATE [ TEMPORARY | TEMP ] TABLE table [ (column [, ...] ) ]
- AS select_clause
+
+CREATE [ [ LOCAL ] { TEMPORARY | TEMP } ] TABLE table_name [ (column_name [, ...] ) ]
+ AS query
-
-
-
- 1998-09-22
-
-
- Inputs
-
-
-
-
-
- TEMPORARY or TEMP
-
-
- If specified, the table is created only within this session, and is
- automatically dropped on session exit.
- Existing permanent tables with the same name are not visible
- (in this session) while the temporary table exists.
- Any indexes created on a temporary table are automatically
- temporary as well.
-
-
-
-
-
- table
-
-
- The name of the new table to be created.
- This table must not already exist. However, a temporary table
- can be created that has the same name as an existing permanent
- table.
-
-
-
-
-
- column
-
-
- The name of a column. Multiple column names can be specified using
- a comma-delimited list of column names. If column names are not
- provided, they are taken from the output column names of the
- SELECT query.
-
-
-
-
-
- select_clause
-
-
- A valid query statement. Refer to
-
- for a description of the allowed syntax.
-
-
-
-
-
-
-
-
-
- 1998-09-22
-
-
- Outputs
-
-
-
- Refer to
-
- and
-
- for a summary of possible output messages.
-
-
-
+
2001-03-20
@@ -117,28 +31,135 @@ CREATE [ TEMPORARY | TEMP ] TABLE table [ (
CREATE TABLE AS creates a table and fills it
with data computed by a SELECT command. The
- table columns have the names and datatypes associated with the
+ table columns have the names and data types associated with the
output columns of the SELECT (except that you
- can override the SELECT column names by giving
- an explicit list of column names).
+ can override the column names by giving an explicit list of new
+ column names).
- CREATE TABLE AS bears some resemblance to creating
- a view, but it is really quite different: it creates a new table and
- evaluates the SELECT just once to fill the new table
- initially. The new table will not track subsequent changes to
- the source tables of the SELECT. In contrast,
- a view re-evaluates the given SELECT whenever queried.
-
-
-
- This command is functionally equivalent to
- ,
- but it is preferred since it is less likely to be confused with
- other uses of the SELECT ... INTO syntax.
+ CREATE TABLE AS bears some resemblance to
+ creating a view, but it is really quite different: it creates a new
+ table and evaluates the query just once to fill the new table
+ initially. The new table will not track subsequent changes to the
+ source tables of the query. In contrast, a view re-evaluates the
+ underlying SELECT statements whenever it is
+ queried.
+
+
+ Parameters
+
+
+
+ [LOCAL] TEMPORARY> or [LOCAL] TEMP>
+
+
+ If specified, the table is created as a temporary table.
+ Temporary tables are automatically dropped at the end of a
+ session. Existing persistent tables with the same name are not
+ visible to the current session while the temporary table exists.
+ Any indexes created on a temporary table are automatically
+ temporary as well.
+
+
+
+ The LOCAL word is optional.
+
+
+
+
+
+ table_name
+
+
+ The name of the new table to be created. This table must not
+ already exist. However, a temporary table can be created that
+ has the same name as an existing permanent table.
+
+
+
+
+
+ column_name
+
+
+ The name of a column in the new table. Multiple column names can
+ be specified using a comma-delimited list of column names. If
+ column names are not provided, they are taken from the output
+ column names of the query.
+
+
+
+
+
+ query
+
+
+ A query statement (that is, a SELECT
+ command). Refer to
+
+ for a description of the allowed syntax.
+
+
+
+
+
+
+
+ Diagnostics
+
+
+ Refer to and
+
+ for a summary of possible output messages.
+
+
+
+
+ Notes
+
+
+ This command is functionally equivalent to , but it is preferred since it is less
+ likely to be confused with other uses of the SELECT
+ ... INTO syntax.
+
+
+
+
+ Compatibility
+
+
+ This command is modeled after an Oracle
+ feature. There is no command with equivalent functionality in
+ SQL92 or SQL99. However, a combination of CREATE
+ TABLE and INSERT ... SELECT can
+ accomplish the same thing with little more effort.
+
+
+
+
+ History
+
+
+ The CREATE TABLE AS command has been available
+ since PostgreSQL 6.3.
+
+
+
+
+ See Also
+
+
+
+
+
+
+
+
+
@@ -89,7 +89,7 @@ where from_item can be:
All other inputs are described in detail for
- .
+ .
@@ -103,9 +103,9 @@ where from_item can be:
Refer to
-
+
and
-
+
for a summary of possible output messages.
@@ -128,7 +128,7 @@ where from_item can be:
-
+
is functionally equivalent to SELECT INTO.
CREATE TABLE AS is the recommended syntax, since
SELECT INTO is not standard. In fact, this form of
diff --git a/doc/src/sgml/stylesheet.dsl b/doc/src/sgml/stylesheet.dsl
index 1b2d55ce86..80d9462d23 100644
--- a/doc/src/sgml/stylesheet.dsl
+++ b/doc/src/sgml/stylesheet.dsl
@@ -1,4 +1,4 @@
-
+
@@ -123,6 +123,16 @@
;;; XXX The above is very ugly. It might be better to run 'tidy' on
;;; the resulting *.html files.
+
+;; Format multiple terms in varlistentry vertically, instead
+;; of comma-separated.
+(element (varlistentry term)
+ (make sequence
+ (process-children-trim)
+ (if (not (last-sibling?))
+ (make empty-element gi: "BR")
+ (empty-sosofo))))
+
]]>