summaryrefslogtreecommitdiff
path: root/doc/src/sgml/xindex.sgml
blob: 8f9fd21f386bcbd6d554be12bdc2dd5b3c3e7670 (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
<!-- doc/src/sgml/xindex.sgml -->

<sect1 id="xindex">
 <title>Interfacing Extensions To Indexes</title>

 <indexterm zone="xindex">
  <primary>index</primary>
  <secondary>for user-defined data type</secondary>
 </indexterm>

  <para>
   The procedures described thus far let you define new types, new
   functions, and new operators. However, we cannot yet define an
   index on a column of a new data type.  To do this, we must define an
   <firstterm>operator class</> for the new data type.  Later in this
   section, we will illustrate this concept in an example: a new
   operator class for the B-tree index method that stores and sorts
   complex numbers in ascending absolute value order.
  </para>

  <para>
   Operator classes can be grouped into <firstterm>operator families</>
   to show the relationships between semantically compatible classes.
   When only a single data type is involved, an operator class is sufficient,
   so we'll focus on that case first and then return to operator families.
  </para>

 <sect2 id="xindex-opclass">
  <title>Index Methods and Operator Classes</title>

  <para>
   The <classname>pg_am</classname> table contains one row for every
   index method (internally known as access method).  Support for
   regular access to tables is built into
   <productname>PostgreSQL</productname>, but all index methods are
   described in <classname>pg_am</classname>.  It is possible to add a
   new index method by defining the required interface routines and
   then creating a row in <classname>pg_am</classname> &mdash; but that is
   beyond the scope of this chapter (see <xref linkend="indexam">).
  </para>

  <para>
   The routines for an index method do not directly know anything
   about the data types that the index method will operate on.
   Instead, an <firstterm>operator
   class</><indexterm><primary>operator class</></indexterm>
   identifies the set of operations that the index method needs to use
   to work with a particular data type.  Operator classes are so
   called because one thing they specify is the set of
   <literal>WHERE</>-clause operators that can be used with an index
   (i.e., can be converted into an index-scan qualification).  An
   operator class can also specify some <firstterm>support
   procedures</> that are needed by the internal operations of the
   index method, but do not directly correspond to any
   <literal>WHERE</>-clause operator that can be used with the index.
  </para>

  <para>
   It is possible to define multiple operator classes for the same
   data type and index method.  By doing this, multiple
   sets of indexing semantics can be defined for a single data type.
   For example, a B-tree index requires a sort ordering to be defined
   for each data type it works on.
   It might be useful for a complex-number data type
   to have one B-tree operator class that sorts the data by complex
   absolute value, another that sorts by real part, and so on.
   Typically, one of the operator classes will be deemed most commonly
   useful and will be marked as the default operator class for that
   data type and index method.
  </para>

  <para>
   The same operator class name
   can be used for several different index methods (for example, both B-tree
   and hash index methods have operator classes named
   <literal>int4_ops</literal>), but each such class is an independent
   entity and must be defined separately.
  </para>
 </sect2>

 <sect2 id="xindex-strategies">
  <title>Index Method Strategies</title>

  <para>
   The operators associated with an operator class are identified by
   <quote>strategy numbers</>, which serve to identify the semantics of
   each operator within the context of its operator class.
   For example, B-trees impose a strict ordering on keys, lesser to greater,
   and so operators like <quote>less than</> and <quote>greater than or equal
   to</> are interesting with respect to a B-tree.
   Because
   <productname>PostgreSQL</productname> allows the user to define operators,
   <productname>PostgreSQL</productname> cannot look at the name of an operator
   (e.g., <literal>&lt;</> or <literal>&gt;=</>) and tell what kind of
   comparison it is.  Instead, the index method defines a set of
   <quote>strategies</>, which can be thought of as generalized operators.
   Each operator class specifies which actual operator corresponds to each
   strategy for a particular data type and interpretation of the index
   semantics.
  </para>

  <para>
   The B-tree index method defines five strategies, shown in <xref
   linkend="xindex-btree-strat-table">.
  </para>

   <table tocentry="1" id="xindex-btree-strat-table">
    <title>B-tree Strategies</title>
    <tgroup cols="2">
     <thead>
      <row>
       <entry>Operation</entry>
       <entry>Strategy Number</entry>
      </row>
     </thead>
     <tbody>
      <row>
       <entry>less than</entry>
       <entry>1</entry>
      </row>
      <row>
       <entry>less than or equal</entry>
       <entry>2</entry>
      </row>
      <row>
       <entry>equal</entry>
       <entry>3</entry>
      </row>
      <row>
       <entry>greater than or equal</entry>
       <entry>4</entry>
      </row>
      <row>
       <entry>greater than</entry>
       <entry>5</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

  <para>
   Hash indexes support only equality comparisons, and so they use only one
   strategy, shown in <xref linkend="xindex-hash-strat-table">.
  </para>

   <table tocentry="1" id="xindex-hash-strat-table">
    <title>Hash Strategies</title>
    <tgroup cols="2">
     <thead>
      <row>
       <entry>Operation</entry>
       <entry>Strategy Number</entry>
      </row>
     </thead>
     <tbody>
      <row>
       <entry>equal</entry>
       <entry>1</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

  <para>
   GiST indexes are more flexible: they do not have a fixed set of
   strategies at all.  Instead, the <quote>consistency</> support routine
   of each particular GiST operator class interprets the strategy numbers
   however it likes.  As an example, several of the built-in GiST index
   operator classes index two-dimensional geometric objects, providing
   the <quote>R-tree</> strategies shown in
   <xref linkend="xindex-rtree-strat-table">.  Four of these are true
   two-dimensional tests (overlaps, same, contains, contained by);
   four of them consider only the X direction; and the other four
   provide the same tests in the Y direction.
  </para>

   <table tocentry="1" id="xindex-rtree-strat-table">
    <title>GiST Two-Dimensional <quote>R-tree</> Strategies</title>
    <tgroup cols="2">
     <thead>
      <row>
       <entry>Operation</entry>
       <entry>Strategy Number</entry>
      </row>
     </thead>
     <tbody>
      <row>
       <entry>strictly left of</entry>
       <entry>1</entry>
      </row>
      <row>
       <entry>does not extend to right of</entry>
       <entry>2</entry>
      </row>
      <row>
       <entry>overlaps</entry>
       <entry>3</entry>
      </row>
      <row>
       <entry>does not extend to left of</entry>
       <entry>4</entry>
      </row>
      <row>
       <entry>strictly right of</entry>
       <entry>5</entry>
      </row>
      <row>
       <entry>same</entry>
       <entry>6</entry>
      </row>
      <row>
       <entry>contains</entry>
       <entry>7</entry>
      </row>
      <row>
       <entry>contained by</entry>
       <entry>8</entry>
      </row>
      <row>
       <entry>does not extend above</entry>
       <entry>9</entry>
      </row>
      <row>
       <entry>strictly below</entry>
       <entry>10</entry>
      </row>
      <row>
       <entry>strictly above</entry>
       <entry>11</entry>
      </row>
      <row>
       <entry>does not extend below</entry>
       <entry>12</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

  <para>
   GIN indexes are similar to GiST indexes in flexibility: they don't have a
   fixed set of strategies. Instead the support routines of each operator
   class interpret the strategy numbers according to the operator class's
   definition. As an example, the strategy numbers used by the built-in
   operator classes for arrays are
   shown in <xref linkend="xindex-gin-array-strat-table">.
  </para>

   <table tocentry="1" id="xindex-gin-array-strat-table">
    <title>GIN Array Strategies</title>
    <tgroup cols="2">
     <thead>
      <row>
       <entry>Operation</entry>
       <entry>Strategy Number</entry>
      </row>
     </thead>
     <tbody>
      <row>
       <entry>overlap</entry>
       <entry>1</entry>
      </row>
      <row>
       <entry>contains</entry>
       <entry>2</entry>
      </row>
      <row>
       <entry>is contained by</entry>
       <entry>3</entry>
      </row>
      <row>
       <entry>equal</entry>
       <entry>4</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

  <para>
   Notice that all strategy operators return Boolean values.  In
   practice, all operators defined as index method strategies must
   return type <type>boolean</type>, since they must appear at the top
   level of a <literal>WHERE</> clause to be used with an index.
  </para>
 </sect2>

 <sect2 id="xindex-support">
  <title>Index Method Support Routines</title>

  <para>
   Strategies aren't usually enough information for the system to figure
   out how to use an index.  In practice, the index methods require
   additional support routines in order to work. For example, the B-tree
   index method must be able to compare two keys and determine whether one
   is greater than, equal to, or less than the other.  Similarly, the
   hash index method must be able to compute hash codes for key values.
   These operations do not correspond to operators used in qualifications in
   SQL commands;  they are administrative routines used by
   the index methods, internally.
  </para>

  <para>
   Just as with strategies, the operator class identifies which specific
   functions should play each of these roles for a given data type and
   semantic interpretation.  The index method defines the set
   of functions it needs, and the operator class identifies the correct
   functions to use by assigning them to the <quote>support function numbers</>
   specified by the index method.
  </para>

  <para>
   B-trees require a single support function, shown in <xref
   linkend="xindex-btree-support-table">.
  </para>

   <table tocentry="1" id="xindex-btree-support-table">
    <title>B-tree Support Functions</title>
    <tgroup cols="2">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Support Number</entry>
      </row>
     </thead>
     <tbody>
      <row>
       <entry>
        Compare two keys and return an integer less than zero, zero, or
        greater than zero, indicating whether the first key is less than,
        equal to, or greater than the second
       </entry>
       <entry>1</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

  <para>
   Hash indexes likewise require one support function, shown in <xref
   linkend="xindex-hash-support-table">.
  </para>

   <table tocentry="1" id="xindex-hash-support-table">
    <title>Hash Support Functions</title>
    <tgroup cols="2">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Support Number</entry>
      </row>
     </thead>
     <tbody>
      <row>
       <entry>Compute the hash value for a key</entry>
       <entry>1</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

  <para>
   GiST indexes require seven support functions,
   shown in <xref linkend="xindex-gist-support-table">.
  </para>

   <table tocentry="1" id="xindex-gist-support-table">
    <title>GiST Support Functions</title>
    <tgroup cols="2">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Support Number</entry>
      </row>
     </thead>
     <tbody>
      <row>
       <entry>consistent - determine whether key satisfies the
        query qualifier</entry>
       <entry>1</entry>
      </row>
      <row>
       <entry>union - compute union of a set of keys</entry>
       <entry>2</entry>
      </row>
      <row>
       <entry>compress - compute a compressed representation of a key or value
        to be indexed</entry>
       <entry>3</entry>
      </row>
      <row>
       <entry>decompress - compute a decompressed representation of a
        compressed key</entry>
       <entry>4</entry>
      </row>
      <row>
       <entry>penalty - compute penalty for inserting new key into subtree
       with given subtree's key</entry>
       <entry>5</entry>
      </row>
      <row>
       <entry>picksplit - determine which entries of a page are to be moved
       to the new page and compute the union keys for resulting pages</entry>
       <entry>6</entry>
      </row>
      <row>
       <entry>equal - compare two keys and return true if they are equal</entry>
       <entry>7</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

  <para>
   GIN indexes require four support functions,
   shown in <xref linkend="xindex-gin-support-table">.
  </para>

   <table tocentry="1" id="xindex-gin-support-table">
    <title>GIN Support Functions</title>
    <tgroup cols="3">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Description</entry>
       <entry>Support Number</entry>
      </row>
     </thead>
     <tbody>
      <row>
       <entry><function>compare</></entry>
       <entry>
        compare two keys and return an integer less than zero, zero,
        or greater than zero, indicating whether the first key is less than,
        equal to, or greater than the second
       </entry>
       <entry>1</entry>
      </row>
      <row>
       <entry><function>extractValue</></entry>
       <entry>extract keys from a value to be indexed</entry>
       <entry>2</entry>
      </row>
      <row>
       <entry><function>extractQuery</></entry>
       <entry>extract keys from a query condition</entry>
       <entry>3</entry>
      </row>
      <row>
       <entry><function>consistent</></entry>
       <entry>determine whether value matches query condition</entry>
       <entry>4</entry>
      </row>
      <row>
       <entry><function>comparePartial</></entry>
       <entry>
        (optional method) compare partial key from
        query and key from index, and return an integer less than zero, zero,
        or greater than zero, indicating whether GIN should ignore this index
        entry, treat the entry as a match, or stop the index scan
       </entry>
       <entry>5</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

  <para>
   Unlike strategy operators, support functions return whichever data
   type the particular index method expects; for example in the case
   of the comparison function for B-trees, a signed integer.  The number
   and types of the arguments to each support function are likewise
   dependent on the index method.  For B-tree and hash the support functions
   take the same input data types as do the operators included in the operator
   class, but this is not the case for most GIN and GiST support functions.
  </para>
 </sect2>

 <sect2 id="xindex-example">
  <title>An Example</title>

  <para>
   Now that we have seen the ideas, here is the promised example of
   creating a new operator class.
   (You can find a working copy of this example in
   <filename>src/tutorial/complex.c</filename> and
   <filename>src/tutorial/complex.sql</filename> in the source
   distribution.)
   The operator class encapsulates
   operators that sort complex numbers in absolute value order, so we
   choose the name <literal>complex_abs_ops</literal>.  First, we need
   a set of operators.  The procedure for defining operators was
   discussed in <xref linkend="xoper">.  For an operator class on
   B-trees, the operators we require are:

   <itemizedlist spacing="compact">
    <listitem><simpara>absolute-value less-than (strategy 1)</></>
    <listitem><simpara>absolute-value less-than-or-equal (strategy 2)</></>
    <listitem><simpara>absolute-value equal (strategy 3)</></>
    <listitem><simpara>absolute-value greater-than-or-equal (strategy 4)</></>
    <listitem><simpara>absolute-value greater-than (strategy 5)</></>
   </itemizedlist>
  </para>

  <para>
   The least error-prone way to define a related set of comparison operators
   is to write the B-tree comparison support function first, and then write the
   other functions as one-line wrappers around the support function.  This
   reduces the odds of getting inconsistent results for corner cases.
   Following this approach, we first write:

<programlisting><![CDATA[
#define Mag(c)  ((c)->x*(c)->x + (c)->y*(c)->y)

static int
complex_abs_cmp_internal(Complex *a, Complex *b)
{
    double      amag = Mag(a),
                bmag = Mag(b);

    if (amag < bmag)
        return -1;
    if (amag > bmag)
        return 1;
    return 0;
}
]]>
</programlisting>

   Now the less-than function looks like:

<programlisting><![CDATA[
PG_FUNCTION_INFO_V1(complex_abs_lt);

Datum
complex_abs_lt(PG_FUNCTION_ARGS)
{
    Complex    *a = (Complex *) PG_GETARG_POINTER(0);
    Complex    *b = (Complex *) PG_GETARG_POINTER(1);

    PG_RETURN_BOOL(complex_abs_cmp_internal(a, b) < 0);
}
]]>
</programlisting>

   The other four functions differ only in how they compare the internal
   function's result to zero.
  </para>

  <para>
   Next we declare the functions and the operators based on the functions
   to SQL:

<programlisting>
CREATE FUNCTION complex_abs_lt(complex, complex) RETURNS bool
    AS '<replaceable>filename</replaceable>', 'complex_abs_lt'
    LANGUAGE C IMMUTABLE STRICT;

CREATE OPERATOR &lt; (
   leftarg = complex, rightarg = complex, procedure = complex_abs_lt,
   commutator = &gt; , negator = &gt;= ,
   restrict = scalarltsel, join = scalarltjoinsel
);
</programlisting>
   It is important to specify the correct commutator and negator operators,
   as well as suitable restriction and join selectivity
   functions, otherwise the optimizer will be unable to make effective
   use of the index.  Note that the less-than, equal, and
   greater-than cases should use different selectivity functions.
  </para>

  <para>
   Other things worth noting are happening here:

  <itemizedlist>
   <listitem>
    <para>
     There can only be one operator named, say, <literal>=</literal>
     and taking type <type>complex</type> for both operands.  In this
     case we don't have any other operator <literal>=</literal> for
     <type>complex</type>, but if we were building a practical data
     type we'd probably want <literal>=</literal> to be the ordinary
     equality operation for complex numbers (and not the equality of
     the absolute values).  In that case, we'd need to use some other
     operator name for <function>complex_abs_eq</>.
    </para>
   </listitem>

   <listitem>
    <para>
     Although <productname>PostgreSQL</productname> can cope with
     functions having the same SQL name as long as they have different
     argument data types, C can only cope with one global function
     having a given name.  So we shouldn't name the C function
     something simple like <filename>abs_eq</filename>.  Usually it's
     a good practice to include the data type name in the C function
     name, so as not to conflict with functions for other data types.
    </para>
   </listitem>

   <listitem>
    <para>
     We could have made the SQL name
     of the function <filename>abs_eq</filename>, relying on
     <productname>PostgreSQL</productname> to distinguish it by
     argument data types from any other SQL function of the same name.
     To keep the example simple, we make the function have the same
     names at the C level and SQL level.
    </para>
   </listitem>
  </itemizedlist>
  </para>

  <para>
   The next step is the registration of the support routine required
   by B-trees.  The example C code that implements this is in the same
   file that contains the operator functions.  This is how we declare
   the function:

<programlisting>
CREATE FUNCTION complex_abs_cmp(complex, complex)
    RETURNS integer
    AS '<replaceable>filename</replaceable>'
    LANGUAGE C IMMUTABLE STRICT;
</programlisting>
  </para>

  <para>
   Now that we have the required operators and support routine,
   we can finally create the operator class:

<programlisting><![CDATA[
CREATE OPERATOR CLASS complex_abs_ops
    DEFAULT FOR TYPE complex USING btree AS
        OPERATOR        1       < ,
        OPERATOR        2       <= ,
        OPERATOR        3       = ,
        OPERATOR        4       >= ,
        OPERATOR        5       > ,
        FUNCTION        1       complex_abs_cmp(complex, complex);
]]>
</programlisting>
  </para>

  <para>
   And we're done!  It should now be possible to create
   and use B-tree indexes on <type>complex</type> columns.
  </para>

  <para>
   We could have written the operator entries more verbosely, as in:
<programlisting>
        OPERATOR        1       &lt; (complex, complex) ,
</programlisting>
   but there is no need to do so when the operators take the same data type
   we are defining the operator class for.
  </para>

  <para>
   The above example assumes that you want to make this new operator class the
   default B-tree operator class for the <type>complex</type> data type.
   If you don't, just leave out the word <literal>DEFAULT</>.
  </para>
 </sect2>

 <sect2 id="xindex-opfamily">
  <title>Operator Classes and Operator Families</title>

  <para>
   So far we have implicitly assumed that an operator class deals with
   only one data type.  While there certainly can be only one data type in
   a particular index column, it is often useful to index operations that
   compare an indexed column to a value of a different data type.  Also,
   if there is use for a cross-data-type operator in connection with an
   operator class, it is often the case that the other data type has a
   related operator class of its own.  It is helpful to make the connections
   between related classes explicit, because this can aid the planner in
   optimizing SQL queries (particularly for B-tree operator classes, since
   the planner contains a great deal of knowledge about how to work with them).
  </para>

  <para>
   To handle these needs, <productname>PostgreSQL</productname>
   uses the concept of an <firstterm>operator
   family</><indexterm><primary>operator family</></indexterm>.
   An operator family contains one or more operator classes, and can also
   contain indexable operators and corresponding support functions that
   belong to the family as a whole but not to any single class within the
   family.  We say that such operators and functions are <quote>loose</>
   within the family, as opposed to being bound into a specific class.
   Typically each operator class contains single-data-type operators
   while cross-data-type operators are loose in the family.
  </para>

  <para>
   All the operators and functions in an operator family must have compatible
   semantics, where the compatibility requirements are set by the index
   method.  You might therefore wonder why bother to single out particular
   subsets of the family as operator classes; and indeed for many purposes
   the class divisions are irrelevant and the family is the only interesting
   grouping.  The reason for defining operator classes is that they specify
   how much of the family is needed to support any particular index.
   If there is an index using an operator class, then that operator class
   cannot be dropped without dropping the index &mdash; but other parts of
   the operator family, namely other operator classes and loose operators,
   could be dropped.  Thus, an operator class should be specified to contain
   the minimum set of operators and functions that are reasonably needed
   to work with an index on a specific data type, and then related but
   non-essential operators can be added as loose members of the operator
   family.
  </para>

  <para>
   As an example, <productname>PostgreSQL</productname> has a built-in
   B-tree operator family <literal>integer_ops</>, which includes operator
   classes <literal>int8_ops</>, <literal>int4_ops</>, and
   <literal>int2_ops</> for indexes on <type>bigint</> (<type>int8</>),
   <type>integer</> (<type>int4</>), and <type>smallint</> (<type>int2</>)
   columns respectively.  The family also contains cross-data-type comparison
   operators allowing any two of these types to be compared, so that an index
   on one of these types can be searched using a comparison value of another
   type.  The family could be duplicated by these definitions:

<programlisting><![CDATA[
CREATE OPERATOR FAMILY integer_ops USING btree;

CREATE OPERATOR CLASS int8_ops
DEFAULT FOR TYPE int8 USING btree FAMILY integer_ops AS
  -- standard int8 comparisons
  OPERATOR 1 < ,
  OPERATOR 2 <= ,
  OPERATOR 3 = ,
  OPERATOR 4 >= ,
  OPERATOR 5 > ,
  FUNCTION 1 btint8cmp(int8, int8) ;

CREATE OPERATOR CLASS int4_ops
DEFAULT FOR TYPE int4 USING btree FAMILY integer_ops AS
  -- standard int4 comparisons
  OPERATOR 1 < ,
  OPERATOR 2 <= ,
  OPERATOR 3 = ,
  OPERATOR 4 >= ,
  OPERATOR 5 > ,
  FUNCTION 1 btint4cmp(int4, int4) ;

CREATE OPERATOR CLASS int2_ops
DEFAULT FOR TYPE int2 USING btree FAMILY integer_ops AS
  -- standard int2 comparisons
  OPERATOR 1 < ,
  OPERATOR 2 <= ,
  OPERATOR 3 = ,
  OPERATOR 4 >= ,
  OPERATOR 5 > ,
  FUNCTION 1 btint2cmp(int2, int2) ;

ALTER OPERATOR FAMILY integer_ops USING btree ADD
  -- cross-type comparisons int8 vs int2
  OPERATOR 1 < (int8, int2) ,
  OPERATOR 2 <= (int8, int2) ,
  OPERATOR 3 = (int8, int2) ,
  OPERATOR 4 >= (int8, int2) ,
  OPERATOR 5 > (int8, int2) ,
  FUNCTION 1 btint82cmp(int8, int2) ,

  -- cross-type comparisons int8 vs int4
  OPERATOR 1 < (int8, int4) ,
  OPERATOR 2 <= (int8, int4) ,
  OPERATOR 3 = (int8, int4) ,
  OPERATOR 4 >= (int8, int4) ,
  OPERATOR 5 > (int8, int4) ,
  FUNCTION 1 btint84cmp(int8, int4) ,

  -- cross-type comparisons int4 vs int2
  OPERATOR 1 < (int4, int2) ,
  OPERATOR 2 <= (int4, int2) ,
  OPERATOR 3 = (int4, int2) ,
  OPERATOR 4 >= (int4, int2) ,
  OPERATOR 5 > (int4, int2) ,
  FUNCTION 1 btint42cmp(int4, int2) ,

  -- cross-type comparisons int4 vs int8
  OPERATOR 1 < (int4, int8) ,
  OPERATOR 2 <= (int4, int8) ,
  OPERATOR 3 = (int4, int8) ,
  OPERATOR 4 >= (int4, int8) ,
  OPERATOR 5 > (int4, int8) ,
  FUNCTION 1 btint48cmp(int4, int8) ,

  -- cross-type comparisons int2 vs int8
  OPERATOR 1 < (int2, int8) ,
  OPERATOR 2 <= (int2, int8) ,
  OPERATOR 3 = (int2, int8) ,
  OPERATOR 4 >= (int2, int8) ,
  OPERATOR 5 > (int2, int8) ,
  FUNCTION 1 btint28cmp(int2, int8) ,

  -- cross-type comparisons int2 vs int4
  OPERATOR 1 < (int2, int4) ,
  OPERATOR 2 <= (int2, int4) ,
  OPERATOR 3 = (int2, int4) ,
  OPERATOR 4 >= (int2, int4) ,
  OPERATOR 5 > (int2, int4) ,
  FUNCTION 1 btint24cmp(int2, int4) ;
]]>
</programlisting>

   Notice that this definition <quote>overloads</> the operator strategy and
   support function numbers: each number occurs multiple times within the
   family.  This is allowed so long as each instance of a
   particular number has distinct input data types.  The instances that have
   both input types equal to an operator class's input type are the
   primary operators and support functions for that operator class,
   and in most cases should be declared as part of the operator class rather
   than as loose members of the family.
  </para>

  <para>
   In a B-tree operator family, all the operators in the family must sort
   compatibly, meaning that the transitive laws hold across all the data types
   supported by the family: <quote>if A = B and B = C, then A =
   C</>, and <quote>if A &lt; B and B &lt; C, then A &lt; C</>.  For each
   operator in the family there must be a support function having the same
   two input data types as the operator.  It is recommended that a family be
   complete, i.e., for each combination of data types, all operators are
   included.  Each operator class should include just the non-cross-type
   operators and support function for its data type.
  </para>

  <para>
   To build a multiple-data-type hash operator family, compatible hash
   support functions must be created for each data type supported by the
   family.  Here compatibility means that the functions are guaranteed to
   return the same hash code for any two values that are considered equal
   by the family's equality operators, even when the values are of different
   types.  This is usually difficult to accomplish when the types have
   different physical representations, but it can be done in some cases.
   Notice that there is only one support function per data type, not one
   per equality operator.  It is recommended that a family be complete, i.e.,
   provide an equality operator for each combination of data types.
   Each operator class should include just the non-cross-type equality
   operator and the support function for its data type.
  </para>

  <para>
   GIN and GiST indexes do not have any explicit notion of cross-data-type
   operations.  The set of operators supported is just whatever the primary
   support functions for a given operator class can handle.
  </para>

  <note>
   <para>
    Prior to <productname>PostgreSQL</productname> 8.3, there was no concept
    of operator families, and so any cross-data-type operators intended to be
    used with an index had to be bound directly into the index's operator
    class.  While this approach still works, it is deprecated because it
    makes an index's dependencies too broad, and because the planner can
    handle cross-data-type comparisons more effectively when both data types
    have operators in the same operator family.
   </para>
  </note>
 </sect2>

 <sect2 id="xindex-opclass-dependencies">
  <title>System Dependencies on Operator Classes</title>

   <indexterm>
    <primary>ordering operator</primary>
   </indexterm>

  <para>
   <productname>PostgreSQL</productname> uses operator classes to infer the
   properties of operators in more ways than just whether they can be used
   with indexes.  Therefore, you might want to create operator classes
   even if you have no intention of indexing any columns of your data type.
  </para>

  <para>
   In particular, there are SQL features such as <literal>ORDER BY</> and
   <literal>DISTINCT</> that require comparison and sorting of values.
   To implement these features on a user-defined data type,
   <productname>PostgreSQL</productname> looks for the default B-tree operator
   class for the data type.  The <quote>equals</> member of this operator
   class defines the system's notion of equality of values for
   <literal>GROUP BY</> and <literal>DISTINCT</>, and the sort ordering
   imposed by the operator class defines the default <literal>ORDER BY</>
   ordering.
  </para>

  <para>
   Comparison of arrays of user-defined types also relies on the semantics
   defined by the default B-tree operator class.
  </para>

  <para>
   If there is no default B-tree operator class for a data type, the system
   will look for a default hash operator class.  But since that kind of
   operator class only provides equality, in practice it is only enough
   to support array equality.
  </para>

  <para>
   When there is no default operator class for a data type, you will get
   errors like <quote>could not identify an ordering operator</> if you
   try to use these SQL features with the data type.
  </para>

   <note>
    <para>
     In <productname>PostgreSQL</productname> versions before 7.4,
     sorting and grouping operations would implicitly use operators named
     <literal>=</>, <literal>&lt;</>, and <literal>&gt;</>.  The new
     behavior of relying on default operator classes avoids having to make
     any assumption about the behavior of operators with particular names.
    </para>
   </note>

  <para>
   Another important point is that an operator that
   appears in a hash operator family is a candidate for hash joins,
   hash aggregation, and related optimizations.  The hash operator family
   is essential here since it identifies the hash function(s) to use.
  </para>
 </sect2>

 <sect2 id="xindex-opclass-features">
  <title>Special Features of Operator Classes</title>

  <para>
   There are two special features of operator classes that we have
   not discussed yet, mainly because they are not useful
   with the most commonly used index methods.
  </para>

  <para>
   Normally, declaring an operator as a member of an operator class
   (or family) means that the index method can retrieve exactly the set of rows
   that satisfy a <literal>WHERE</> condition using the operator.  For example:
<programlisting>
SELECT * FROM table WHERE integer_column &lt; 4;
</programlisting>
   can be satisfied exactly by a B-tree index on the integer column.
   But there are cases where an index is useful as an inexact guide to
   the matching rows.  For example, if a GiST index stores only bounding boxes
   for geometric objects, then it cannot exactly satisfy a <literal>WHERE</>
   condition that tests overlap between nonrectangular objects such as
   polygons.  Yet we could use the index to find objects whose bounding
   box overlaps the bounding box of the target object, and then do the
   exact overlap test only on the objects found by the index.  If this
   scenario applies, the index is said to be <quote>lossy</> for the
   operator.  Lossy index searches are implemented by having the index
   method return a <firstterm>recheck</> flag when a row might or might
   not really satisfy the query condition.  The core system will then
   test the original query condition on the retrieved row to see whether
   it should be returned as a valid match.  This approach works if
   the index is guaranteed to return all the required rows, plus perhaps
   some additional rows, which can be eliminated by performing the original
   operator invocation.  The index methods that support lossy searches
   (currently, GiST and GIN) allow the support functions of individual
   operator classes to set the recheck flag, and so this is essentially an
   operator-class feature.
  </para>

  <para>
   Consider again the situation where we are storing in the index only
   the bounding box of a complex object such as a polygon.  In this
   case there's not much value in storing the whole polygon in the index
   entry &mdash; we might as well store just a simpler object of type
   <type>box</>.  This situation is expressed by the <literal>STORAGE</>
   option in <command>CREATE OPERATOR CLASS</>: we'd write something like:

<programlisting>
CREATE OPERATOR CLASS polygon_ops
    DEFAULT FOR TYPE polygon USING gist AS
        ...
        STORAGE box;
</programlisting>

   At present, only the GiST and GIN index methods support a
   <literal>STORAGE</> type that's different from the column data type.
   The GiST <function>compress</> and <function>decompress</> support
   routines must deal with data-type conversion when <literal>STORAGE</>
   is used.  In GIN, the <literal>STORAGE</> type identifies the type of
   the <quote>key</> values, which normally is different from the type
   of the indexed column &mdash; for example, an operator class for
   integer-array columns might have keys that are just integers.  The
   GIN <function>extractValue</> and <function>extractQuery</> support
   routines are responsible for extracting keys from indexed values.
  </para>
 </sect2>

</sect1>