diff --git a/doc/src/sgml/ref/commands.sgml b/doc/src/sgml/ref/commands.sgml
index f295a94279..3edc715778 100644
--- a/doc/src/sgml/ref/commands.sgml
+++ b/doc/src/sgml/ref/commands.sgml
@@ -16,6 +16,10 @@
&createFunction;
&createIndex;
&createLanguage;
+&createOperator;
+&createRule;
+&createSequence;
+&createTable;
&dropFunction;
&select;
@@ -36,4 +40,4 @@ sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
--->
\ No newline at end of file
+-->
diff --git a/doc/src/sgml/ref/create_operator.sgml b/doc/src/sgml/ref/create_operator.sgml
new file mode 100644
index 0000000000..a9c25a0269
--- /dev/null
+++ b/doc/src/sgml/ref/create_operator.sgml
@@ -0,0 +1,416 @@
+
+
+
+ CREATE OPERATOR
+
+ SQL - Language Statements
+
+
+
+ CREATE OPERATOR
+
+
+ Defines a new user operator.
+
+
+
+
+ 1998-04-15
+
+
+ CREATE OPERATOR name
+ ([ LEFTARG = type1 ]
+ [, RIGHTARG = type2 ]
+ , PROCEDURE = func_name
+ [, COMMUTATOR = com_op ]
+ [, NEGATOR = neg_op ]
+ [, RESTRICT = res_proc ]
+ [, HASHES ]
+ [, JOIN = join_proc ]
+ [, SORT = sort_op [, ...] ]
+ )
+
+
+
+
+ 1998-04-15
+
+
+ Inputs
+
+
+
+
+
+
+
+
+
+
+
+
+ name
+
+
+
+ The name of an existing aggregate function.
+
+
+
+
+
+ type1
+
+
+
+
+
+
+
+
+ type2
+
+
+
+
+
+
+
+
+ func_name
+
+
+
+
+
+
+
+
+ com_op
+
+
+
+
+
+
+
+
+ neg_op
+
+
+
+
+
+
+
+
+ res_proc
+
+
+
+
+
+
+
+
+ join_proc
+
+
+
+
+
+
+
+
+ sort_op
+
+
+
+
+
+
+
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ Outputs
+
+
+
+
+
+
+
+
+
+
+
+
+ CREATE
+
+
+
+ Message returned if the operator is successfully created.
+
+
+
+
+
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ Description
+
+
+ This command defines a new user operator, operator_name.
+ The user who defines an operator becomes its owner.
+
+
+ The operator_name is a sequence of up to sixteen punctua
+ tion characters. The following characters are valid for
+ single-character operator names:
+
+ ~ ! @ # % ^ & ` ?
+
+
+ If the operator name is more than one character long, it
+ may consist of any combination of the above characters or
+ the following additional characters:
+
+ | $ : + - * / < > =
+
+
+ The operator "!=" is mapped to "<>" on input, and they are
+ therefore equivalent.
+
+
+ At least one of leftarg and rightarg must be defined. For
+ binary operators, both should be defined. For right unary
+ operators, only arg1 should be defined, while for left
+ unary operators only arg2 should be defined.
+
+
+ The name of the operator, operator_name, can be composed
+ of symbols only. Also, the func_name procedure must have
+ been previously defined using create function(l) and must
+ have one or two arguments.
+
+
+ The commutator operator is present so that Postgres can
+ reverse the order of the operands if it wishes. For exam
+ ple, the operator area-less-than, >>>, would have a commu
+ tator operator, area-greater-than, <<<. Suppose that an
+ operator, area-equal, ===, exists, as well as an area not
+ equal, !==. Hence, the query optimizer could freely con
+ vert:
+
+ "0,0,1,1"::box >>> MYBOXES.description
+
+ to
+
+ MYBOXES.description <<< "0,0,1,1"::box
+
+
+ This allows the execution code to always use the latter
+ representation and simplifies the query optimizer some
+ what.
+
+
+ The negator operator allows the query optimizer to convert
+
+ NOT MYBOXES.description === "0,0,1,1"::box
+
+ to
+
+ MYBOXES.description !== "0,0,1,1"::box
+
+
+
+ If a commutator operator name is supplied, Postgres
+ searches for it in the catalog. If it is found and it
+ does not yet have a commutator itself, then the commutator's
+ entry is updated to have the current (new) operator
+ as its commutator. This applies to the negator, as well.
+
+
+ This is to allow the definition of two operators that are
+ the commutators or the negators of each other. The first
+ operator should be defined without a commutator or negator
+ (as appropriate). When the second operator is defined,
+ name the first as the commutator or negator. The first
+ will be updated as a side effect.
+
+
+ The next two specifications are present to support the
+ query optimizer in performing joins. Postgres can always
+ evaluate a join (i.e., processing a clause with two tuple
+ variables separated by an operator that returns a boolean)
+ by iterative substitution [WONG76]. In addition, Postgres
+ is planning on implementing a hash-join algorithm along
+ the lines of [SHAP86]; however, it must know whether this
+ strategy is applicable. For example, a hash-join
+ algorithm is usable for a clause of the form:
+
+ MYBOXES.description === MYBOXES2.description
+
+ but not for a clause of the form:
+
+ MYBOXES.description <<< MYBOXES2.description.
+
+ The hashes flag gives the needed information to the query
+ optimizer concerning whether a hash join strategy is
+ usable for the operator in question.
+
+ Similarly, the two sort operators indicate to the query
+ optimizer whether merge-sort is a usable join strategy and
+ what operators should be used to sort the two operand
+ classes. For the === clause above, the optimizer must
+ sort both relations using the operator, <<<. On the other
+ hand, merge-sort is not usable with the clause:
+
+ MYBOXES.description <<< MYBOXES2.description
+
+
+
+ If other join strategies are found to be practical, Post
+ gres will change the optimizer and run-time system to use
+ them and will require additional specification when an
+ operator is defined. Fortunately, the research community
+ invents new join strategies infrequently, and the added
+ generality of user-defined join strategies was not felt to
+ be worth the complexity involved.
+
+
+ The last two pieces of the specification are present so
+ the query optimizer can estimate result sizes. If a
+ clause of the form:
+
+ MYBOXES.description <<< "0,0,1,1"::box
+
+ is present in the qualification, then Postgres may have to
+ estimate the fraction of the instances in MYBOXES that
+ satisfy the clause. The function res_proc must be a reg
+ istered function (meaning it is already defined using
+ define function(l)) which accepts one argument of the correct
+ data type and returns a floating point number. The
+ query optimizer simply calls this function, passing the
+ parameter "0,0,1,1" and multiplies the result by the relation
+ size to get the desired expected number of instances.
+
+
+ Similarly, when the operands of the operator both contain
+ instance variables, the query optimizer must estimate the
+ size of the resulting join. The function join_proc will
+ return another floating point number which will be multiplied
+ by the cardinalities of the two classes involved to
+ compute the desired expected result size.
+
+
+ The difference between the function
+
+ my_procedure_1 (MYBOXES.description, "0,0,1,1"::box)
+
+ and the operator
+
+ MYBOXES.description === "0,0,1,1"::box
+
+ is that Postgres attempts to optimize operators and can
+ decide to use an index to restrict the search space when
+ operators are involved. However, there is no attempt to
+ optimize functions, and they are performed by brute force.
+ Moreover, functions can have any number of arguments while
+ operators are restricted to one or two.
+
+
+
+
+ 1998-04-15
+
+
+ Notes
+
+
+ Refer to PostgreSQL User's Guide chapter 5
+
+ This reference must be corrected.
+
+ for further information.
+ Refer to DROP OPERATOR statement to drop operators.
+
+
+
+
+
+ Usage
+
+ The following command defines a new operator,
+ area-equality, for the BOX data type.
+
+
+ CREATE OPERATOR === (
+ LEFTARG = box,
+ RIGHTARG = box,
+ PROCEDURE = area_equal_procedure,
+ COMMUTATOR = ===,
+ NEGATOR = !==,
+ RESTRICT = area_restriction_procedure,
+ HASHES,
+ JOIN = area-join-procedure,
+ SORT = <<<, <<<)
+
+
+
+
+
+
+
+ Compatibility
+
+
+ CREATE OPERATOR is a PostgreSQL extension of SQL.
+
+
+
+
+ 1998-04-15
+
+
+ SQL92
+
+
+ There is no CREATE OPERATOR statement on SQL92.
+
+
+
+
+
+
diff --git a/doc/src/sgml/ref/create_rule.sgml b/doc/src/sgml/ref/create_rule.sgml
new file mode 100644
index 0000000000..93ef6057de
--- /dev/null
+++ b/doc/src/sgml/ref/create_rule.sgml
@@ -0,0 +1,363 @@
+
+
+
+ CREATE RULE
+
+ SQL - Language Statements
+
+
+
+ CREATE RULE
+
+
+ Defines a new rule.
+
+
+
+ 1998-04-15
+
+
+ CREATE RULE name
+ AS ON event
+ TO object [WHERE condition]
+ DO [INSTEAD]
+ [action | NOTHING ]
+
+
+
+
+ 1998-04-15
+
+
+ Inputs
+
+
+
+
+
+
+
+
+
+
+
+
+ name
+
+
+
+ The name of a rule to create.
+
+
+
+
+
+ event
+
+
+
+ Event is one of select, update, delete or insert.
+
+
+
+
+
+ object
+
+
+
+ Object is either table or table.column.
+
+
+
+
+
+ condition
+
+
+
+ Any SQL where clause. new or
+ current can appear instead of an instance
+ variable whenever an instance variable is permissible in SQL.
+
+
+
+
+
+ action
+
+
+
+ Any SQL-statement. new or
+ current can appear instead of an instance
+ variable whenever an instance variable is permissible in SQL.
+
+
+
+
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ Outputs
+
+
+
+
+
+
+
+
+
+
+
+
+ CREATE
+
+
+
+ Message returned if the rule is successfully created.
+
+
+
+
+
+
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ Description
+
+
+ The semantics of a rule is that at the time an individual instance is
+ accessed, updated, inserted or deleted, there is a current instance (for
+ retrieves, updates and deletes) and a new instance (for updates and
+ appends). If the event
+ specified in the on clause and the
+ condition specified in the
+ where clause are true for the current instance, the
+ action part of the rule is
+ executed. First, however, values from fields in the current instance
+ and/or the new instance are substituted for
+ current.attribute-name
+ and new.attribute-name.
+
+
+ The action part of the rule
+ executes with the same command and transaction identifier as the user
+ command that caused activation.
+
+
+
+
+ 1998-04-15
+
+
+ Notes
+
+
+ A note of caution about SQL rules is in order. If the same class name
+ or instance variable appears in the
+ event, the
+ condition and the
+ action parts of a rule,
+ they are all considered different tuple variables. More accurately,
+ new and current are the only tuple
+ variables that are shared between these clauses. For example, the following
+ two rules have the same semantics:
+
+ on update to EMP.salary where EMP.name = "Joe"
+ do update EMP ( ... ) where ...
+
+ on update to EMP-1.salary where EMP-2.name = "Joe"
+ do update EMP-3 ( ... ) where ...
+
+ Each rule can have the optional tag instead. Without
+ this tag, action will be
+ performed in addition to the user command when the
+ event in the
+ condition part of the rule
+ occurs. Alternately, the
+ action part will be done
+ instead of the user command. In this later case, the
+ action can be the keyword
+ nothing.
+
+
+ When choosing between the rewrite and instance rule systems for a
+ particular rule application, remember that in the rewrite system,
+ current refers to a relation and some qualifiers
+ whereas in the instance system it refers to an instance (tuple).
+
+
+ It is very important to note that the rewrite rule system
+ will neither detect nor process circular rules. For example, though each
+ of the following two rule definitions are accepted by Postgres, the
+ retrieve command will cause Postgres to crash:
+
+ Example of a circular rewrite rule combination.
+
+ create rule bad_rule_combination_1 is
+ on select to EMP
+ do instead select to TOYEMP
+
+ create rule bad_rule_combination_2 is
+ on select to TOYEMP
+ do instead select to EMP
+
+
+ This attempt to retrieve from EMP will cause Postgres to crash.
+
+ select * from EMP
+
+
+
+
+ You must have rule definition access to a class in order
+ to define a rule on it (see change acl(l)).
+
+ There is no manpage change or change_acl. What is intended?
+
+
+
+
+
+
+
+ Usage
+
+
+ Make Sam get the same salary adjustment as Joe
+
+
+ create rule example_1 is
+ on update EMP.salary where current.name = "Joe"
+ do update EMP (salary = new.salary)
+ where EMP.name = "Sam"
+
+
+ At the time Joe receives a salary adjustment, the event
+ will become true and Joe's current instance and proposed
+ new instance are available to the execution routines.
+ Hence, his new salary is substituted into the action part
+ of the rule which is subsequently executed. This propagates
+ Joe's salary on to Sam.
+
+
+ Make Bill get Joe's salary when it is accessed
+
+ create rule example_2 is
+
+ on select to EMP.salary
+ where current.name = "Bill"
+ do instead
+ select (EMP.salary) from EMP where EMP.name = "Joe"
+
+
+
+ Deny Joe access to the salary of employees in the shoe
+ department. (pg_username() returns the name of
+ the current user)
+
+ create rule example_3 is
+ on select to EMP.salary
+ where current.dept = "shoe" and pg_username() = "Joe"
+ do instead nothing
+
+
+
+ Create a view of the employees working in the toy department.
+
+ create TOYEMP(name = char16, salary = int4)
+
+ create rule example_4 is
+ on select to TOYEMP
+ do instead select (EMP.name, EMP.salary) from EMP
+ where EMP.dept = "toy"
+
+
+
+ All new employees must make 5,000 or less
+
+ create rule example_5 is
+ on insert to EMP where new.salary > 5000
+ do update newset salary = 5000
+
+
+
+
+
+
+ Bugs
+
+
+ instead rules do not work properly.
+
+
+ The object in a SQL rule cannot be an array reference and
+ cannot have parameters.
+
+
+ Aside from the "oid" field, system attributes cannot be
+ referenced anywhere in a rule. Among other things, this
+ means that functions of instances (e.g., "foo(emp)" where
+ "emp" is a class) cannot be called anywhere in a rule.
+
+
+ The rule system stores the rule text and query plans as
+ text attributes. This implies that creation of rules may
+ fail if the rule plus its various internal representations
+ exceed some value that is on the order of one page (8KB).
+
+
+
+
+ Compatibility
+
+
+ CREATE RULE statement is a PostgreSQL language extension.
+
+
+
+
+ 1998-04-15
+
+
+ SQL92
+
+
+ There is no CREATE RULE statement in SQL92.
+
+
+
+
+
+
diff --git a/doc/src/sgml/ref/create_sequence.sgml b/doc/src/sgml/ref/create_sequence.sgml
new file mode 100644
index 0000000000..bad6ef36aa
--- /dev/null
+++ b/doc/src/sgml/ref/create_sequence.sgml
@@ -0,0 +1,317 @@
+
+
+
+ CREATE SEQUENCE
+
+ SQL - Language Statements
+
+
+
+ CREATE SEQUENCE
+
+
+ creates a new sequence number generator.
+
+
+
+
+ 1998-04-15
+
+
+ CREATE SEQUENCE seqname
+ [INCREMENT increment]
+ [MINVALUE minvalue]
+ [MAXVALUE maxvalue]
+ [START start]
+ [CACHE cache]
+ [CYCLE]
+
+
+
+
+ 1998-04-15
+
+
+ Inputs
+
+
+
+
+
+
+
+
+
+
+
+
+ seqname
+
+
+
+ The name of a sequence to be created.
+
+
+
+
+
+ increment
+
+
+
+ The clause is optional. A positive value will make an
+ ascending sequence, a negative one a descending sequence. The default value
+ is 1.
+
+
+
+
+
+ minvalue
+
+
+
+ The optional clause
+ determines the minimum value
+ a sequence can be. The defaults are 1 and -2147483647 for
+ ascending and descending sequences, respectively.
+
+
+
+
+
+ maxvalue
+
+
+
+ Use the optional clause to
+ determine the maximum
+ value for the sequence. The defaults are 2147483647 and -1 for
+ ascending and descending sequences, respectively.
+
+
+
+
+
+ start
+
+
+
+ The optional enables the sequence to begin anywhere.
+ The default starting value is
+ minvalue
+ for ascending sequences and
+ maxvalue
+ for descending ones.
+
+ What happens if the user specifies start outside the range?
+
+
+
+
+
+
+ cache
+
+
+
+ The option
+ enables sequence numbers to be preallocated
+ and stored in memory for faster access. The minimum
+ value is 1 (no cache) and this is also the default.
+
+
+
+
+
+ CYCLE
+
+
+
+ The optional CYCLE keyword may be used to enable the sequence
+ to continue when the
+ maxvalue or
+ minvalue has been
+ reached by
+ an ascending or descending sequence respectively. If the limit is
+ reached, the next number generated will be whatever the
+ minvalue or
+ maxvalue is,
+ as appropriate.
+
+
+
+
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ Outputs
+
+
+
+
+
+
+
+
+
+
+
+
+ CREATE
+
+
+
+ Message returned if the command is successful.
+
+
+
+
+
+ ERROR: amcreate: ' seqname' relation already exists
+
+
+
+ If the sequence specified already exists.
+
+
+
+
+
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ Description
+
+
+ CREATE SEQUENCE will enter a new sequence number generator
+ into the current data base. This involves creating and initialising a
+ new single block
+ table with the name seqname.
+ The generator will be "owned" by the user issuing the command.
+
+
+ After the sequence is created, you may use the function
+ nextval() with the
+ sequence name as the argument to get a new number from the sequence.
+ The function currval('sequence_name') may be used
+ to determine the number returned by the last call to
+ nextval() for the
+ specified sequence in the current session.
+
+
+
+ Use a query like
+
+ SELECT * FROM sequence_name;
+
+ to get the parameters of a sequence.
+
+
+ Low-level locking is used to enable multiple simultaneous
+ calls to a generator.
+
+
+
+
+ 1998-04-15
+
+
+ Notes
+
+
+ Refer to the DROP SEQUENCE statement to remove a sequence.
+
+
+ Each backend uses its own cache to store allocated numbers.
+ Numbers that are cached but not used in the current session will be
+ lost.
+
+
+
+
+
+
+ Usage
+
+
+ Create an ascending sequence called serial, starting at 101:
+
+
+ CREATE SEQUENCE serial START 101;
+
+
+ Select the next number from this sequence
+
+ SELECT NEXTVAL ('serial');
+
+ nextval
+ -------
+ 114
+
+
+
+ Use this sequence in an INSERT:
+
+ INSERT INTO distributors VALUES (NEXTVAL ('serial'),'nothing');
+
+
+
+
+
+
+ Compatibility
+
+
+ CREATE SEQUENCE statement is a PostgreSQL language extension.
+
+
+
+
+ 1998-04-15
+
+
+ SQL92
+
+
+ There is no CREATE SEQUENCE statement on SQL92.
+
+
+
+
+
+
+
diff --git a/doc/src/sgml/ref/create_table.sgml b/doc/src/sgml/ref/create_table.sgml
new file mode 100644
index 0000000000..9e19e13997
--- /dev/null
+++ b/doc/src/sgml/ref/create_table.sgml
@@ -0,0 +1,1304 @@
+
+
+
+ CREATE TABLE
+
+ SQL - Language Statements
+
+
+
+ CREATE TABLE
+
+
+ Creates a new table.
+
+
+
+
+ 1998-04-15
+
+
+ CREATE TABLE table (
+ columntype [DEFAULT value] [CONSTRAINT column_constraint] [, ...]
+ [, column ...]
+ [, CONSTRAINT table_constraint]
+ ) [INHERITS ( inherited_table [, ...] )]
+
+
+
+
+ 1998-04-15
+
+
+ Inputs
+
+
+
+
+
+
+
+ table
+
+
+
+ The name of a new table to be created.
+
+
+
+
+
+
+ column
+
+
+
+ The name of a column.
+
+
+
+
+
+
+ type
+
+
+
+ The type of the column.
+ (Refer to the Postgres User's Guide for
+ further information about data types).
+
+
+
+
+
+
+ value
+
+
+
+ A default value for a column.
+ See the DEFAULT clause for more information.
+
+
+
+
+
+
+ inherited_table
+
+
+
+ The optional INHERITS clause specifies a collection of table
+ names from which this table automatically inherits all fields.
+ If any inherited field name appears more than once, PostgreSQL
+ reports an error. PostgreSQL automatically allows the created
+ table to inherit functions on tables above it in the inheritance
+ hierarchy. Inheritance of functions is done according
+ to the conventions of the Common Lisp Object System (CLOS).
+
+
+
+
+
+
+ column_constraint
+ table_constraint
+
+
+
+ The optional CONSTRAINT clause specifies a list of integrity
+ constraints which new or updated entries must satisfy for
+ an insert or update operation to succeed. Each constraint
+ must evaluate to a boolean expression. Multiple columns
+ may be referenced within a single constraint.
+ See CONSTRAINT clause for more information.
+
+
+
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ Outputs
+
+
+
+
+
+
+ status
+
+
+
+
+
+
+ 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:
+
+ amcreate: "table" relation already exists
+
+ which occurs at runtime, if the table specified already exists
+ in the database.
+
+
+
+
+
+
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ Description
+
+
+ CREATE TABLE will enter a new table into the current data
+ base. The table will be "owned" by the user issuing the
+ command.
+
+
+ The new table is created as a heap with no initial data.
+ A table can have no more than 1600 columns (realistically,
+ this is limited by the fact that tuple sizes must
+ be less than 8192 bytes), but this limit may be configured
+ lower at some sites. A table cannot have the same name as
+ a system catalog table.
+
+
+
+
+ 1998-04-15
+
+
+ DEFAULT clause
+
+
+
+ DEFAULT value
+
+
+ The DEFAULT clause assigns a default data value to a column.
+
+
+
+
+
+
+
+
+
+
+ value
+
+
+
+ The possible values for expression are:
+
+
+
+ a literal value
+
+
+
+
+ a user function
+
+
+
+
+ a niladic function
+
+
+
+
+
+
+
+
+
+ ERROR: DEFAULT: type mismatched
+
+
+
+ if data type of default value doesn't match the
+ column definition's data type.
+
+
+
+
+
+ The DEFAULT clause assigns a default data value to a column
+ (via a column definition in the CREATE TABLE statement).
+ The data type of a default value must match the column definition's
+ data type.
+
+
+ An INSERT operation that includes a column without a specified
+ default value will assign the NULL value to the column
+ if no explicit data value is provided for it.
+ Default literal means
+ that the default is the specified constant value.
+ Default niladic-function
+ or user-function means
+ that the default
+ is the value of the specified function at the time of the INSERT.
+
+
+ There are two types of niladic functions:
+
+ niladic USER
+
+
+
+ CURRENT_USER / USER
+
+ See CURRENT_USER function
+
+
+
+ SESSION_USER
+
+ not yet supported
+
+
+
+ SYSTEM_USER
+
+ not yet supported
+
+
+
+
+
+
+ niladic datetime
+
+
+
+ CURRENT_DATE
+
+ See CURRENT_DATE function
+
+
+
+ CURRENT_TIME
+
+ See CURRENT_TIME function
+
+
+
+ CURRENT_TIMESTAMP
+
+ See CURRENT_TIMESTAMP function
+
+
+
+
+
+
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ NOT NULL constraint
+
+
+ [ CONSTRAINT name ] NOT NULL
+
+
+ The NOT NULL constraint specifies a rule that a column may
+ contain only non-null values.
+
+
+ The NOT NULL constraint is a column constraint.
+
+
+
+
+
+
+
+
+
+
+ name
+
+
+
+ The optional name of a constraint.
+
+
+
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ Outputs
+
+
+
+
+
+
+
+
+
+
+
+
+ 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.
+
+
+
+
+
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ UNIQUE constraint
+
+
+ Table Constraint definition
+
+
+ [ CONSTRAINT name ] UNIQUE ( column [, ...] )
+
+
+ Column Constraint definition
+
+
+ [ CONSTRAINT name ] UNIQUE
+
+
+ Parameters
+
+
+
+ name
+
+
+
+ An arbitrary name given to a constraint.
+
+
+
+
+
+ column
+
+
+
+ A name of a column in a table.
+
+
+
+
+
+
+ Outputs
+
+
+
+
+
+
+
+
+
+
+
+ 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.
+
+
+ Each UNIQUE 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.
+
+
+
+ PostgreSQL automatically creates a unique index for each UNIQUE
+ constraint, to assure
+ data integrity. See CREATE INDEX for more information.
+
+
+
+
+
+
+ 1998-04-15
+
+
+ CONSTRAINT clause
+
+
+ Table constraint definition
+
+
+ [ CONSTRAINT name ]
+ { PRIMARY KEY constraint |
+ UNIQUE constraint |
+ CHECK constraint }
+
+
+ Column constraint definition
+
+
+ [ CONSTRAINT name ]
+ { NOT NULL constraint |
+ PRIMARY KEY constraint |
+ UNIQUE constraint |
+ CHECK constraint }
+
+
+
+
+
+
+
+
+
+
+
+
+
+ name
+
+
+
+
+ An arbitrary name given to an integrity constraint.
+
+
+
+
+
+
+ constraint
+
+
+
+
+ The definition of the constraint.
+
+
+
+
+
+
+
+
+ A Constraint is a named rule: a SQL object which helps define
+ valid sets of values by putting limits on the results of INSERT,
+ UPDATE or DELETE operations performed on a Base table.
+
+
+ There are two ways to define integrity constraints:
+ Table constraint and Column constraint.
+
+
+ A Table Constraint is an integrity Constraint defined on one or
+ more Columns of a Base table. The four variations of "Table
+ Constraint" are:
+
+ PRIMARY KEY
+ FOREIGN KEY
+ UNIQUE
+ CHECK
+
+
+
+ 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
+
+
+
+ PostgreSQL does not yet (at release 6.3.2) support the FOREIGN KEY or
+ REFERENCES integrity constraints, although the parser will accept them.
+ Foreign keys may be partially emulated by triggers (See CREATE TRIGGER
+ statement)
+
+
+
+
+ PostgreSQL does not yet support either DOMAINs or ASSERTIONs.
+
+
+
+
+
+
+
+ 1998-04-15
+
+ The CHECK constraint
+
+ [ CONSTRAINT name ] CHECK ( condition [, ...] )
+
+
+ Inputs
+
+
+
+
+ name
+
+
+
+ An arbitrary name given to a constraint.
+
+
+
+
+
+ condition
+
+
+
+ Any valid conditional expression.
+
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ Outputs
+
+
+
+
+
+
+ ERROR: ExecAppend: rejected due to CHECK constraint
+ "table_column".
+
+
+
+
+ This error occurs at runtime if one tries to insert an illegal
+ value into a column subject to a CHECK constraint.
+
+
+
+
+
+
+ Description
+
+ The CHECK constraint specifies a rule that a group of one or
+ more columns of a table may contain only those values allowed by
+ the rule.
+
+
+ The CHECK constraint is either a table constraint or a column
+ constraint.
+
+
+ PostgreSQL automatically creates an unique index to assure
+ data integrity. (See CREATE INDEX statement)
+
+
+ The SQL92 CHECK column constraints can only be defined on, and
+ refer to, one column of the table. PostgreSQL does not have
+ this restriction.
+
+
+
+ BUGS in CHECK constraint
+
+ The following CHECK constraints gives a parse error like:
+
+ ERROR: parser: parse error at or near "opname":
+
+
+ CHECK ( column BETWEEN 'A' AND 'Z' )
+ CHECK ( column IN ('A','Z'))
+ CHECK ( column NOT LIKE 'A%')
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ PRIMARY KEY clause
+
+
+ Table constraint definition
+
+
+ [ CONSTRAINT name ] PRIMARY KEY ( column [, ...] )
+
+
+ Column constraint definition
+
+
+ [ CONSTRAINT name ] PRIMARY KEY
+
+
+
+ Parameters
+
+
+
+
+ name
+
+
+
+ An arbitrary name for the constraint.
+
+
+
+
+
+ column
+
+
+
+ The name of a column in the table.
+
+
+
+
+
+
+
+ Outputs
+
+
+ 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,
+ (not duplicates), 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.
+
+
+ A table's set of valid values may be constrained by only one
+ PRIMARY KEY constraint at a time.
+
+
+ The PRIMARY KEY constraint must name a set of columns that is
+ different from the set of columns named by any UNIQUE constraint
+ defined for the same table.
+
+
+
+
+
+ 1998-04-15
+
+
+ Notes
+
+
+ PostgreSQL automatically creates an unique index to assure
+ data integrity. (See CREATE INDEX statement)
+
+
+
+
+
+
+
+
+ Usage
+
+
+ Create table films and table distributors
+
+
+ CREATE TABLE films (
+ code CHARACTER(5) CONSTRAINT firstkey PRIMARY KEY,
+ title CHARACTER VARYING(40) NOT NULL,
+ did DECIMAL(3) NOT NULL,
+ date_prod DATE,
+ kind CHAR(10),
+ len INTERVAL HOUR TO MINUTE
+ );
+
+
+
+ CREATE TABLE distributors (
+ did DECIMAL(03) PRIMARY KEY DEFAULT NEXTVAL('serial'),
+ name VARCHAR(40) NOT NULL CHECK (name <> '')
+ );
+
+
+
+ Create a table with a 2-dimensional array
+
+
+ CREATE TABLE array (
+ vector INT[][]
+ );
+
+
+
+ Define two NOT NULL column constraints on the table distributors
+
+
+ CREATE TABLE distributors (
+ did DECIMAL(3) CONSTRAINT no_null NOT NULL,
+ name VARCHAR(40) NOT NULL
+ );
+
+
+
+ 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(03),
+ date_prod DATE,
+ kind CHAR(10),
+ len INTERVAL HOUR TO MINUTE,
+ CONSTRAINT production UNIQUE(date_prod)
+ );
+
+
+
+ Defines a UNIQUE column constraint for the table distributors.
+ UNIQUE column constraints can only be defined on one column
+ of the table (the following two examples are equivalents).
+
+
+ CREATE TABLE distributors (
+ did DECIMAL(03),
+ name VARCHAR(40) UNIQUE,
+ UNIQUE(name)
+ );
+
+
+
+ CREATE TABLE distributors (
+ did DECIMAL(3),
+ name VARCHAR(40) UNIQUE
+ );
+
+
+
+ Define a CHECK column constraint.
+
+
+ CREATE TABLE distributors (
+ did DECIMAL(3) CHECK (did > 100),
+ name VARCHAR(40)
+ );
+
+
+
+ Define a CHECK table constraint
+
+
+ CREATE TABLE distributors (
+ did DECIMAL(3),
+ name VARCHAR(40)
+ CONSTRAINT con1 CHECK (did > 100 AND name > '')
+ );
+
+
+
+ Define a PRIMARY KEY table constraint for the table films.
+ PRIMARY KEY table constraints can be defined on one or more
+ columns of the table
+
+
+ CREATE TABLE films (
+ code CHAR(05),
+ title VARCHAR(40),
+ did DECIMAL(03),
+ date_prod DATE,
+ kind CHAR(10),
+ len INTERVAL HOUR TO MINUTE,
+ CONSTRAINT code_title PRIMARY KEY(code,title)
+ );
+
+
+
+ Defines a PRIMARY KEY column constraint for table distributors.
+ PRIMARY KEY column constraints can only be defined on one column
+ of the table (the following two examples are equivalents)
+
+
+ CREATE TABLE distributors (
+ did DECIMAL(03),
+ name CHAR VARYING(40),
+ PRIMARY KEY(did)
+ );
+
+ CREATE TABLE distributors (
+ did DECIMAL(03) PRIMARY KEY,
+ name VARCHAR(40)
+ );
+
+
+ To assign a sequence as the default for the column did,
+ and a literal to the column name
+
+
+
+ CREATE TABLE distributors (
+ did DECIMAL(3) DEFAULT NEXTVAL('serial'),
+ name VARCHAR(40) DEFAULT 'luso films'
+ );
+
+
+
+
+ 1998-04-15
+
+
+ Notes
+
+
+ CREATE TABLE/INHERITS is a PostgreSQL language extension.
+
+
+
+
+
+
+
+ Compatibility
+
+
+
+
+
+
+ 1998-04-15
+
+
+ SQL92
+
+
+ In addition to normal CREATE TABLE, SQL92 also supports a
+ CREATE TEMPORARY TABLE statement.
+
+
+ CREATE [ {GLOBAL | LOCAL} ] TEMPORARY TABLE table (
+ column type [DEFAULT value] [CONSTRAINT column_constraint] [, ...] )
+ [CONSTRAINT table_constraint ]
+ [ ON COMMIT {DELETE | PRESERVE} ROWS ]
+
+
+ For temporary tables, the CREATE TEMPORARY TABLE statement
+ names a new table and defines the table's columns and
+ constraints.
+
+
+ The optional ON COMMIT clause of CREATE TEMPORARY TABLE
+ specifies whether or not the temporary table should be emptied of
+ rows whenever COMMIT is executed. If the ON COMMIT clause is
+ omitted, the default option, ON COMMIT DELETE ROWS, is assumed.
+
+
+ To create a temporary table:
+
+
+ CREATE TEMPORARY TABLE actors (
+ id DECIMAL(03),
+ name VARCHAR(40),
+ CONSTRAINT actor_id CHECK (id < 150)
+ ) ON COMMIT DELETE ROWS
+
+
+ TIP: In the current release of PostgreSQL (6.3.2), to create a temporary
+ table you must create and drop the table by explicit commands.
+
+
+
+
+ 1998-04-15
+
+
+ UNIQUE clause
+
+
+ SQL92 specifies some additional capabilities for UNIQUE:
+ Table Constraint definition
+
+
+ [ CONSTRAINT name ]
+ UNIQUE ( column [, ...] )
+ [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
+ [ [ NOT ] DEFERRABLE ]
+
+
+ Column Constraint definition
+
+
+ [ CONSTRAINT name ]
+ UNIQUE
+ [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
+ [ [ NOT ] DEFERRABLE ]
+
+
+
+
+
+ 1998-04-15
+
+
+ NOT NULL clause
+
+
+
+ SQL92 specifies some additional capabilities for NOT NULL:
+
+
+ [ CONSTRAINT name ] NOT NULL
+ [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
+ [ [ NOT ] DEFERRABLE ]
+
+
+
+
+
+ 1998-04-15
+
+
+ DEFAULT clause
+
+
+ SQL92 specifies some additional capabilities for the DEFAULT clause.
+ A DEFAULT clause is used to set the default value for a column
+ or a domain.
+
+
+ DEFAULT literal |
+ niladic USER function |
+ niladic datetime function |
+ NULL
+
+
+
+
+
+ 1998-04-15
+
+
+ CONSTRAINT clause
+
+
+ SQL92 specifies some additional capabilities for CONSTRAINTs,
+ it also defines assertions and domain constraints.
+
+
+ An assertion is a special type of integrity constraint and share
+ the same namespace as other constraints.
+ However, an assertion is not necessarily dependent on one
+ particular base table as constraints are, so SQL-92 provides the
+ CREATE ASSERTION statement as an alternate method for defining a
+ constraint:
+
+
+ CREATE ASSERTION name CHECK ( condition )
+
+
+
+ Domain constraints are defined by CREATE DOMAIN or ALTER DOMAIN
+ statements:
+
+
+ Domain constraint:
+
+
+ [ CONSTRAINT name ]
+ CHECK constraint
+ [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
+ [ [ NOT ] DEFERRABLE ]
+
+
+ Table constraint definition:
+
+
+ [ CONSTRAINT name ]
+ { PRIMARY KEY constraint |
+ FOREIGN KEY constraint |
+ UNIQUE constraint |
+ CHECK constraint }
+ [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
+ [ [ NOT ] DEFERRABLE ]
+
+ Column constraint definition:
+
+
+ [ CONSTRAINT name ]
+ { NOT NULL constraint |
+ PRIMARY KEY constraint |
+ FOREIGN KEY constraint |
+ UNIQUE constraint |
+ CHECK constraint }
+ [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
+ [ [ NOT ] DEFERRABLE ]
+
+
+ A CONSTRAINT definition may contain one deferment attribute
+ clause and/or one initial constraint mode clause, in any order.
+
+
+ NOT DEFERRABLE
+
+
+ means that the Constraint must be checked for
+ violation of its rule after the execution of every SQL statement.
+
+
+
+
+ DEFERRABLE
+
+
+ means that checking of the Constraint may be deferred
+ until some later time, but no later than the end of the current
+ transaction.
+
+
+
+
+
+
+ The constraint mode for every Constraint always has an initial
+ default value which is set for that Constraint at the beginning
+ of a transaction.
+
+
+ INITIALLY IMMEDIATE
+
+
+ means that, as of the start of the transaction,
+ the Constraint must be checked for violation of its rule after the
+ execution of every SQL statement.
+
+
+
+
+ INITIALLY DEFERRED
+
+
+ means that, as of the start of the transaction,
+ checking of the Constraint may be deferred until some later time,
+ but no later than the end of the current transaction.
+
+
+
+
+
+
+
+
+
+ 1998-04-15
+
+
+ CHECK clause
+
+
+ SQL92 specifies some additional capabilities for CHECK:
+
+
+ A CHECK constraint is either a table constraint, a column
+ constraint or a domain constraint.
+
+
+ table constraint definition:
+
+
+ [ CONSTRAINT name ]
+ CHECK ( VALUE condition )
+ [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
+ [ [ NOT ] DEFERRABLE ]
+
+
+ column constraint definition:
+
+
+ [ CONSTRAINT name ]
+ CHECK ( VALUE condition )
+ [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
+ [ [ NOT ] DEFERRABLE ]
+
+
+ domain constraint definition:
+
+
+ [ CONSTRAINT name ]
+ CHECK ( VALUE condition )
+ [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
+ [ [ NOT ] DEFERRABLE ]
+
+
+ CHECK domain constraints can be defined in either
+ a CREATE DOMAIN statement or an ALTER DOMAIN statement:
+
+
+ CREATE DOMAIN duration AS SMALLINT
+ CONSTRAINT minutes CHECK (VALUE IN (90,120,180,240));
+
+ ALTER DOMAIN cities
+ ADD CONSTRAINT new_city CHECK (VALUE LIKE 'L%');
+
+
+
+
+
+
+ 1998-04-15
+
+
+ PRIMARY KEY clause
+
+
+ SQL92 specifies some additional capabilities for PRIMARY KEY:
+
+
+ Table Constraint definition:
+
+
+ [ CONSTRAINT name ]
+ PRIMARY KEY ( column [, ...] )
+ [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
+ [ [ NOT ] DEFERRABLE ]
+
+
+ Column Constraint definition:
+
+
+ [ CONSTRAINT name ]
+ PRIMARY KEY
+ [ {INITIALLY DEFERRED | INITIALLY IMMEDIATE} ]
+ [ [ NOT ] DEFERRABLE ]
+
+
+
+
+
+
+