mirror of
https://git.postgresql.org/git/postgresql.git
synced 2025-01-24 18:55:04 +08:00
527 lines
23 KiB
Plaintext
527 lines
23 KiB
Plaintext
<!--
|
|
$PostgreSQL: pgsql/doc/src/sgml/xoper.sgml,v 1.31 2003/11/29 19:51:38 pgsql Exp $
|
|
-->
|
|
|
|
<sect1 id="xoper">
|
|
<title>User-Defined Operators</title>
|
|
|
|
<indexterm zone="xoper">
|
|
<primary>operator</primary>
|
|
<secondary>user-defined</secondary>
|
|
</indexterm>
|
|
|
|
<Para>
|
|
Every operator is <quote>syntactic sugar</quote> for a call to an
|
|
underlying function that does the real work; so you must
|
|
first create the underlying function before you can create
|
|
the operator. However, an operator is <emphasis>not merely</emphasis>
|
|
syntactic sugar, because it carries additional information
|
|
that helps the query planner optimize queries that use the
|
|
operator. The next section will be devoted to explaining
|
|
that additional information.
|
|
</Para>
|
|
|
|
<Para>
|
|
<productname>PostgreSQL</productname> supports left unary, right
|
|
unary, and binary operators. Operators can be
|
|
overloaded;<indexterm><primary>overloading</primary><secondary>operators</secondary></indexterm>
|
|
that is, the same operator name can be used for different operators
|
|
that have different numbers and types of operands. When a query is
|
|
executed, the system determines the operator to call from the
|
|
number and types of the provided operands.
|
|
</Para>
|
|
|
|
<Para>
|
|
Here is an example of creating an operator for adding two complex
|
|
numbers. We assume we've already created the definition of type
|
|
<type>complex</type> (see <xref linkend="xtypes">). First we need a
|
|
function that does the work, then we can define the operator:
|
|
|
|
<ProgramListing>
|
|
CREATE FUNCTION complex_add(complex, complex)
|
|
RETURNS complex
|
|
AS '<replaceable>filename</replaceable>', 'complex_add'
|
|
LANGUAGE C IMMUTABLE STRICT;
|
|
|
|
CREATE OPERATOR + (
|
|
leftarg = complex,
|
|
rightarg = complex,
|
|
procedure = complex_add,
|
|
commutator = +
|
|
);
|
|
</ProgramListing>
|
|
</Para>
|
|
|
|
<Para>
|
|
Now we could execute a query like this:
|
|
|
|
<screen>
|
|
SELECT (a + b) AS c FROM test_complex;
|
|
|
|
c
|
|
-----------------
|
|
(5.2,6.05)
|
|
(133.42,144.95)
|
|
</screen>
|
|
</Para>
|
|
|
|
<Para>
|
|
We've shown how to create a binary operator here. To create unary
|
|
operators, just omit one of <literal>leftarg</> (for left unary) or
|
|
<literal>rightarg</> (for right unary). The <literal>procedure</>
|
|
clause and the argument clauses are the only required items in
|
|
<command>CREATE OPERATOR</command>. The <literal>commutator</>
|
|
clause shown in the example is an optional hint to the query
|
|
optimizer. Further details about <literal>commutator</> and other
|
|
optimizer hints appear in the next section.
|
|
</Para>
|
|
</sect1>
|
|
|
|
<sect1 id="xoper-optimization">
|
|
<title>Operator Optimization Information</title>
|
|
|
|
<para>
|
|
A <ProductName>PostgreSQL</ProductName> operator definition can include
|
|
several optional clauses that tell the system useful things about how
|
|
the operator behaves. These clauses should be provided whenever
|
|
appropriate, because they can make for considerable speedups in execution
|
|
of queries that use the operator. But if you provide them, you must be
|
|
sure that they are right! Incorrect use of an optimization clause can
|
|
result in server process crashes, subtly wrong output, or other Bad Things.
|
|
You can always leave out an optimization clause if you are not sure
|
|
about it; the only consequence is that queries might run slower than
|
|
they need to.
|
|
</para>
|
|
|
|
<para>
|
|
Additional optimization clauses might be added in future versions of
|
|
<ProductName>PostgreSQL</ProductName>. The ones described here are all
|
|
the ones that release &version; understands.
|
|
</para>
|
|
|
|
<sect2>
|
|
<title><literal>COMMUTATOR</></title>
|
|
|
|
<para>
|
|
The <literal>COMMUTATOR</> clause, if provided, names an operator that is the
|
|
commutator of the operator being defined. We say that operator A is the
|
|
commutator of operator B if (x A y) equals (y B x) for all possible input
|
|
values x, y. Notice that B is also the commutator of A. For example,
|
|
operators <literal><</> and <literal>></> for a particular data type are usually each others'
|
|
commutators, and operator <literal>+</> is usually commutative with itself.
|
|
But operator <literal>-</> is usually not commutative with anything.
|
|
</para>
|
|
|
|
<para>
|
|
The left operand type of a commutable operator is the same as the
|
|
right operand type of its commutator, and vice versa. So the name of
|
|
the commutator operator is all that <ProductName>PostgreSQL</ProductName>
|
|
needs to be given to look up the commutator, and that's all that needs to
|
|
be provided in the <literal>COMMUTATOR</> clause.
|
|
</para>
|
|
|
|
<para>
|
|
It's critical to provide commutator information for operators that
|
|
will be used in indexes and join clauses, because this allows the
|
|
query optimizer to <quote>flip around</> such a clause to the forms
|
|
needed for different plan types. For example, consider a query with
|
|
a WHERE clause like <literal>tab1.x = tab2.y</>, where <literal>tab1.x</>
|
|
and <literal>tab2.y</> are of a user-defined type, and suppose that
|
|
<literal>tab2.y</> is indexed. The optimizer cannot generate an
|
|
index scan unless it can determine how to flip the clause around to
|
|
<literal>tab2.y = tab1.x</>, because the index-scan machinery expects
|
|
to see the indexed column on the left of the operator it is given.
|
|
<ProductName>PostgreSQL</ProductName> will <emphasis>not</> simply
|
|
assume that this is a valid transformation --- the creator of the
|
|
<literal>=</> operator must specify that it is valid, by marking the
|
|
operator with commutator information.
|
|
</para>
|
|
|
|
<para>
|
|
When you are defining a self-commutative operator, you just do it.
|
|
When you are defining a pair of commutative operators, things are
|
|
a little trickier: how can the first one to be defined refer to the
|
|
other one, which you haven't defined yet? There are two solutions
|
|
to this problem:
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
One way is to omit the <literal>COMMUTATOR</> clause in the first operator that
|
|
you define, and then provide one in the second operator's definition.
|
|
Since <ProductName>PostgreSQL</ProductName> knows that commutative
|
|
operators come in pairs, when it sees the second definition it will
|
|
automatically go back and fill in the missing <literal>COMMUTATOR</> clause in
|
|
the first definition.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
The other, more straightforward way is just to include <literal>COMMUTATOR</> clauses
|
|
in both definitions. When <ProductName>PostgreSQL</ProductName> processes
|
|
the first definition and realizes that <literal>COMMUTATOR</> refers to a nonexistent
|
|
operator, the system will make a dummy entry for that operator in the
|
|
system catalog. This dummy entry will have valid data only
|
|
for the operator name, left and right operand types, and result type,
|
|
since that's all that <ProductName>PostgreSQL</ProductName> can deduce
|
|
at this point. The first operator's catalog entry will link to this
|
|
dummy entry. Later, when you define the second operator, the system
|
|
updates the dummy entry with the additional information from the second
|
|
definition. If you try to use the dummy operator before it's been filled
|
|
in, you'll just get an error message.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>NEGATOR</></title>
|
|
|
|
<para>
|
|
The <literal>NEGATOR</> clause, if provided, names an operator that is the
|
|
negator of the operator being defined. We say that operator A
|
|
is the negator of operator B if both return Boolean results and
|
|
(x A y) equals NOT (x B y) for all possible inputs x, y.
|
|
Notice that B is also the negator of A.
|
|
For example, <literal><</> and <literal>>=</> are a negator pair for most data types.
|
|
An operator can never validly be its own negator.
|
|
</para>
|
|
|
|
<para>
|
|
Unlike commutators, a pair of unary operators could validly be marked
|
|
as each others' negators; that would mean (A x) equals NOT (B x)
|
|
for all x, or the equivalent for right unary operators.
|
|
</para>
|
|
|
|
<para>
|
|
An operator's negator must have the same left and/or right operand types
|
|
as the operator to be defined, so just as with <literal>COMMUTATOR</>, only the operator
|
|
name need be given in the <literal>NEGATOR</> clause.
|
|
</para>
|
|
|
|
<para>
|
|
Providing a negator is very helpful to the query optimizer since
|
|
it allows expressions like <literal>NOT (x = y)</> to be simplified into
|
|
<literal>x <> y</>. This comes up more often than you might think, because
|
|
<literal>NOT</> operations can be inserted as a consequence of other rearrangements.
|
|
</para>
|
|
|
|
<para>
|
|
Pairs of negator operators can be defined using the same methods
|
|
explained above for commutator pairs.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>RESTRICT</></title>
|
|
|
|
<para>
|
|
The <literal>RESTRICT</> clause, if provided, names a restriction selectivity
|
|
estimation function for the operator. (Note that this is a function
|
|
name, not an operator name.) <literal>RESTRICT</> clauses only make sense for
|
|
binary operators that return <type>boolean</>. The idea behind a restriction
|
|
selectivity estimator is to guess what fraction of the rows in a
|
|
table will satisfy a <literal>WHERE</literal>-clause condition of the form
|
|
<ProgramListing>
|
|
column OP constant
|
|
</ProgramListing>
|
|
for the current operator and a particular constant value.
|
|
This assists the optimizer by
|
|
giving it some idea of how many rows will be eliminated by <literal>WHERE</>
|
|
clauses that have this form. (What happens if the constant is on
|
|
the left, you may be wondering? Well, that's one of the things that
|
|
<literal>COMMUTATOR</> is for...)
|
|
</para>
|
|
|
|
<para>
|
|
Writing new restriction selectivity estimation functions is far beyond
|
|
the scope of this chapter, but fortunately you can usually just use
|
|
one of the system's standard estimators for many of your own operators.
|
|
These are the standard restriction estimators:
|
|
<simplelist>
|
|
<member><function>eqsel</> for <literal>=</></member>
|
|
<member><function>neqsel</> for <literal><></></member>
|
|
<member><function>scalarltsel</> for <literal><</> or <literal><=</></member>
|
|
<member><function>scalargtsel</> for <literal>></> or <literal>>=</></member>
|
|
</simplelist>
|
|
It might seem a little odd that these are the categories, but they
|
|
make sense if you think about it. <literal>=</> will typically accept only
|
|
a small fraction of the rows in a table; <literal><></> will typically reject
|
|
only a small fraction. <literal><</> will accept a fraction that depends on
|
|
where the given constant falls in the range of values for that table
|
|
column (which, it just so happens, is information collected by
|
|
<command>ANALYZE</command> and made available to the selectivity estimator).
|
|
<literal><=</> will accept a slightly larger fraction than <literal><</> for the same
|
|
comparison constant, but they're close enough to not be worth
|
|
distinguishing, especially since we're not likely to do better than a
|
|
rough guess anyhow. Similar remarks apply to <literal>></> and <literal>>=</>.
|
|
</para>
|
|
|
|
<para>
|
|
You can frequently get away with using either <function>eqsel</function> or <function>neqsel</function> for
|
|
operators that have very high or very low selectivity, even if they
|
|
aren't really equality or inequality. For example, the
|
|
approximate-equality geometric operators use <function>eqsel</function> on the assumption that
|
|
they'll usually only match a small fraction of the entries in a table.
|
|
</para>
|
|
|
|
<para>
|
|
You can use <function>scalarltsel</> and <function>scalargtsel</> for comparisons on data types that
|
|
have some sensible means of being converted into numeric scalars for
|
|
range comparisons. If possible, add the data type to those understood
|
|
by the function <function>convert_to_scalar()</function> in <filename>src/backend/utils/adt/selfuncs.c</filename>.
|
|
(Eventually, this function should be replaced by per-data-type functions
|
|
identified through a column of the <classname>pg_type</> system catalog; but that hasn't happened
|
|
yet.) If you do not do this, things will still work, but the optimizer's
|
|
estimates won't be as good as they could be.
|
|
</para>
|
|
|
|
<para>
|
|
There are additional selectivity estimation functions designed for geometric
|
|
operators in <filename>src/backend/utils/adt/geo_selfuncs.c</filename>: <function>areasel</function>, <function>positionsel</function>,
|
|
and <function>contsel</function>. At this writing these are just stubs, but you may want
|
|
to use them (or even better, improve them) anyway.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>JOIN</></title>
|
|
|
|
<para>
|
|
The <literal>JOIN</> clause, if provided, names a join selectivity
|
|
estimation function for the operator. (Note that this is a function
|
|
name, not an operator name.) <literal>JOIN</> clauses only make sense for
|
|
binary operators that return <type>boolean</type>. The idea behind a join
|
|
selectivity estimator is to guess what fraction of the rows in a
|
|
pair of tables will satisfy a <literal>WHERE</>-clause condition of the form
|
|
<ProgramListing>
|
|
table1.column1 OP table2.column2
|
|
</ProgramListing>
|
|
for the current operator. As with the <literal>RESTRICT</literal> clause, this helps
|
|
the optimizer very substantially by letting it figure out which
|
|
of several possible join sequences is likely to take the least work.
|
|
</para>
|
|
|
|
<para>
|
|
As before, this chapter will make no attempt to explain how to write
|
|
a join selectivity estimator function, but will just suggest that
|
|
you use one of the standard estimators if one is applicable:
|
|
<simplelist>
|
|
<member><function>eqjoinsel</> for <literal>=</></member>
|
|
<member><function>neqjoinsel</> for <literal><></></member>
|
|
<member><function>scalarltjoinsel</> for <literal><</> or <literal><=</></member>
|
|
<member><function>scalargtjoinsel</> for <literal>></> or <literal>>=</></member>
|
|
<member><function>areajoinsel</> for 2D area-based comparisons</member>
|
|
<member><function>positionjoinsel</> for 2D position-based comparisons</member>
|
|
<member><function>contjoinsel</> for 2D containment-based comparisons</member>
|
|
</simplelist>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>HASHES</></title>
|
|
|
|
<para>
|
|
The <literal>HASHES</literal> clause, if present, tells the system that
|
|
it is permissible to use the hash join method for a join based on this
|
|
operator. <literal>HASHES</> only makes sense for a binary operator that
|
|
returns <literal>boolean</>, and in practice the operator had better be
|
|
equality for some data type.
|
|
</para>
|
|
|
|
<para>
|
|
The assumption underlying hash join is that the join operator can
|
|
only return true for pairs of left and right values that hash to the
|
|
same hash code. If two values get put in different hash buckets, the
|
|
join will never compare them at all, implicitly assuming that the
|
|
result of the join operator must be false. So it never makes sense
|
|
to specify <literal>HASHES</literal> for operators that do not represent
|
|
equality.
|
|
</para>
|
|
|
|
<para>
|
|
To be marked <literal>HASHES</literal>, the join operator must appear
|
|
in a hash index operator class. This is not enforced when you create
|
|
the operator, since of course the referencing operator class couldn't
|
|
exist yet. But attempts to use the operator in hash joins will fail
|
|
at runtime if no such operator class exists. The system needs the
|
|
operator class to find the data-type-specific hash function for the
|
|
operator's input data type. Of course, you must also supply a suitable
|
|
hash function before you can create the operator class.
|
|
</para>
|
|
|
|
<para>
|
|
Care should be exercised when preparing a hash function, because there
|
|
are machine-dependent ways in which it might fail to do the right thing.
|
|
For example, if your data type is a structure in which there may be
|
|
uninteresting pad bits, you can't simply pass the whole structure to
|
|
<function>hash_any</>. (Unless you write your other operators and
|
|
functions to ensure that the unused bits are always zero, which is the
|
|
recommended strategy.)
|
|
Another example is that on machines that meet the <acronym>IEEE</>
|
|
floating-point standard, negative zero and positive zero are different
|
|
values (different bit patterns) but they are defined to compare equal.
|
|
If a float value might contain negative zero then extra steps are needed
|
|
to ensure it generates the same hash value as positive zero.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The function underlying a hash-joinable operator must be marked
|
|
immutable or stable. If it is volatile, the system will never
|
|
attempt to use the operator for a hash join.
|
|
</para>
|
|
</note>
|
|
|
|
<note>
|
|
<para>
|
|
If a hash-joinable operator has an underlying function that is marked
|
|
strict, the
|
|
function must also be complete: that is, it should return true or
|
|
false, never null, for any two nonnull inputs. If this rule is
|
|
not followed, hash-optimization of <literal>IN</> operations may
|
|
generate wrong results. (Specifically, <literal>IN</> might return
|
|
false where the correct answer according to the standard would be null; or it might
|
|
yield an error complaining that it wasn't prepared for a null result.)
|
|
</para>
|
|
</note>
|
|
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>MERGES</> (<literal>SORT1</>, <literal>SORT2</>, <literal>LTCMP</>, <literal>GTCMP</>)</title>
|
|
|
|
<para>
|
|
The <literal>MERGES</literal> clause, if present, tells the system that
|
|
it is permissible to use the merge-join method for a join based on this
|
|
operator. <literal>MERGES</> only makes sense for a binary operator that
|
|
returns <literal>boolean</>, and in practice the operator must represent
|
|
equality for some data type or pair of data types.
|
|
</para>
|
|
|
|
<para>
|
|
Merge join is based on the idea of sorting the left- and right-hand tables
|
|
into order and then scanning them in parallel. So, both data types must
|
|
be capable of being fully ordered, and the join operator must be one
|
|
that can only succeed for pairs of values that fall at the
|
|
<quote>same place</>
|
|
in the sort order. In practice this means that the join operator must
|
|
behave like equality. But unlike hash join, where the left and right
|
|
data types had better be the same (or at least bitwise equivalent),
|
|
it is possible to merge-join two
|
|
distinct data types so long as they are logically compatible. For
|
|
example, the <type>smallint</type>-versus-<type>integer</type> equality operator
|
|
is merge-joinable.
|
|
We only need sorting operators that will bring both data types into a
|
|
logically compatible sequence.
|
|
</para>
|
|
|
|
<para>
|
|
Execution of a merge join requires that the system be able to identify
|
|
four operators related to the merge-join equality operator: less-than
|
|
comparison for the left operand data type, less-than comparison for the
|
|
right operand data type, less-than comparison between the two data types, and
|
|
greater-than comparison between the two data types. (These are actually
|
|
four distinct operators if the merge-joinable operator has two different
|
|
operand data types; but when the operand types are the same the three
|
|
less-than operators are all the same operator.)
|
|
It is possible to
|
|
specify these operators individually by name, as the <literal>SORT1</>,
|
|
<literal>SORT2</>, <literal>LTCMP</>, and <literal>GTCMP</> options
|
|
respectively. The system will fill in the default names
|
|
<literal><</>, <literal><</>, <literal><</>, <literal>></>
|
|
respectively if any of these are omitted when <literal>MERGES</> is
|
|
specified. Also, <literal>MERGES</> will be assumed to be implied if any
|
|
of these four operator options appear, so it is possible to specify
|
|
just some of them and let the system fill in the rest.
|
|
</para>
|
|
|
|
<para>
|
|
The operand data types of the four comparison operators can be deduced
|
|
from the operand types of the merge-joinable operator, so just as with
|
|
<literal>COMMUTATOR</>, only the operator names need be given in these
|
|
clauses. Unless you are using peculiar choices of operator names,
|
|
it's sufficient to write <literal>MERGES</> and let the system fill in
|
|
the details.
|
|
(As with <literal>COMMUTATOR</> and <literal>NEGATOR</>, the system is
|
|
able to make dummy
|
|
operator entries if you happen to define the equality operator before
|
|
the other ones.)
|
|
</para>
|
|
|
|
<para>
|
|
There are additional restrictions on operators that you mark
|
|
merge-joinable. These restrictions are not currently checked by
|
|
<command>CREATE OPERATOR</command>, but errors may occur when
|
|
the operator is used if any are not true:
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
A merge-joinable equality operator must have a merge-joinable
|
|
commutator (itself if the two operand data types are the same, or a related
|
|
equality operator if they are different).
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
If there is a merge-joinable operator relating any two data types
|
|
A and B, and another merge-joinable operator relating B to any
|
|
third data type C, then A and C must also have a merge-joinable
|
|
operator; in other words, having a merge-joinable operator must
|
|
be transitive.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
Bizarre results will ensue at runtime if the four comparison
|
|
operators you name do not sort the data values compatibly.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The function underlying a merge-joinable operator must be marked
|
|
immutable or stable. If it is volatile, the system will never
|
|
attempt to use the operator for a merge join.
|
|
</para>
|
|
</note>
|
|
|
|
<note>
|
|
<para>
|
|
In <ProductName>PostgreSQL</ProductName> versions before 7.3,
|
|
the <literal>MERGES</> shorthand was not available: to make a
|
|
merge-joinable operator one had to write both <literal>SORT1</> and
|
|
<literal>SORT2</> explicitly. Also, the <literal>LTCMP</> and
|
|
<literal>GTCMP</>
|
|
options did not exist; the names of those operators were hardwired as
|
|
<literal><</> and <literal>></> respectively.
|
|
</para>
|
|
</note>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<!-- Keep this comment at the end of the file
|
|
Local variables:
|
|
mode:sgml
|
|
sgml-omittag:nil
|
|
sgml-shorttag:t
|
|
sgml-minimize-attributes:nil
|
|
sgml-always-quote-attributes:t
|
|
sgml-indent-step:1
|
|
sgml-indent-data:t
|
|
sgml-parent-document:nil
|
|
sgml-default-dtd-file:"./reference.ced"
|
|
sgml-exposed-tags:nil
|
|
sgml-local-catalogs:("/usr/lib/sgml/catalog")
|
|
sgml-local-ecat-files:nil
|
|
End:
|
|
-->
|