Fix spelling error in docs.
[PostgreSQL.git] / doc / src / sgml / xindex.sgml
blob2bb01644fd9a656288aea1e4905a0f49234cbae9
1 <!-- $PostgreSQL$ -->
3 <sect1 id="xindex">
4 <title>Interfacing Extensions To Indexes</title>
6 <indexterm zone="xindex">
7 <primary>index</primary>
8 <secondary>for user-defined data type</secondary>
9 </indexterm>
11 <para>
12 The procedures described thus far let you define new types, new
13 functions, and new operators. However, we cannot yet define an
14 index on a column of a new data type. To do this, we must define an
15 <firstterm>operator class</> for the new data type. Later in this
16 section, we will illustrate this concept in an example: a new
17 operator class for the B-tree index method that stores and sorts
18 complex numbers in ascending absolute value order.
19 </para>
21 <para>
22 Operator classes can be grouped into <firstterm>operator families</>
23 to show the relationships between semantically compatible classes.
24 When only a single data type is involved, an operator class is sufficient,
25 so we'll focus on that case first and then return to operator families.
26 </para>
28 <sect2 id="xindex-opclass">
29 <title>Index Methods and Operator Classes</title>
31 <para>
32 The <classname>pg_am</classname> table contains one row for every
33 index method (internally known as access method). Support for
34 regular access to tables is built into
35 <productname>PostgreSQL</productname>, but all index methods are
36 described in <classname>pg_am</classname>. It is possible to add a
37 new index method by defining the required interface routines and
38 then creating a row in <classname>pg_am</classname> &mdash; but that is
39 beyond the scope of this chapter (see <xref linkend="indexam">).
40 </para>
42 <para>
43 The routines for an index method do not directly know anything
44 about the data types that the index method will operate on.
45 Instead, an <firstterm>operator
46 class</><indexterm><primary>operator class</></indexterm>
47 identifies the set of operations that the index method needs to use
48 to work with a particular data type. Operator classes are so
49 called because one thing they specify is the set of
50 <literal>WHERE</>-clause operators that can be used with an index
51 (i.e., can be converted into an index-scan qualification). An
52 operator class can also specify some <firstterm>support
53 procedures</> that are needed by the internal operations of the
54 index method, but do not directly correspond to any
55 <literal>WHERE</>-clause operator that can be used with the index.
56 </para>
58 <para>
59 It is possible to define multiple operator classes for the same
60 data type and index method. By doing this, multiple
61 sets of indexing semantics can be defined for a single data type.
62 For example, a B-tree index requires a sort ordering to be defined
63 for each data type it works on.
64 It might be useful for a complex-number data type
65 to have one B-tree operator class that sorts the data by complex
66 absolute value, another that sorts by real part, and so on.
67 Typically, one of the operator classes will be deemed most commonly
68 useful and will be marked as the default operator class for that
69 data type and index method.
70 </para>
72 <para>
73 The same operator class name
74 can be used for several different index methods (for example, both B-tree
75 and hash index methods have operator classes named
76 <literal>int4_ops</literal>), but each such class is an independent
77 entity and must be defined separately.
78 </para>
79 </sect2>
81 <sect2 id="xindex-strategies">
82 <title>Index Method Strategies</title>
84 <para>
85 The operators associated with an operator class are identified by
86 <quote>strategy numbers</>, which serve to identify the semantics of
87 each operator within the context of its operator class.
88 For example, B-trees impose a strict ordering on keys, lesser to greater,
89 and so operators like <quote>less than</> and <quote>greater than or equal
90 to</> are interesting with respect to a B-tree.
91 Because
92 <productname>PostgreSQL</productname> allows the user to define operators,
93 <productname>PostgreSQL</productname> cannot look at the name of an operator
94 (e.g., <literal>&lt;</> or <literal>&gt;=</>) and tell what kind of
95 comparison it is. Instead, the index method defines a set of
96 <quote>strategies</>, which can be thought of as generalized operators.
97 Each operator class specifies which actual operator corresponds to each
98 strategy for a particular data type and interpretation of the index
99 semantics.
100 </para>
102 <para>
103 The B-tree index method defines five strategies, shown in <xref
104 linkend="xindex-btree-strat-table">.
105 </para>
107 <table tocentry="1" id="xindex-btree-strat-table">
108 <title>B-tree Strategies</title>
109 <tgroup cols="2">
110 <thead>
111 <row>
112 <entry>Operation</entry>
113 <entry>Strategy Number</entry>
114 </row>
115 </thead>
116 <tbody>
117 <row>
118 <entry>less than</entry>
119 <entry>1</entry>
120 </row>
121 <row>
122 <entry>less than or equal</entry>
123 <entry>2</entry>
124 </row>
125 <row>
126 <entry>equal</entry>
127 <entry>3</entry>
128 </row>
129 <row>
130 <entry>greater than or equal</entry>
131 <entry>4</entry>
132 </row>
133 <row>
134 <entry>greater than</entry>
135 <entry>5</entry>
136 </row>
137 </tbody>
138 </tgroup>
139 </table>
141 <para>
142 Hash indexes support only equality comparisons, and so they use only one
143 strategy, shown in <xref linkend="xindex-hash-strat-table">.
144 </para>
146 <table tocentry="1" id="xindex-hash-strat-table">
147 <title>Hash Strategies</title>
148 <tgroup cols="2">
149 <thead>
150 <row>
151 <entry>Operation</entry>
152 <entry>Strategy Number</entry>
153 </row>
154 </thead>
155 <tbody>
156 <row>
157 <entry>equal</entry>
158 <entry>1</entry>
159 </row>
160 </tbody>
161 </tgroup>
162 </table>
164 <para>
165 GiST indexes are more flexible: they do not have a fixed set of
166 strategies at all. Instead, the <quote>consistency</> support routine
167 of each particular GiST operator class interprets the strategy numbers
168 however it likes. As an example, several of the built-in GiST index
169 operator classes index two-dimensional geometric objects, providing
170 the <quote>R-tree</> strategies shown in
171 <xref linkend="xindex-rtree-strat-table">. Four of these are true
172 two-dimensional tests (overlaps, same, contains, contained by);
173 four of them consider only the X direction; and the other four
174 provide the same tests in the Y direction.
175 </para>
177 <table tocentry="1" id="xindex-rtree-strat-table">
178 <title>GiST Two-Dimensional <quote>R-tree</> Strategies</title>
179 <tgroup cols="2">
180 <thead>
181 <row>
182 <entry>Operation</entry>
183 <entry>Strategy Number</entry>
184 </row>
185 </thead>
186 <tbody>
187 <row>
188 <entry>strictly left of</entry>
189 <entry>1</entry>
190 </row>
191 <row>
192 <entry>does not extend to right of</entry>
193 <entry>2</entry>
194 </row>
195 <row>
196 <entry>overlaps</entry>
197 <entry>3</entry>
198 </row>
199 <row>
200 <entry>does not extend to left of</entry>
201 <entry>4</entry>
202 </row>
203 <row>
204 <entry>strictly right of</entry>
205 <entry>5</entry>
206 </row>
207 <row>
208 <entry>same</entry>
209 <entry>6</entry>
210 </row>
211 <row>
212 <entry>contains</entry>
213 <entry>7</entry>
214 </row>
215 <row>
216 <entry>contained by</entry>
217 <entry>8</entry>
218 </row>
219 <row>
220 <entry>does not extend above</entry>
221 <entry>9</entry>
222 </row>
223 <row>
224 <entry>strictly below</entry>
225 <entry>10</entry>
226 </row>
227 <row>
228 <entry>strictly above</entry>
229 <entry>11</entry>
230 </row>
231 <row>
232 <entry>does not extend below</entry>
233 <entry>12</entry>
234 </row>
235 </tbody>
236 </tgroup>
237 </table>
239 <para>
240 GIN indexes are similar to GiST indexes in flexibility: they don't have a
241 fixed set of strategies. Instead the support routines of each operator
242 class interpret the strategy numbers according to the operator class's
243 definition. As an example, the strategy numbers used by the built-in
244 operator classes for arrays are
245 shown in <xref linkend="xindex-gin-array-strat-table">.
246 </para>
248 <table tocentry="1" id="xindex-gin-array-strat-table">
249 <title>GIN Array Strategies</title>
250 <tgroup cols="2">
251 <thead>
252 <row>
253 <entry>Operation</entry>
254 <entry>Strategy Number</entry>
255 </row>
256 </thead>
257 <tbody>
258 <row>
259 <entry>overlap</entry>
260 <entry>1</entry>
261 </row>
262 <row>
263 <entry>contains</entry>
264 <entry>2</entry>
265 </row>
266 <row>
267 <entry>is contained by</entry>
268 <entry>3</entry>
269 </row>
270 <row>
271 <entry>equal</entry>
272 <entry>4</entry>
273 </row>
274 </tbody>
275 </tgroup>
276 </table>
278 <para>
279 Notice that all strategy operators return Boolean values. In
280 practice, all operators defined as index method strategies must
281 return type <type>boolean</type>, since they must appear at the top
282 level of a <literal>WHERE</> clause to be used with an index.
283 </para>
284 </sect2>
286 <sect2 id="xindex-support">
287 <title>Index Method Support Routines</title>
289 <para>
290 Strategies aren't usually enough information for the system to figure
291 out how to use an index. In practice, the index methods require
292 additional support routines in order to work. For example, the B-tree
293 index method must be able to compare two keys and determine whether one
294 is greater than, equal to, or less than the other. Similarly, the
295 hash index method must be able to compute hash codes for key values.
296 These operations do not correspond to operators used in qualifications in
297 SQL commands; they are administrative routines used by
298 the index methods, internally.
299 </para>
301 <para>
302 Just as with strategies, the operator class identifies which specific
303 functions should play each of these roles for a given data type and
304 semantic interpretation. The index method defines the set
305 of functions it needs, and the operator class identifies the correct
306 functions to use by assigning them to the <quote>support function numbers</>
307 specified by the index method.
308 </para>
310 <para>
311 B-trees require a single support function, shown in <xref
312 linkend="xindex-btree-support-table">.
313 </para>
315 <table tocentry="1" id="xindex-btree-support-table">
316 <title>B-tree Support Functions</title>
317 <tgroup cols="2">
318 <thead>
319 <row>
320 <entry>Function</entry>
321 <entry>Support Number</entry>
322 </row>
323 </thead>
324 <tbody>
325 <row>
326 <entry>
327 Compare two keys and return an integer less than zero, zero, or
328 greater than zero, indicating whether the first key is less than,
329 equal to, or greater than the second
330 </entry>
331 <entry>1</entry>
332 </row>
333 </tbody>
334 </tgroup>
335 </table>
337 <para>
338 Hash indexes likewise require one support function, shown in <xref
339 linkend="xindex-hash-support-table">.
340 </para>
342 <table tocentry="1" id="xindex-hash-support-table">
343 <title>Hash Support Functions</title>
344 <tgroup cols="2">
345 <thead>
346 <row>
347 <entry>Function</entry>
348 <entry>Support Number</entry>
349 </row>
350 </thead>
351 <tbody>
352 <row>
353 <entry>Compute the hash value for a key</entry>
354 <entry>1</entry>
355 </row>
356 </tbody>
357 </tgroup>
358 </table>
360 <para>
361 GiST indexes require seven support functions,
362 shown in <xref linkend="xindex-gist-support-table">.
363 </para>
365 <table tocentry="1" id="xindex-gist-support-table">
366 <title>GiST Support Functions</title>
367 <tgroup cols="2">
368 <thead>
369 <row>
370 <entry>Function</entry>
371 <entry>Support Number</entry>
372 </row>
373 </thead>
374 <tbody>
375 <row>
376 <entry>consistent - determine whether key satisfies the
377 query qualifier</entry>
378 <entry>1</entry>
379 </row>
380 <row>
381 <entry>union - compute union of a set of keys</entry>
382 <entry>2</entry>
383 </row>
384 <row>
385 <entry>compress - compute a compressed representation of a key or value
386 to be indexed</entry>
387 <entry>3</entry>
388 </row>
389 <row>
390 <entry>decompress - compute a decompressed representation of a
391 compressed key</entry>
392 <entry>4</entry>
393 </row>
394 <row>
395 <entry>penalty - compute penalty for inserting new key into subtree
396 with given subtree's key</entry>
397 <entry>5</entry>
398 </row>
399 <row>
400 <entry>picksplit - determine which entries of a page are to be moved
401 to the new page and compute the union keys for resulting pages</entry>
402 <entry>6</entry>
403 </row>
404 <row>
405 <entry>equal - compare two keys and return true if they are equal</entry>
406 <entry>7</entry>
407 </row>
408 </tbody>
409 </tgroup>
410 </table>
412 <para>
413 GIN indexes require four support functions,
414 shown in <xref linkend="xindex-gin-support-table">.
415 </para>
417 <table tocentry="1" id="xindex-gin-support-table">
418 <title>GIN Support Functions</title>
419 <tgroup cols="2">
420 <thead>
421 <row>
422 <entry>Function</entry>
423 <entry>Support Number</entry>
424 </row>
425 </thead>
426 <tbody>
427 <row>
428 <entry>
429 compare - compare two keys and return an integer less than zero, zero,
430 or greater than zero, indicating whether the first key is less than,
431 equal to, or greater than the second
432 </entry>
433 <entry>1</entry>
434 </row>
435 <row>
436 <entry>extractValue - extract keys from a value to be indexed</entry>
437 <entry>2</entry>
438 </row>
439 <row>
440 <entry>extractQuery - extract keys from a query condition</entry>
441 <entry>3</entry>
442 </row>
443 <row>
444 <entry>consistent - determine whether value matches query condition</entry>
445 <entry>4</entry>
446 </row>
447 <row>
448 <entry>comparePartial - (optional method) compare partial key from
449 query and key from index, and return an integer less than zero, zero,
450 or greater than zero, indicating whether GIN should ignore this index
451 entry, treat the entry as a match, or stop the index scan</entry>
452 <entry>5</entry>
453 </row>
454 </tbody>
455 </tgroup>
456 </table>
458 <para>
459 Unlike strategy operators, support functions return whichever data
460 type the particular index method expects; for example in the case
461 of the comparison function for B-trees, a signed integer. The number
462 and types of the arguments to each support function are likewise
463 dependent on the index method. For B-tree and hash the support functions
464 take the same input data types as do the operators included in the operator
465 class, but this is not the case for most GIN and GiST support functions.
466 </para>
467 </sect2>
469 <sect2 id="xindex-example">
470 <title>An Example</title>
472 <para>
473 Now that we have seen the ideas, here is the promised example of
474 creating a new operator class.
475 (You can find a working copy of this example in
476 <filename>src/tutorial/complex.c</filename> and
477 <filename>src/tutorial/complex.sql</filename> in the source
478 distribution.)
479 The operator class encapsulates
480 operators that sort complex numbers in absolute value order, so we
481 choose the name <literal>complex_abs_ops</literal>. First, we need
482 a set of operators. The procedure for defining operators was
483 discussed in <xref linkend="xoper">. For an operator class on
484 B-trees, the operators we require are:
486 <itemizedlist spacing="compact">
487 <listitem><simpara>absolute-value less-than (strategy 1)</></>
488 <listitem><simpara>absolute-value less-than-or-equal (strategy 2)</></>
489 <listitem><simpara>absolute-value equal (strategy 3)</></>
490 <listitem><simpara>absolute-value greater-than-or-equal (strategy 4)</></>
491 <listitem><simpara>absolute-value greater-than (strategy 5)</></>
492 </itemizedlist>
493 </para>
495 <para>
496 The least error-prone way to define a related set of comparison operators
497 is to write the B-tree comparison support function first, and then write the
498 other functions as one-line wrappers around the support function. This
499 reduces the odds of getting inconsistent results for corner cases.
500 Following this approach, we first write:
502 <programlisting><![CDATA[
503 #define Mag(c) ((c)->x*(c)->x + (c)->y*(c)->y)
505 static int
506 complex_abs_cmp_internal(Complex *a, Complex *b)
508 double amag = Mag(a),
509 bmag = Mag(b);
511 if (amag < bmag)
512 return -1;
513 if (amag > bmag)
514 return 1;
515 return 0;
518 </programlisting>
520 Now the less-than function looks like:
522 <programlisting><![CDATA[
523 PG_FUNCTION_INFO_V1(complex_abs_lt);
525 Datum
526 complex_abs_lt(PG_FUNCTION_ARGS)
528 Complex *a = (Complex *) PG_GETARG_POINTER(0);
529 Complex *b = (Complex *) PG_GETARG_POINTER(1);
531 PG_RETURN_BOOL(complex_abs_cmp_internal(a, b) < 0);
534 </programlisting>
536 The other four functions differ only in how they compare the internal
537 function's result to zero.
538 </para>
540 <para>
541 Next we declare the functions and the operators based on the functions
542 to SQL:
544 <programlisting>
545 CREATE FUNCTION complex_abs_lt(complex, complex) RETURNS bool
546 AS '<replaceable>filename</replaceable>', 'complex_abs_lt'
547 LANGUAGE C IMMUTABLE STRICT;
549 CREATE OPERATOR &lt; (
550 leftarg = complex, rightarg = complex, procedure = complex_abs_lt,
551 commutator = &gt; , negator = &gt;= ,
552 restrict = scalarltsel, join = scalarltjoinsel
554 </programlisting>
555 It is important to specify the correct commutator and negator operators,
556 as well as suitable restriction and join selectivity
557 functions, otherwise the optimizer will be unable to make effective
558 use of the index. Note that the less-than, equal, and
559 greater-than cases should use different selectivity functions.
560 </para>
562 <para>
563 Other things worth noting are happening here:
565 <itemizedlist>
566 <listitem>
567 <para>
568 There can only be one operator named, say, <literal>=</literal>
569 and taking type <type>complex</type> for both operands. In this
570 case we don't have any other operator <literal>=</literal> for
571 <type>complex</type>, but if we were building a practical data
572 type we'd probably want <literal>=</literal> to be the ordinary
573 equality operation for complex numbers (and not the equality of
574 the absolute values). In that case, we'd need to use some other
575 operator name for <function>complex_abs_eq</>.
576 </para>
577 </listitem>
579 <listitem>
580 <para>
581 Although <productname>PostgreSQL</productname> can cope with
582 functions having the same SQL name as long as they have different
583 argument data types, C can only cope with one global function
584 having a given name. So we shouldn't name the C function
585 something simple like <filename>abs_eq</filename>. Usually it's
586 a good practice to include the data type name in the C function
587 name, so as not to conflict with functions for other data types.
588 </para>
589 </listitem>
591 <listitem>
592 <para>
593 We could have made the SQL name
594 of the function <filename>abs_eq</filename>, relying on
595 <productname>PostgreSQL</productname> to distinguish it by
596 argument data types from any other SQL function of the same name.
597 To keep the example simple, we make the function have the same
598 names at the C level and SQL level.
599 </para>
600 </listitem>
601 </itemizedlist>
602 </para>
604 <para>
605 The next step is the registration of the support routine required
606 by B-trees. The example C code that implements this is in the same
607 file that contains the operator functions. This is how we declare
608 the function:
610 <programlisting>
611 CREATE FUNCTION complex_abs_cmp(complex, complex)
612 RETURNS integer
613 AS '<replaceable>filename</replaceable>'
614 LANGUAGE C IMMUTABLE STRICT;
615 </programlisting>
616 </para>
618 <para>
619 Now that we have the required operators and support routine,
620 we can finally create the operator class:
622 <programlisting><![CDATA[
623 CREATE OPERATOR CLASS complex_abs_ops
624 DEFAULT FOR TYPE complex USING btree AS
625 OPERATOR 1 < ,
626 OPERATOR 2 <= ,
627 OPERATOR 3 = ,
628 OPERATOR 4 >= ,
629 OPERATOR 5 > ,
630 FUNCTION 1 complex_abs_cmp(complex, complex);
632 </programlisting>
633 </para>
635 <para>
636 And we're done! It should now be possible to create
637 and use B-tree indexes on <type>complex</type> columns.
638 </para>
640 <para>
641 We could have written the operator entries more verbosely, as in:
642 <programlisting>
643 OPERATOR 1 &lt; (complex, complex) ,
644 </programlisting>
645 but there is no need to do so when the operators take the same data type
646 we are defining the operator class for.
647 </para>
649 <para>
650 The above example assumes that you want to make this new operator class the
651 default B-tree operator class for the <type>complex</type> data type.
652 If you don't, just leave out the word <literal>DEFAULT</>.
653 </para>
654 </sect2>
656 <sect2 id="xindex-opfamily">
657 <title>Operator Classes and Operator Families</title>
659 <para>
660 So far we have implicitly assumed that an operator class deals with
661 only one data type. While there certainly can be only one data type in
662 a particular index column, it is often useful to index operations that
663 compare an indexed column to a value of a different data type. Also,
664 if there is use for a cross-data-type operator in connection with an
665 operator class, it is often the case that the other data type has a
666 related operator class of its own. It is helpful to make the connections
667 between related classes explicit, because this can aid the planner in
668 optimizing SQL queries (particularly for B-tree operator classes, since
669 the planner contains a great deal of knowledge about how to work with them).
670 </para>
672 <para>
673 To handle these needs, <productname>PostgreSQL</productname>
674 uses the concept of an <firstterm>operator
675 family</><indexterm><primary>operator family</></indexterm>.
676 An operator family contains one or more operator classes, and can also
677 contain indexable operators and corresponding support functions that
678 belong to the family as a whole but not to any single class within the
679 family. We say that such operators and functions are <quote>loose</>
680 within the family, as opposed to being bound into a specific class.
681 Typically each operator class contains single-data-type operators
682 while cross-data-type operators are loose in the family.
683 </para>
685 <para>
686 All the operators and functions in an operator family must have compatible
687 semantics, where the compatibility requirements are set by the index
688 method. You might therefore wonder why bother to single out particular
689 subsets of the family as operator classes; and indeed for many purposes
690 the class divisions are irrelevant and the family is the only interesting
691 grouping. The reason for defining operator classes is that they specify
692 how much of the family is needed to support any particular index.
693 If there is an index using an operator class, then that operator class
694 cannot be dropped without dropping the index &mdash; but other parts of
695 the operator family, namely other operator classes and loose operators,
696 could be dropped. Thus, an operator class should be specified to contain
697 the minimum set of operators and functions that are reasonably needed
698 to work with an index on a specific data type, and then related but
699 non-essential operators can be added as loose members of the operator
700 family.
701 </para>
703 <para>
704 As an example, <productname>PostgreSQL</productname> has a built-in
705 B-tree operator family <literal>integer_ops</>, which includes operator
706 classes <literal>int8_ops</>, <literal>int4_ops</>, and
707 <literal>int2_ops</> for indexes on <type>bigint</> (<type>int8</>),
708 <type>integer</> (<type>int4</>), and <type>smallint</> (<type>int2</>)
709 columns respectively. The family also contains cross-data-type comparison
710 operators allowing any two of these types to be compared, so that an index
711 on one of these types can be searched using a comparison value of another
712 type. The family could be duplicated by these definitions:
714 <programlisting><![CDATA[
715 CREATE OPERATOR FAMILY integer_ops USING btree;
717 CREATE OPERATOR CLASS int8_ops
718 DEFAULT FOR TYPE int8 USING btree FAMILY integer_ops AS
719 -- standard int8 comparisons
720 OPERATOR 1 < ,
721 OPERATOR 2 <= ,
722 OPERATOR 3 = ,
723 OPERATOR 4 >= ,
724 OPERATOR 5 > ,
725 FUNCTION 1 btint8cmp(int8, int8) ;
727 CREATE OPERATOR CLASS int4_ops
728 DEFAULT FOR TYPE int4 USING btree FAMILY integer_ops AS
729 -- standard int4 comparisons
730 OPERATOR 1 < ,
731 OPERATOR 2 <= ,
732 OPERATOR 3 = ,
733 OPERATOR 4 >= ,
734 OPERATOR 5 > ,
735 FUNCTION 1 btint4cmp(int4, int4) ;
737 CREATE OPERATOR CLASS int2_ops
738 DEFAULT FOR TYPE int2 USING btree FAMILY integer_ops AS
739 -- standard int2 comparisons
740 OPERATOR 1 < ,
741 OPERATOR 2 <= ,
742 OPERATOR 3 = ,
743 OPERATOR 4 >= ,
744 OPERATOR 5 > ,
745 FUNCTION 1 btint2cmp(int2, int2) ;
747 ALTER OPERATOR FAMILY integer_ops USING btree ADD
748 -- cross-type comparisons int8 vs int2
749 OPERATOR 1 < (int8, int2) ,
750 OPERATOR 2 <= (int8, int2) ,
751 OPERATOR 3 = (int8, int2) ,
752 OPERATOR 4 >= (int8, int2) ,
753 OPERATOR 5 > (int8, int2) ,
754 FUNCTION 1 btint82cmp(int8, int2) ,
756 -- cross-type comparisons int8 vs int4
757 OPERATOR 1 < (int8, int4) ,
758 OPERATOR 2 <= (int8, int4) ,
759 OPERATOR 3 = (int8, int4) ,
760 OPERATOR 4 >= (int8, int4) ,
761 OPERATOR 5 > (int8, int4) ,
762 FUNCTION 1 btint84cmp(int8, int4) ,
764 -- cross-type comparisons int4 vs int2
765 OPERATOR 1 < (int4, int2) ,
766 OPERATOR 2 <= (int4, int2) ,
767 OPERATOR 3 = (int4, int2) ,
768 OPERATOR 4 >= (int4, int2) ,
769 OPERATOR 5 > (int4, int2) ,
770 FUNCTION 1 btint42cmp(int4, int2) ,
772 -- cross-type comparisons int4 vs int8
773 OPERATOR 1 < (int4, int8) ,
774 OPERATOR 2 <= (int4, int8) ,
775 OPERATOR 3 = (int4, int8) ,
776 OPERATOR 4 >= (int4, int8) ,
777 OPERATOR 5 > (int4, int8) ,
778 FUNCTION 1 btint48cmp(int4, int8) ,
780 -- cross-type comparisons int2 vs int8
781 OPERATOR 1 < (int2, int8) ,
782 OPERATOR 2 <= (int2, int8) ,
783 OPERATOR 3 = (int2, int8) ,
784 OPERATOR 4 >= (int2, int8) ,
785 OPERATOR 5 > (int2, int8) ,
786 FUNCTION 1 btint28cmp(int2, int8) ,
788 -- cross-type comparisons int2 vs int4
789 OPERATOR 1 < (int2, int4) ,
790 OPERATOR 2 <= (int2, int4) ,
791 OPERATOR 3 = (int2, int4) ,
792 OPERATOR 4 >= (int2, int4) ,
793 OPERATOR 5 > (int2, int4) ,
794 FUNCTION 1 btint24cmp(int2, int4) ;
796 </programlisting>
798 Notice that this definition <quote>overloads</> the operator strategy and
799 support function numbers: each number occurs multiple times within the
800 family. This is allowed so long as each instance of a
801 particular number has distinct input data types. The instances that have
802 both input types equal to an operator class's input type are the
803 primary operators and support functions for that operator class,
804 and in most cases should be declared as part of the operator class rather
805 than as loose members of the family.
806 </para>
808 <para>
809 In a B-tree operator family, all the operators in the family must sort
810 compatibly, meaning that the transitive laws hold across all the data types
811 supported by the family: <quote>if A = B and B = C, then A =
812 C</>, and <quote>if A &lt; B and B &lt; C, then A &lt; C</>. For each
813 operator in the family there must be a support function having the same
814 two input data types as the operator. It is recommended that a family be
815 complete, i.e., for each combination of data types, all operators are
816 included. Each operator class should include just the non-cross-type
817 operators and support function for its data type.
818 </para>
820 <para>
821 To build a multiple-data-type hash operator family, compatible hash
822 support functions must be created for each data type supported by the
823 family. Here compatibility means that the functions are guaranteed to
824 return the same hash code for any two values that are considered equal
825 by the family's equality operators, even when the values are of different
826 types. This is usually difficult to accomplish when the types have
827 different physical representations, but it can be done in some cases.
828 Notice that there is only one support function per data type, not one
829 per equality operator. It is recommended that a family be complete, i.e.,
830 provide an equality operator for each combination of data types.
831 Each operator class should include just the non-cross-type equality
832 operator and the support function for its data type.
833 </para>
835 <para>
836 GIN and GiST indexes do not have any explicit notion of cross-data-type
837 operations. The set of operators supported is just whatever the primary
838 support functions for a given operator class can handle.
839 </para>
841 <note>
842 <para>
843 Prior to <productname>PostgreSQL</productname> 8.3, there was no concept
844 of operator families, and so any cross-data-type operators intended to be
845 used with an index had to be bound directly into the index's operator
846 class. While this approach still works, it is deprecated because it
847 makes an index's dependencies too broad, and because the planner can
848 handle cross-data-type comparisons more effectively when both data types
849 have operators in the same operator family.
850 </para>
851 </note>
852 </sect2>
854 <sect2 id="xindex-opclass-dependencies">
855 <title>System Dependencies on Operator Classes</title>
857 <indexterm>
858 <primary>ordering operator</primary>
859 </indexterm>
861 <para>
862 <productname>PostgreSQL</productname> uses operator classes to infer the
863 properties of operators in more ways than just whether they can be used
864 with indexes. Therefore, you might want to create operator classes
865 even if you have no intention of indexing any columns of your data type.
866 </para>
868 <para>
869 In particular, there are SQL features such as <literal>ORDER BY</> and
870 <literal>DISTINCT</> that require comparison and sorting of values.
871 To implement these features on a user-defined data type,
872 <productname>PostgreSQL</productname> looks for the default B-tree operator
873 class for the data type. The <quote>equals</> member of this operator
874 class defines the system's notion of equality of values for
875 <literal>GROUP BY</> and <literal>DISTINCT</>, and the sort ordering
876 imposed by the operator class defines the default <literal>ORDER BY</>
877 ordering.
878 </para>
880 <para>
881 Comparison of arrays of user-defined types also relies on the semantics
882 defined by the default B-tree operator class.
883 </para>
885 <para>
886 If there is no default B-tree operator class for a data type, the system
887 will look for a default hash operator class. But since that kind of
888 operator class only provides equality, in practice it is only enough
889 to support array equality.
890 </para>
892 <para>
893 When there is no default operator class for a data type, you will get
894 errors like <quote>could not identify an ordering operator</> if you
895 try to use these SQL features with the data type.
896 </para>
898 <note>
899 <para>
900 In <productname>PostgreSQL</productname> versions before 7.4,
901 sorting and grouping operations would implicitly use operators named
902 <literal>=</>, <literal>&lt;</>, and <literal>&gt;</>. The new
903 behavior of relying on default operator classes avoids having to make
904 any assumption about the behavior of operators with particular names.
905 </para>
906 </note>
908 <para>
909 Another important point is that an operator that
910 appears in a hash operator family is a candidate for hash joins,
911 hash aggregation, and related optimizations. The hash operator family
912 is essential here since it identifies the hash function(s) to use.
913 </para>
914 </sect2>
916 <sect2 id="xindex-opclass-features">
917 <title>Special Features of Operator Classes</title>
919 <para>
920 There are two special features of operator classes that we have
921 not discussed yet, mainly because they are not useful
922 with the most commonly used index methods.
923 </para>
925 <para>
926 Normally, declaring an operator as a member of an operator class
927 (or family) means that the index method can retrieve exactly the set of rows
928 that satisfy a <literal>WHERE</> condition using the operator. For example:
929 <programlisting>
930 SELECT * FROM table WHERE integer_column &lt; 4;
931 </programlisting>
932 can be satisfied exactly by a B-tree index on the integer column.
933 But there are cases where an index is useful as an inexact guide to
934 the matching rows. For example, if a GiST index stores only bounding boxes
935 for geometric objects, then it cannot exactly satisfy a <literal>WHERE</>
936 condition that tests overlap between nonrectangular objects such as
937 polygons. Yet we could use the index to find objects whose bounding
938 box overlaps the bounding box of the target object, and then do the
939 exact overlap test only on the objects found by the index. If this
940 scenario applies, the index is said to be <quote>lossy</> for the
941 operator. Lossy index searches are implemented by having the index
942 method return a <firstterm>recheck</> flag when a row might or might
943 not really satisfy the query condition. The core system will then
944 test the original query condition on the retrieved row to see whether
945 it should be returned as a valid match. This approach works if
946 the index is guaranteed to return all the required rows, plus perhaps
947 some additional rows, which can be eliminated by performing the original
948 operator invocation. The index methods that support lossy searches
949 (currently, GiST and GIN) allow the support functions of individual
950 operator classes to set the recheck flag, and so this is essentially an
951 operator-class feature.
952 </para>
954 <para>
955 Consider again the situation where we are storing in the index only
956 the bounding box of a complex object such as a polygon. In this
957 case there's not much value in storing the whole polygon in the index
958 entry &mdash; we might as well store just a simpler object of type
959 <type>box</>. This situation is expressed by the <literal>STORAGE</>
960 option in <command>CREATE OPERATOR CLASS</>: we'd write something like:
962 <programlisting>
963 CREATE OPERATOR CLASS polygon_ops
964 DEFAULT FOR TYPE polygon USING gist AS
966 STORAGE box;
967 </programlisting>
969 At present, only the GiST and GIN index methods support a
970 <literal>STORAGE</> type that's different from the column data type.
971 The GiST <function>compress</> and <function>decompress</> support
972 routines must deal with data-type conversion when <literal>STORAGE</>
973 is used. In GIN, the <literal>STORAGE</> type identifies the type of
974 the <quote>key</> values, which normally is different from the type
975 of the indexed column &mdash; for example, an operator class for
976 integer-array columns might have keys that are just integers. The
977 GIN <function>extractValue</> and <function>extractQuery</> support
978 routines are responsible for extracting keys from indexed values.
979 </para>
980 </sect2>
982 </sect1>