2 11.10. Operator Classes and Operator Families #
4 An index definition can specify an operator class for each column of an
6 CREATE INDEX name ON table (column opclass [ ( opclass_options ) ] [sort options
9 The operator class identifies the operators to be used by the index for
10 that column. For example, a B-tree index on the type int4 would use the
11 int4_ops class; this operator class includes comparison functions for
12 values of type int4. In practice the default operator class for the
13 column's data type is usually sufficient. The main reason for having
14 operator classes is that for some data types, there could be more than
15 one meaningful index behavior. For example, we might want to sort a
16 complex-number data type either by absolute value or by real part. We
17 could do this by defining two operator classes for the data type and
18 then selecting the proper class when making an index. The operator
19 class determines the basic sort ordering (which can then be modified by
20 adding sort options COLLATE, ASC/DESC and/or NULLS FIRST/NULLS LAST).
22 There are also some built-in operator classes besides the default ones:
23 * The operator classes text_pattern_ops, varchar_pattern_ops, and
24 bpchar_pattern_ops support B-tree indexes on the types text,
25 varchar, and char respectively. The difference from the default
26 operator classes is that the values are compared strictly character
27 by character rather than according to the locale-specific collation
28 rules. This makes these operator classes suitable for use by
29 queries involving pattern matching expressions (LIKE or POSIX
30 regular expressions) when the database does not use the standard
31 āCā locale. As an example, you might index a varchar column like
33 CREATE INDEX test_index ON test_table (col varchar_pattern_ops);
35 Note that you should also create an index with the default operator
36 class if you want queries involving ordinary <, <=, >, or >=
37 comparisons to use an index. Such queries cannot use the
38 xxx_pattern_ops operator classes. (Ordinary equality comparisons
39 can use these operator classes, however.) It is possible to create
40 multiple indexes on the same column with different operator
41 classes. If you do use the C locale, you do not need the
42 xxx_pattern_ops operator classes, because an index with the default
43 operator class is usable for pattern-matching queries in the C
46 The following query shows all defined operator classes:
47 SELECT am.amname AS index_method,
48 opc.opcname AS opclass_name,
49 opc.opcintype::regtype AS indexed_type,
50 opc.opcdefault AS is_default
51 FROM pg_am am, pg_opclass opc
52 WHERE opc.opcmethod = am.oid
53 ORDER BY index_method, opclass_name;
55 An operator class is actually just a subset of a larger structure
56 called an operator family. In cases where several data types have
57 similar behaviors, it is frequently useful to define cross-data-type
58 operators and allow these to work with indexes. To do this, the
59 operator classes for each of the types must be grouped into the same
60 operator family. The cross-type operators are members of the family,
61 but are not associated with any single class within the family.
63 This expanded version of the previous query shows the operator family
64 each operator class belongs to:
65 SELECT am.amname AS index_method,
66 opc.opcname AS opclass_name,
67 opf.opfname AS opfamily_name,
68 opc.opcintype::regtype AS indexed_type,
69 opc.opcdefault AS is_default
70 FROM pg_am am, pg_opclass opc, pg_opfamily opf
71 WHERE opc.opcmethod = am.oid AND
72 opc.opcfamily = opf.oid
73 ORDER BY index_method, opclass_name;
75 This query shows all defined operator families and all the operators
76 included in each family:
77 SELECT am.amname AS index_method,
78 opf.opfname AS opfamily_name,
79 amop.amopopr::regoperator AS opfamily_operator
80 FROM pg_am am, pg_opfamily opf, pg_amop amop
81 WHERE opf.opfmethod = am.oid AND
82 amop.amopfamily = opf.oid
83 ORDER BY index_method, opfamily_name, opfamily_operator;
87 psql has commands \dAc, \dAf, and \dAo, which provide slightly more
88 sophisticated versions of these queries.