Creating the Operators and Support Routines

So now we have an access method and an operator class. We still need a set of operators. The procedure for defining operators is discussed in the Red Hat Database SQL Guide and Reference. For the complex_abs_ops operator class on Btrees, the operators we require are:

Suppose the code that implements the functions defined is stored in the file $PGROOT/src/tutorial/complex.c

Part of the C code looks like this: (note that we will show only the equality operator for the rest of the examples. The other four operators are very similar. Refer to complex.c or complex.source for the details.)
#define Mag(c) ((c)->x*(c)->x + (c)->y*(c)->y)

         bool
         complex_abs_eq(Complex *a, Complex *b)
         {
             double amag = Mag(a), bmag = Mag(b);
             return (amag==bmag);
         }

We make the function known to PostgreSQL:
CREATE FUNCTION complex_abs_eq(complex, complex)
              RETURNS bool
              AS '$PGROOT/src/tutorial/complex.so'
              LANGUAGE 'c';

There are some important things to note:

Now we are ready to define the operators:
CREATE OPERATOR = (
     leftarg = complex, rightarg = complex,
     procedure = complex_abs_eq,
     restrict = eqsel, join = eqjoinsel
         )
The important things here are the procedure names (which are the C functions defined above) and the restriction and join selectivity functions. You should just use the selectivity functions used in the example (see complex.source). Note that there are different functions for the less-than, equal, and greater-than cases. These must be supplied, or the optimizer will be unable to make effective use of the index.

The next step is to add entries for these operators to the pg_amop relation. To do this, we will need the oids of the operators we just defined. We will look up the names of all the operators that take two complexes, and pick the ones that we want:
SELECT o.oid AS opoid, o.oprname
    INTO TABLE complex_ops_tmp
    FROM pg_operator o, pg_type t
    WHERE o.oprleft = t.oid and o.oprright = t.oid
      and t.typname = 'complex';

 opoid  | oprname
--------+---------
 277963 | +
 277970 | <
 277971 | <=
 277972 | =
 277973 | >=
 277974 | >
(6 rows)
(Again, some of your oid numbers will almost certainly be different.) The operators we are interested in are those with oids 277970 through 277974. The values you get will probably be different, and you should substitute them for the values below. We will do this with a select statement.

Now we are ready to update pg_amop with our new operator class. The most important thing in this entire discussion is that the operators are ordered, from less than through greater than, in pg_amop. We add the rows we need:
INSERT INTO pg_amop (amopid, amopclaid, amopopr, amopstrategy)
    SELECT am.oid, opcl.oid, c.opoid, 1
        FROM pg_am am, pg_opclass opcl, complex_ops_tmp c
        WHERE amname = 'btree' AND
            opcname = 'complex_abs_ops' AND
            c.oprname = '<';
Now do this for the other operators substituting for the 1 in the third line above and the < in the last line. Note the order: "less than" is 1, "less than or equal" is 2, "equal" is 3, "greater than or equal" is 4, and "greater than" is 5.

The field amopreqcheck is not discussed here; it should always be false for B-tree operators.

The next step is registration of the "support routine" previously described in our discussion of pg_am. The oid of this support routine is stored in the pg_amproc table, keyed by the access method oid and the operator class oid.

First, we need to register the function in PostgreSQL. (We put the C code that implements this routine in the bottom of the file in which we implemented the operator routines.):
    CREATE FUNCTION complex_abs_cmp(complex, complex)
     RETURNS int4
     AS '$PGROOT/src/tutorial/complex.so'
     LANGUAGE 'c';

    SELECT oid, proname FROM pg_proc
     WHERE proname = 'complex_abs_cmp';

  oid   |     proname
--------+-----------------
 277997 | complex_abs_cmp
(1 row)
(Again, your oid number will probably be different.) We can add the new row as follows:
    INSERT INTO pg_amproc (amid, amopclaid, amproc, amprocnum)
        SELECT a.oid, b.oid, c.oid, 1
            FROM pg_am a, pg_opclass b, pg_proc c
            WHERE a.amname = 'btree' AND
                b.opcname = 'complex_abs_ops' AND
                c.proname = 'complex_abs_cmp';

Now that we are done it should be possible to create and use btree indexes on complex columns.