First version of files from Oliver Elphick.
This commit is contained in:
parent
0acc52ae91
commit
3733bd4627
@ -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:
|
||||
-->
|
||||
-->
|
||||
|
416
doc/src/sgml/ref/create_operator.sgml
Normal file
416
doc/src/sgml/ref/create_operator.sgml
Normal file
@ -0,0 +1,416 @@
|
||||
<REFENTRY ID="SQL-CREATEOPERATOR-1">
|
||||
<REFMETA>
|
||||
<REFENTRYTITLE>
|
||||
CREATE OPERATOR
|
||||
</REFENTRYTITLE>
|
||||
<REFMISCINFO>SQL - Language Statements</REFMISCINFO>
|
||||
</REFMETA>
|
||||
<REFNAMEDIV>
|
||||
<REFNAME>
|
||||
CREATE OPERATOR
|
||||
</REFNAME>
|
||||
<REFPURPOSE>
|
||||
Defines a new user operator.
|
||||
</REFPURPOSE>
|
||||
|
||||
<REFSYNOPSISDIV>
|
||||
<REFSYNOPSISDIVINFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSYNOPSISDIVINFO>
|
||||
<SYNOPSIS>
|
||||
CREATE OPERATOR <replaceable>name</replaceable>
|
||||
([ LEFTARG = <replaceable class="parameter">type1</replaceable> ]
|
||||
[, RIGHTARG = <replaceable class="parameter">type2</replaceable> ]
|
||||
, PROCEDURE = <replaceable class="parameter">func_name</replaceable>
|
||||
[, COMMUTATOR = <replaceable class="parameter">com_op</replaceable> ]
|
||||
[, NEGATOR = <replaceable class="parameter">neg_op</replaceable> ]
|
||||
[, RESTRICT = <replaceable class="parameter">res_proc</replaceable> ]
|
||||
[, HASHES ]
|
||||
[, JOIN = <replaceable class="parameter">join_proc</replaceable> ]
|
||||
[, SORT = <replaceable class="parameter">sort_op</replaceable> [, ...] ]
|
||||
)
|
||||
</SYNOPSIS>
|
||||
|
||||
<REFSECT2 ID="R2-SQL-CREATEOPERATOR-1">
|
||||
<REFSECT2INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT2INFO>
|
||||
<TITLE>
|
||||
Inputs
|
||||
</TITLE>
|
||||
<PARA>
|
||||
</PARA>
|
||||
<VARIABLELIST>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
<VARIABLELIST>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<replaceable class="parameter">name</replaceable>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
The name of an existing aggregate function.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<replaceable class="parameter">type1</replaceable>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<replaceable class="parameter">type2</replaceable>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<replaceable class="parameter">func_name</replaceable>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<replaceable class="parameter">com_op</replaceable>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<replaceable class="parameter">neg_op</replaceable>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<replaceable class="parameter">res_proc</replaceable>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<replaceable class="parameter">join_proc</replaceable>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<replaceable class="parameter">sort_op</replaceable>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
</variablelist>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
</VARIABLELIST>
|
||||
</REFSECT2>
|
||||
|
||||
<REFSECT2 ID="R2-SQL-CREATEOPERATOR-2">
|
||||
<REFSECT2INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT2INFO>
|
||||
<TITLE>
|
||||
Outputs
|
||||
</TITLE>
|
||||
<PARA>
|
||||
</PARA>
|
||||
<VARIABLELIST>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
<VARIABLELIST>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue>CREATE</ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
Message returned if the operator is successfully created.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
</variablelist>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
</VARIABLELIST>
|
||||
</REFSECT2>
|
||||
</REFSYNOPSISDIV>
|
||||
|
||||
<REFSECT1 ID="R1-SQL-CREATEOPERATOR-1">
|
||||
<REFSECT1INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT1INFO>
|
||||
<TITLE>
|
||||
Description
|
||||
</TITLE>
|
||||
<PARA>
|
||||
This command defines a new user operator, operator_name.
|
||||
The user who defines an operator becomes its owner.
|
||||
</para>
|
||||
<para>
|
||||
The operator_name is a sequence of up to sixteen punctua
|
||||
tion characters. The following characters are valid for
|
||||
single-character operator names:<literallayout>
|
||||
|
||||
~ ! @ # % ^ & ` ? </literallayout>
|
||||
</para>
|
||||
<para>
|
||||
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:<literallayout>
|
||||
|
||||
| $ : + - * / < > =</literallayout>
|
||||
</para>
|
||||
<para>
|
||||
The operator "!=" is mapped to "<>" on input, and they are
|
||||
therefore equivalent.
|
||||
</para>
|
||||
<para>
|
||||
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.
|
||||
</para>
|
||||
<para>
|
||||
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.
|
||||
</para>
|
||||
<para>
|
||||
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:
|
||||
<programlisting>
|
||||
"0,0,1,1"::box >>> MYBOXES.description
|
||||
</programlisting>
|
||||
to
|
||||
<programlisting>
|
||||
MYBOXES.description <<< "0,0,1,1"::box</programlisting>
|
||||
</para>
|
||||
<para>
|
||||
This allows the execution code to always use the latter
|
||||
representation and simplifies the query optimizer some
|
||||
what.
|
||||
</para>
|
||||
<para>
|
||||
The negator operator allows the query optimizer to convert
|
||||
<programlisting>
|
||||
NOT MYBOXES.description === "0,0,1,1"::box
|
||||
</programlisting>
|
||||
to
|
||||
<programlisting>
|
||||
MYBOXES.description !== "0,0,1,1"::box
|
||||
</programlisting>
|
||||
</para>
|
||||
<para>
|
||||
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.
|
||||
</para>
|
||||
<para>
|
||||
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.
|
||||
</para>
|
||||
<para>
|
||||
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:
|
||||
<programlisting>
|
||||
MYBOXES.description === MYBOXES2.description
|
||||
</programlisting>
|
||||
but not for a clause of the form:
|
||||
<programlisting>
|
||||
MYBOXES.description <<< MYBOXES2.description.
|
||||
</programlisting>
|
||||
The hashes flag gives the needed information to the query
|
||||
optimizer concerning whether a hash join strategy is
|
||||
usable for the operator in question.</para>
|
||||
<para>
|
||||
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:
|
||||
<programlisting>
|
||||
MYBOXES.description <<< MYBOXES2.description
|
||||
</programlisting>
|
||||
</para>
|
||||
<para>
|
||||
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.
|
||||
</para>
|
||||
<para>
|
||||
The last two pieces of the specification are present so
|
||||
the query optimizer can estimate result sizes. If a
|
||||
clause of the form:
|
||||
<programlisting>
|
||||
MYBOXES.description <<< "0,0,1,1"::box
|
||||
</programlisting>
|
||||
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.
|
||||
</para>
|
||||
<para>
|
||||
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.
|
||||
</para>
|
||||
<para>
|
||||
The difference between the function
|
||||
<programlisting>
|
||||
my_procedure_1 (MYBOXES.description, "0,0,1,1"::box)
|
||||
</programlisting>
|
||||
and the operator
|
||||
<programlisting>
|
||||
MYBOXES.description === "0,0,1,1"::box
|
||||
</programlisting>
|
||||
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.
|
||||
</PARA>
|
||||
|
||||
<REFSECT2 ID="R2-SQL-CREATEOPERATOR-3">
|
||||
<REFSECT2INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT2INFO>
|
||||
<TITLE>
|
||||
Notes
|
||||
</TITLE>
|
||||
<PARA>
|
||||
Refer to <citetitle>PostgreSQL User's Guide</citetitle> chapter 5
|
||||
<comment>
|
||||
This reference must be corrected.
|
||||
</comment>
|
||||
for further information.
|
||||
Refer to DROP OPERATOR statement to drop operators.
|
||||
|
||||
</REFSECT2>
|
||||
|
||||
<REFSECT1 ID="R1-SQL-CREATEOPERATOR-2">
|
||||
<TITLE>
|
||||
Usage
|
||||
</TITLE>
|
||||
<PARA>The following command defines a new operator,
|
||||
area-equality, for the BOX data type.
|
||||
</PARA>
|
||||
<ProgramListing>
|
||||
CREATE OPERATOR === (
|
||||
LEFTARG = box,
|
||||
RIGHTARG = box,
|
||||
PROCEDURE = area_equal_procedure,
|
||||
COMMUTATOR = ===,
|
||||
NEGATOR = !==,
|
||||
RESTRICT = area_restriction_procedure,
|
||||
HASHES,
|
||||
JOIN = area-join-procedure,
|
||||
SORT = <<<, <<<)
|
||||
</ProgramListing>
|
||||
|
||||
|
||||
</REFSECT1>
|
||||
|
||||
<REFSECT1 ID="R1-SQL-CREATEOPERATOR-3">
|
||||
<TITLE>
|
||||
Compatibility
|
||||
</TITLE>
|
||||
<PARA>
|
||||
CREATE OPERATOR is a PostgreSQL extension of SQL.
|
||||
</PARA>
|
||||
|
||||
<REFSECT2 ID="R2-SQL-CREATEOPERATOR-4">
|
||||
<REFSECT2INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT2INFO>
|
||||
<TITLE>
|
||||
SQL92
|
||||
</TITLE>
|
||||
<PARA>
|
||||
There is no CREATE OPERATOR statement on SQL92.
|
||||
</PARA>
|
||||
</refsect2>
|
||||
</refsect1>
|
||||
</REFENTRY>
|
||||
|
||||
<!-- Keep this comment at the end of the file
|
||||
Local variables:
|
||||
mode: sgml
|
||||
sgml-omittag:t
|
||||
sgml-shorttag:t
|
||||
sgml-minimize-attributes:nil
|
||||
sgml-always-quote-attributes:t
|
||||
sgml-indent-step:1
|
||||
sgml-indent-data:t
|
||||
sgml-parent-document:nil
|
||||
sgml-default-dtd-file:"../reference.ced"
|
||||
sgml-exposed-tags:nil
|
||||
sgml-local-catalogs:"/usr/lib/sgml/catalog"
|
||||
sgml-local-ecat-files:nil
|
||||
End:
|
||||
-->
|
363
doc/src/sgml/ref/create_rule.sgml
Normal file
363
doc/src/sgml/ref/create_rule.sgml
Normal file
@ -0,0 +1,363 @@
|
||||
<REFENTRY ID="SQL-CREATERULE-1">
|
||||
<REFMETA>
|
||||
<REFENTRYTITLE>
|
||||
CREATE RULE
|
||||
</REFENTRYTITLE>
|
||||
<REFMISCINFO>SQL - Language Statements</REFMISCINFO>
|
||||
</REFMETA>
|
||||
<REFNAMEDIV>
|
||||
<REFNAME>
|
||||
CREATE RULE
|
||||
</REFNAME>
|
||||
<REFPURPOSE>
|
||||
Defines a new rule.
|
||||
</REFPURPOSE>
|
||||
<REFSYNOPSISDIV>
|
||||
<REFSYNOPSISDIVINFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSYNOPSISDIVINFO>
|
||||
<SYNOPSIS>
|
||||
CREATE RULE <replaceable class="parameter">name</replaceable>
|
||||
AS ON <replaceable class="parameter">event</replaceable>
|
||||
TO <replaceable class="parameter">object</replaceable> [WHERE <replaceable class="parameter">condition</replaceable>]
|
||||
DO [INSTEAD]
|
||||
[<replaceable class="parameter">action</replaceable> | NOTHING ]
|
||||
</SYNOPSIS>
|
||||
|
||||
<REFSECT2 ID="R2-SQL-CREATERULE-1">
|
||||
<REFSECT2INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT2INFO>
|
||||
<TITLE>
|
||||
Inputs
|
||||
</TITLE>
|
||||
<PARA>
|
||||
</PARA>
|
||||
<VARIABLELIST>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
<VARIABLELIST>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue><replaceable class="parameter">name</replaceable></ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
The name of a rule to create.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue><replaceable class="parameter">event</replaceable></ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
Event is one of <literal>select</literal>, <literal>update</literal>, <literal>delete</literal> or <literal>insert</literal>.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue><replaceable class="parameter">object</replaceable></ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
Object is either <replaceable class="parameter">table</replaceable> or <replaceable class="parameter">table</replaceable>.<replaceable class="parameter">column</replaceable>.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue><replaceable class="parameter">condition</replaceable></ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
Any SQL <literal>where</literal> clause. <literal>new</literal> or
|
||||
<literal>current</literal> can appear instead of an instance
|
||||
variable whenever an instance variable is permissible in SQL.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue><replaceable class="parameter">action</replaceable></ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
Any SQL-statement. <literal>new</literal> or
|
||||
<literal>current</literal> can appear instead of an instance
|
||||
variable whenever an instance variable is permissible in SQL.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
</VARIABLELIST>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
</VARIABLELIST>
|
||||
</REFSECT2>
|
||||
|
||||
<REFSECT2 ID="R2-SQL-CREATERULE-2">
|
||||
<REFSECT2INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT2INFO>
|
||||
<TITLE>
|
||||
Outputs
|
||||
</TITLE>
|
||||
<PARA>
|
||||
</PARA>
|
||||
<VARIABLELIST>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
<VARIABLELIST>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue>CREATE</ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
Message returned if the rule is successfully created.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
</variablelist>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
</VARIABLELIST>
|
||||
|
||||
</REFSECT2>
|
||||
</REFSYNOPSISDIV>
|
||||
|
||||
<REFSECT1 ID="R1-SQL-CREATERULE-1">
|
||||
<REFSECT1INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT1INFO>
|
||||
<TITLE>
|
||||
Description
|
||||
</TITLE>
|
||||
<PARA>
|
||||
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 <replaceable class="parameter">event</replaceable>
|
||||
specified in the <literal>on</literal> clause and the
|
||||
<replaceable class="parameter">condition</replaceable> specified in the
|
||||
<literal>where</literal> clause are true for the current instance, the
|
||||
<replaceable class="parameter">action</replaceable> part of the rule is
|
||||
executed. First, however, values from fields in the current instance
|
||||
and/or the new instance are substituted for
|
||||
<literal> current.</literal><replaceable class="parameter">attribute-name</replaceable>
|
||||
and <literal>new.</literal><replaceable class="parameter">attribute-name</replaceable>.
|
||||
</para>
|
||||
<para>
|
||||
The <replaceable class="parameter">action</replaceable> part of the rule
|
||||
executes with the same command and transaction identifier as the user
|
||||
command that caused activation.
|
||||
</para>
|
||||
|
||||
<REFSECT2 ID="R2-SQL-CREATERULE-3">
|
||||
<REFSECT2INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT2INFO>
|
||||
<TITLE>
|
||||
Notes
|
||||
</TITLE>
|
||||
<para>
|
||||
A note of caution about SQL rules is in order. If the same class name
|
||||
or instance variable appears in the
|
||||
<replaceable class="parameter">event</replaceable>, the
|
||||
<replaceable class="parameter">condition</replaceable> and the
|
||||
<replaceable class="parameter">action</replaceable> parts of a rule,
|
||||
they are all considered different tuple variables. More accurately,
|
||||
<literal>new</literal> and <literal>current</literal> are the only tuple
|
||||
variables that are shared between these clauses. For example, the following
|
||||
two rules have the same semantics:
|
||||
<programlisting>
|
||||
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 ...
|
||||
</programlisting>
|
||||
Each rule can have the optional tag <literal>instead</literal>. Without
|
||||
this tag, <replaceable class="parameter">action</replaceable> will be
|
||||
performed in addition to the user command when the
|
||||
<replaceable class="parameter">event</replaceable> in the
|
||||
<replaceable class="parameter">condition</replaceable> part of the rule
|
||||
occurs. Alternately, the
|
||||
<replaceable class="parameter">action</replaceable> part will be done
|
||||
instead of the user command. In this later case, the
|
||||
<replaceable class="parameter">action</replaceable> can be the keyword
|
||||
<literal>nothing</literal>.
|
||||
</para>
|
||||
<para>
|
||||
When choosing between the rewrite and instance rule systems for a
|
||||
particular rule application, remember that in the rewrite system,
|
||||
<literal>current</literal> refers to a relation and some qualifiers
|
||||
whereas in the instance system it refers to an instance (tuple).
|
||||
</para>
|
||||
<para>
|
||||
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>
|
||||
<title>Example of a circular rewrite rule combination.</title>
|
||||
<programlisting>
|
||||
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
|
||||
</programlisting>
|
||||
<para>
|
||||
This attempt to retrieve from EMP will cause Postgres to crash.
|
||||
<programlisting>
|
||||
select * from EMP
|
||||
</programlisting></para>
|
||||
</example>
|
||||
</para>
|
||||
<para>
|
||||
You must have rule definition access to a class in order
|
||||
to define a rule on it (see change acl(l)).
|
||||
<comment>
|
||||
There is no manpage change or change_acl. What is intended?
|
||||
</comment>
|
||||
</PARA>
|
||||
</REFSECT2>
|
||||
</refsect1>
|
||||
|
||||
<REFSECT1 ID="R1-SQL-CREATERULE-2">
|
||||
<TITLE>
|
||||
Usage
|
||||
</TITLE>
|
||||
<PARA>
|
||||
Make Sam get the same salary adjustment as Joe
|
||||
|
||||
<programlisting>
|
||||
create rule example_1 is
|
||||
on update EMP.salary where current.name = "Joe"
|
||||
do update EMP (salary = new.salary)
|
||||
where EMP.name = "Sam"
|
||||
</programlisting>
|
||||
|
||||
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.
|
||||
</para>
|
||||
<para>
|
||||
Make Bill get Joe's salary when it is accessed
|
||||
<programlisting>
|
||||
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"
|
||||
</programlisting>
|
||||
</para>
|
||||
<para>
|
||||
Deny Joe access to the salary of employees in the shoe
|
||||
department. (<function>pg_username()</function> returns the name of
|
||||
the current user)
|
||||
<programlisting>
|
||||
create rule example_3 is
|
||||
on select to EMP.salary
|
||||
where current.dept = "shoe" and pg_username() = "Joe"
|
||||
do instead nothing
|
||||
</programlisting>
|
||||
</para>
|
||||
<para>
|
||||
Create a view of the employees working in the toy department.
|
||||
<programlisting>
|
||||
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"
|
||||
</programlisting>
|
||||
</para>
|
||||
<para>
|
||||
All new employees must make 5,000 or less
|
||||
<programlisting>
|
||||
create rule example_5 is
|
||||
on insert to EMP where new.salary > 5000
|
||||
do update newset salary = 5000
|
||||
</programlisting>
|
||||
</PARA>
|
||||
</REFSECT1>
|
||||
|
||||
<REFSECT1 ID="R1-SQL-CREATERULE-3">
|
||||
<TITLE>
|
||||
Bugs
|
||||
</TITLE>
|
||||
<PARA>
|
||||
<literal>instead</literal> rules do not work properly.
|
||||
</para>
|
||||
<para>
|
||||
The object in a SQL rule cannot be an array reference and
|
||||
cannot have parameters.
|
||||
</para>
|
||||
<para>
|
||||
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., "<literal>foo(emp)</literal>" where
|
||||
"<literal>emp</literal>" is a class) cannot be called anywhere in a rule.
|
||||
</para>
|
||||
<para>
|
||||
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).
|
||||
</PARA>
|
||||
|
||||
<REFSECT1 ID="R1-SQL-CREATERULE-4">
|
||||
<TITLE>
|
||||
Compatibility
|
||||
</TITLE>
|
||||
<PARA>
|
||||
CREATE RULE statement is a PostgreSQL language extension.
|
||||
</PARA>
|
||||
|
||||
<REFSECT2 ID="R2-SQL-CREATERULE-4">
|
||||
<REFSECT2INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT2INFO>
|
||||
<TITLE>
|
||||
SQL92
|
||||
</TITLE>
|
||||
<para>
|
||||
There is no CREATE RULE statement in SQL92.
|
||||
</para>
|
||||
</refsect2>
|
||||
</refsect1>
|
||||
</REFENTRY>
|
||||
|
||||
<!-- Keep this comment at the end of the file
|
||||
Local variables:
|
||||
mode: sgml
|
||||
sgml-omittag:t
|
||||
sgml-shorttag:t
|
||||
sgml-minimize-attributes:nil
|
||||
sgml-always-quote-attributes:t
|
||||
sgml-indent-step:1
|
||||
sgml-indent-data:t
|
||||
sgml-parent-document:nil
|
||||
sgml-default-dtd-file:"../reference.ced"
|
||||
sgml-exposed-tags:nil
|
||||
sgml-local-catalogs:"/usr/lib/sgml/catalog"
|
||||
sgml-local-ecat-files:nil
|
||||
End:
|
||||
-->
|
317
doc/src/sgml/ref/create_sequence.sgml
Normal file
317
doc/src/sgml/ref/create_sequence.sgml
Normal file
@ -0,0 +1,317 @@
|
||||
<REFENTRY ID="SQL-CREATESEQUENCE-1">
|
||||
<REFMETA>
|
||||
<REFENTRYTITLE>
|
||||
CREATE SEQUENCE
|
||||
</REFENTRYTITLE>
|
||||
<REFMISCINFO>SQL - Language Statements</REFMISCINFO>
|
||||
</REFMETA>
|
||||
<REFNAMEDIV>
|
||||
<REFNAME>
|
||||
CREATE SEQUENCE
|
||||
</REFNAME>
|
||||
<REFPURPOSE>
|
||||
creates a new sequence number generator.
|
||||
</REFPURPOSE>
|
||||
|
||||
<REFSYNOPSISDIV>
|
||||
<REFSYNOPSISDIVINFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSYNOPSISDIVINFO>
|
||||
<SYNOPSIS>
|
||||
CREATE SEQUENCE <replaceable class="parameter">seqname</replaceable>
|
||||
[INCREMENT <replaceable class="parameter">increment</replaceable>]
|
||||
[MINVALUE <replaceable class="parameter">minvalue</replaceable>]
|
||||
[MAXVALUE <replaceable class="parameter">maxvalue</replaceable>]
|
||||
[START <replaceable class="parameter">start</replaceable>]
|
||||
[CACHE <replaceable class="parameter">cache</replaceable>]
|
||||
[CYCLE]
|
||||
</SYNOPSIS>
|
||||
|
||||
<REFSECT2 ID="R2-SQL-CREATESEQUENCE-1">
|
||||
<REFSECT2INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT2INFO>
|
||||
<TITLE>
|
||||
Inputs
|
||||
</TITLE>
|
||||
<PARA>
|
||||
</PARA>
|
||||
<VARIABLELIST>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
<VARIABLELIST>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue><replaceable class="parameter">seqname</replaceable></ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
The name of a sequence to be created.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue><replaceable class="parameter">increment</replaceable></ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
The <option>INCREMENT <replaceable class="parameter">increment</replaceable></option> clause is optional. A positive value will make an
|
||||
ascending sequence, a negative one a descending sequence. The default value
|
||||
is 1.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue><replaceable class="parameter">minvalue</replaceable></ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
The optional clause <option>MINVALUE
|
||||
<replaceable class="parameter">minvalue</replaceable></option>
|
||||
determines the minimum value
|
||||
a sequence can be. The defaults are 1 and -2147483647 for
|
||||
ascending and descending sequences, respectively.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue><replaceable class="parameter">maxvalue</replaceable></ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
Use the optional clause <option>MAXVALUE
|
||||
<replaceable class="parameter">maxvalue</replaceable></option> to
|
||||
determine the maximum
|
||||
value for the sequence. The defaults are 2147483647 and -1 for
|
||||
ascending and descending sequences, respectively.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue><replaceable class="parameter">start</replaceable></ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
The optional <option>START
|
||||
<replaceable class="parameter">start</replaceable>
|
||||
clause</option> enables the sequence to begin anywhere.
|
||||
The default starting value is
|
||||
<replaceable class="parameter">minvalue</replaceable>
|
||||
for ascending sequences and
|
||||
<replaceable class="parameter">maxvalue</replaceable>
|
||||
for descending ones.
|
||||
<comment>
|
||||
What happens if the user specifies start outside the range?
|
||||
</comment>
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue><replaceable class="parameter">cache</replaceable></ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
The <option>CACHE <replaceable class="parameter">cache</replaceable></option> 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.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue>CYCLE</ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
The optional CYCLE keyword may be used to enable the sequence
|
||||
to continue when the
|
||||
<replaceable class="parameter">maxvalue</replaceable> or
|
||||
<replaceable class="parameter">minvalue</replaceable> has been
|
||||
reached by
|
||||
an ascending or descending sequence respectively. If the limit is
|
||||
reached, the next number generated will be whatever the
|
||||
<replaceable class="parameter">minvalue</replaceable> or
|
||||
<replaceable class="parameter">maxvalue</replaceable> is,
|
||||
as appropriate.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
</variablelist>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
</variablelist>
|
||||
</REFSECT2>
|
||||
|
||||
<REFSECT2 ID="R2-SQL-CREATESEQUENCE-2">
|
||||
<REFSECT2INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT2INFO>
|
||||
<TITLE>
|
||||
Outputs
|
||||
</TITLE>
|
||||
<PARA>
|
||||
</PARA>
|
||||
<VARIABLELIST>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
<VARIABLELIST>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue>CREATE</ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
Message returned if the command is successful.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
<VARLISTENTRY>
|
||||
<TERM>
|
||||
<ReturnValue>ERROR: amcreate: '<replaceable class="parameter"> seqname</replaceable>' relation already exists</ReturnValue>
|
||||
</TERM>
|
||||
<LISTITEM>
|
||||
<PARA>
|
||||
If the sequence specified already exists.
|
||||
</PARA>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
</variablelist>
|
||||
</LISTITEM>
|
||||
</VARLISTENTRY>
|
||||
</VARIABLELIST>
|
||||
</REFSECT2>
|
||||
</REFSYNOPSISDIV>
|
||||
|
||||
<REFSECT1 ID="R1-SQL-CREATESEQUENCE-1">
|
||||
<REFSECT1INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT1INFO>
|
||||
<TITLE>
|
||||
Description
|
||||
</TITLE>
|
||||
<PARA>
|
||||
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 <replaceable class="parameter">seqname</replaceable>.
|
||||
The generator will be "owned" by the user issuing the command.
|
||||
</PARA>
|
||||
<para>
|
||||
After the sequence is created, you may use the function
|
||||
<function>nextval()</function> with the
|
||||
sequence name as the argument to get a new number from the sequence.
|
||||
The function <function>currval('<replaceable class="parameter">sequence_name</replaceable>')</function> may be used
|
||||
to determine the number returned by the last call to
|
||||
<function>nextval()</function> for the
|
||||
specified sequence in the current session.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Use a query like
|
||||
<programlisting>
|
||||
SELECT * FROM sequence_name;
|
||||
</programlisting>
|
||||
to get the parameters of a sequence.
|
||||
</para>
|
||||
<para>
|
||||
Low-level locking is used to enable multiple simultaneous
|
||||
calls to a generator.
|
||||
</para>
|
||||
|
||||
<REFSECT2 ID="R2-SQL-CREATESEQUENCE-3">
|
||||
<REFSECT2INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT2INFO>
|
||||
<TITLE>
|
||||
Notes
|
||||
</TITLE>
|
||||
<PARA>
|
||||
Refer to the DROP SEQUENCE statement to remove a sequence.
|
||||
</PARA>
|
||||
<para>
|
||||
Each backend uses its own cache to store allocated numbers.
|
||||
Numbers that are cached but not used in the current session will be
|
||||
lost.
|
||||
</para>
|
||||
</REFSECT2>
|
||||
</refsect1>
|
||||
|
||||
<REFSECT1 ID="R1-SQL-CREATESEQUENCE-2">
|
||||
<TITLE>
|
||||
Usage
|
||||
</TITLE>
|
||||
<PARA>
|
||||
Create an ascending sequence called serial, starting at 101:
|
||||
</PARA>
|
||||
<ProgramListing>
|
||||
CREATE SEQUENCE serial START 101;
|
||||
</ProgramListing>
|
||||
<para>
|
||||
Select the next number from this sequence
|
||||
<programlisting>
|
||||
SELECT NEXTVAL ('serial');
|
||||
|
||||
nextval
|
||||
-------
|
||||
114
|
||||
</programlisting>
|
||||
</para>
|
||||
<para>
|
||||
Use this sequence in an INSERT:
|
||||
<programlisting>
|
||||
INSERT INTO distributors VALUES (NEXTVAL ('serial'),'nothing');
|
||||
</programlisting>
|
||||
</para>
|
||||
</REFSECT1>
|
||||
|
||||
<REFSECT1 ID="R1-SQL-CREATESEQUENCE-3">
|
||||
<TITLE>
|
||||
Compatibility
|
||||
</TITLE>
|
||||
<PARA>
|
||||
CREATE SEQUENCE statement is a PostgreSQL language extension.
|
||||
</PARA>
|
||||
|
||||
<REFSECT2 ID="R2-SQL-CREATESEQUENCE-4">
|
||||
<REFSECT2INFO>
|
||||
<DATE>1998-04-15</DATE>
|
||||
</REFSECT2INFO>
|
||||
<TITLE>
|
||||
SQL92
|
||||
</TITLE>
|
||||
<PARA>
|
||||
There is no CREATE SEQUENCE statement on SQL92.
|
||||
</PARA>
|
||||
</refsect2>
|
||||
</refsect1>
|
||||
</REFENTRY>
|
||||
|
||||
|
||||
<!-- Keep this comment at the end of the file
|
||||
Local variables:
|
||||
mode: sgml
|
||||
sgml-omittag:t
|
||||
sgml-shorttag:t
|
||||
sgml-minimize-attributes:nil
|
||||
sgml-always-quote-attributes:t
|
||||
sgml-indent-step:1
|
||||
sgml-indent-data:t
|
||||
sgml-parent-document:nil
|
||||
sgml-default-dtd-file:"../reference.ced"
|
||||
sgml-exposed-tags:nil
|
||||
sgml-local-catalogs:"/usr/lib/sgml/catalog"
|
||||
sgml-local-ecat-files:nil
|
||||
End:
|
||||
-->
|
1304
doc/src/sgml/ref/create_table.sgml
Normal file
1304
doc/src/sgml/ref/create_table.sgml
Normal file
File diff suppressed because it is too large
Load Diff
Loading…
x
Reference in New Issue
Block a user