Operators

An operator can be considered to be "syntactic sugar" 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 not merely syntactic sugar, because it carries additional information that helps the query planner optimize queries that use the operator. Much of this section will be devoted to explaining that additional information.

Example

Here is an example of creating an operator for adding two complex numbers. We assume we have already created the definition of type complex. First we need a function that does the work; then we can define the operator:
CREATE FUNCTION complex_add(complex, complex)
    RETURNS complex
    AS 'PGROOT/tutorial/complex.so'
    LANGUAGE 'c';

CREATE OPERATOR + (
    leftarg = complex,
    rightarg = complex,
    procedure = complex_add,
    commutator = +
);

Now we can do:
SELECT (a + b) AS c FROM test_complex;

        c
-----------------
 (5.2,6.05)
 (133.42,144.95)
   

We have shown how to create a binary operator here. To create unary operators, just omit one of leftarg (for left unary) or rightarg (for right unary). The procedure clause and the argument clauses are the only required items in CREATE OPERATOR. The COMMUTATOR clause shown in the example is an optional hint to the query optimizer. Further details about COMMUTATOR and other optimizer hints follow.

Operator Optimization Information

A PostgreSQL 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 considerably speed up the execution of queries that use the operator. However, if you provide them, you must be sure that they are right! Incorrect use of an optimization clause can result in backend crashes, subtly wrong output, or other problems. 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.

Additional optimization clauses might be added in future versions of PostgreSQL. The ones described here are all the ones that release 7.2 understands.

COMMUTATOR

The 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 "<" and ">" for a particular data type are usually each others' commutators, and operator "+" is usually commutative with itself. But operator "-" is usually not commutative with anything.

The left operand type of a commuted 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 PostgreSQL needs to be given to look up the commutator, and that is all that needs be provided in the COMMUTATOR clause.

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 have not yet defined? There are two solutions to this problem:

RESTRICT

The RESTRICT clause, if provided, names a restriction selectivity estimation function for the operator (note that this is a function name, not an operator name). RESTRICT clauses make sense only for binary operators that return boolean. The idea behind a restriction selectivity estimator is to guess what fraction of the rows in a table will satisfy a WHERE-clause condition of the form:
column OP constant
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 WHERE clauses that have this form. (What happens if the constant is on the left, you may be wondering? Well, that is one of the things that COMMUTATOR is for...)

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:

eqsel for =
neqsel for <>
scalarltsel for < or <=
scalargtsel for > or >=

It might seem a little odd that these are the categories, but they make sense if you think about it. "=" will typically accept only a small fraction of the rows in a table; "<>" will typically reject only a small fraction. "<" will accept a fraction that depends on where the given constant falls in the range of values for that table column (which, it happens, is information collected by ANALYZE and made available to the selectivity estimator). "<=" will accept a slightly larger fraction than "<" for the same comparison constant, but they are close enough to not be worth distinguishing, especially since we are not likely to do better than a rough guess anyhow. Similar remarks apply to ">" and ">=".

You can frequently get away with using either eqsel or neqsel for operators that have very high or very low selectivity, even if they are not really equality or inequality. For example, the approximate-equality geometric operators use eqsel on the assumption that they will usually only match a small fraction of the entries in a table.

You can use scalarltsel and 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 routine convert_to_scalar() in src/backend/utils/adt/selfuncs.c. (Eventually, this routine should be replaced by per-datatype functions identified through a column of the pg_type table; but that has not happened yet.) If you do not do this, things will still work, but the optimizer's estimates will not be as good as they could be.

There are additional selectivity functions designed for geometric operators in src/backend/utils/adt/geo_selfuncs.c: areasel, positionsel, and contsel. At this writing these are just stubs, but you may want to use them anyway.

HASHES

The HASHES clause, if present, tells the system that it is permissible to use the hash join method for a join based on this operator. HASHES makes sense only for binary operators that return boolean, and in practice the operator should be equality for some data type.

The assumption underlying hash join is that the join operator can return TRUE only 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. Because of this, it never makes sense to specify HASHES for operators that do not represent equality.

When we talk about "equality", logical equality is not good enough either: the operator should represent pure bitwise equality, because the hash function will be computed on the memory representation of the values regardless of what the bits mean. For example, equality of time intervals is not bitwise equality; the interval equality operator considers two time intervals equal if they have the same duration, whether or not their endpoints are identical. What this means is that a join using "=" between interval fields would yield different results if implemented as a hash join than if implemented another way, because a large fraction of the pairs that should match will hash to different values and will never be compared by the hash join. However, if the optimizer chose to use a different kind of join, the equality operator will find all the pairs that are defined to be equal. We do not want that kind of inconsistency, so we do not mark interval equality as hashable.

There are also machine-dependent ways in which a hash join might fail to do the right thing. For example, if your data type is a structure in which there may be uninteresting pad bits, it is unsafe to mark the equality operator HASHES. (Unless, perhaps, you write your other operators to ensure that the unused bits are always zero.) Another example is that the FLOAT data types are unsafe for hash joins. On machines that meet the IEEE floating point standard, minus zero (-0) and plus zero (+0) are different values (different bit patterns) but they are defined to compare equal. Therefore, if float equality were marked HASHES, a -0 and a +0 would probably not be matched up by a hash join, but they would be matched up by any other join process.

The bottom line is that you should probably only use HASHES for equality operators that are (or could be) implemented by memcmp().

SORT1 and SORT2

The SORT clauses, if present, tell the system that it is permissible to use the mergejoin method for a join based on the current operator. You must specify both or neither. The current operator must be equality for some pair of data types, and the SORT1 and SORT2 clauses name the ordering operator ("<" operator) for the left and right-side data types respectively.

Merge join is based on the idea of sorting the left and right-hand tables into order and then scanning them in parallel. Both data types must therefore be capable of being fully ordered, and the join operator must be one that will succeed only for pairs of values that fall at the "same place" in the sort order. In practice, this means that the join operator must behave like equality. Unlike hashjoin, where the left and right data types should be the same (or at least bitwise equivalent), it is possible to mergejoin two distinct data types so long as they are logically compatible. For example, the int2-versus-int4 equality operator is merge-joinable. We need sorting operators that will bring both data types into a logically compatible sequence.

When specifying merge sort operators, the current operator and both referenced operators must return boolean; the SORT1 operator must have both input data types equal to the current operator's left argument type, and the SORT2 operator must have both input data types equal to the current operator's right argument type. (As with COMMUTATOR and NEGATOR, this means that the operator name is sufficient to specify the operator, and the system is able to make dummy operator entries if you happen to define the equality operator before the other ones.)

In practice you should write SORT clauses only for an "=" operator, and the two referenced operators should always be named "<". Trying to use mergejoin with operators named anything else will result in hopeless confusion, for reasons we will see in a moment.

There are additional restrictions on operators that you mark merge-joinable. These restrictions are not currently checked by CREATE OPERATOR, but a mergejoin may fail at runtime if any are not true: