2 36.15. Operator Optimization Information #
11 A PostgreSQL operator definition can include several optional clauses
12 that tell the system useful things about how the operator behaves.
13 These clauses should be provided whenever appropriate, because they can
14 make for considerable speedups in execution of queries that use the
15 operator. But if you provide them, you must be sure that they are
16 right! Incorrect use of an optimization clause can result in slow
17 queries, subtly wrong output, or other Bad Things. You can always leave
18 out an optimization clause if you are not sure about it; the only
19 consequence is that queries might run slower than they need to.
21 Additional optimization clauses might be added in future versions of
22 PostgreSQL. The ones described here are all the ones that release 18.0
25 It is also possible to attach a planner support function to the
26 function that underlies an operator, providing another way of telling
27 the system about the behavior of the operator. See Section 36.11 for
32 The COMMUTATOR clause, if provided, names an operator that is the
33 commutator of the operator being defined. We say that operator A is the
34 commutator of operator B if (x A y) equals (y B x) for all possible
35 input values x, y. Notice that B is also the commutator of A. For
36 example, operators < and > for a particular data type are usually each
37 others' commutators, and operator + is usually commutative with itself.
38 But operator - is usually not commutative with anything.
40 The left operand type of a commutable operator is the same as the right
41 operand type of its commutator, and vice versa. So the name of the
42 commutator operator is all that PostgreSQL needs to be given to look up
43 the commutator, and that's all that needs to be provided in the
46 It's critical to provide commutator information for operators that will
47 be used in indexes and join clauses, because this allows the query
48 optimizer to “flip around” such a clause to the forms needed for
49 different plan types. For example, consider a query with a WHERE clause
50 like tab1.x = tab2.y, where tab1.x and tab2.y are of a user-defined
51 type, and suppose that tab2.y is indexed. The optimizer cannot generate
52 an index scan unless it can determine how to flip the clause around to
53 tab2.y = tab1.x, because the index-scan machinery expects to see the
54 indexed column on the left of the operator it is given. PostgreSQL will
55 not simply assume that this is a valid transformation — the creator of
56 the = operator must specify that it is valid, by marking the operator
57 with commutator information.
61 The NEGATOR clause, if provided, names an operator that is the negator
62 of the operator being defined. We say that operator A is the negator of
63 operator B if both return Boolean results and (x A y) equals NOT (x B
64 y) for all possible inputs x, y. Notice that B is also the negator of
65 A. For example, < and >= are a negator pair for most data types. An
66 operator can never validly be its own negator.
68 Unlike commutators, a pair of unary operators could validly be marked
69 as each other's negators; that would mean (A x) equals NOT (B x) for
72 An operator's negator must have the same left and/or right operand
73 types as the operator to be defined, so just as with COMMUTATOR, only
74 the operator name need be given in the NEGATOR clause.
76 Providing a negator is very helpful to the query optimizer since it
77 allows expressions like NOT (x = y) to be simplified into x <> y. This
78 comes up more often than you might think, because NOT operations can be
79 inserted as a consequence of other rearrangements.
83 The RESTRICT clause, if provided, names a restriction selectivity
84 estimation function for the operator. (Note that this is a function
85 name, not an operator name.) RESTRICT clauses only make sense for
86 binary operators that return boolean. The idea behind a restriction
87 selectivity estimator is to guess what fraction of the rows in a table
88 will satisfy a WHERE-clause condition of the form:
91 for the current operator and a particular constant value. This assists
92 the optimizer by giving it some idea of how many rows will be
93 eliminated by WHERE clauses that have this form. (What happens if the
94 constant is on the left, you might be wondering? Well, that's one of
95 the things that COMMUTATOR is for...)
97 Writing new restriction selectivity estimation functions is far beyond
98 the scope of this chapter, but fortunately you can usually just use one
99 of the system's standard estimators for many of your own operators.
100 These are the standard restriction estimators:
108 You can frequently get away with using either eqsel or neqsel for
109 operators that have very high or very low selectivity, even if they
110 aren't really equality or inequality. For example, the
111 approximate-equality geometric operators use eqsel on the assumption
112 that they'll usually only match a small fraction of the entries in a
115 You can use scalarltsel, scalarlesel, scalargtsel and scalargesel for
116 comparisons on data types that have some sensible means of being
117 converted into numeric scalars for range comparisons. If possible, add
118 the data type to those understood by the function convert_to_scalar()
119 in src/backend/utils/adt/selfuncs.c. (Eventually, this function should
120 be replaced by per-data-type functions identified through a column of
121 the pg_type system catalog; but that hasn't happened yet.) If you do
122 not do this, things will still work, but the optimizer's estimates
123 won't be as good as they could be.
125 Another useful built-in selectivity estimation function is matchingsel,
126 which will work for almost any binary operator, if standard MCV and/or
127 histogram statistics are collected for the input data type(s). Its
128 default estimate is set to twice the default estimate used in eqsel,
129 making it most suitable for comparison operators that are somewhat less
130 strict than equality. (Or you could call the underlying
131 generic_restriction_selectivity function, providing a different default
134 There are additional selectivity estimation functions designed for
135 geometric operators in src/backend/utils/adt/geo_selfuncs.c: areasel,
136 positionsel, and contsel. At this writing these are just stubs, but you
137 might want to use them (or even better, improve them) anyway.
141 The JOIN clause, if provided, names a join selectivity estimation
142 function for the operator. (Note that this is a function name, not an
143 operator name.) JOIN clauses only make sense for binary operators that
144 return boolean. The idea behind a join selectivity estimator is to
145 guess what fraction of the rows in a pair of tables will satisfy a
146 WHERE-clause condition of the form:
147 table1.column1 OP table2.column2
149 for the current operator. As with the RESTRICT clause, this helps the
150 optimizer very substantially by letting it figure out which of several
151 possible join sequences is likely to take the least work.
153 As before, this chapter will make no attempt to explain how to write a
154 join selectivity estimator function, but will just suggest that you use
155 one of the standard estimators if one is applicable:
158 scalarltjoinsel for <
159 scalarlejoinsel for <=
160 scalargtjoinsel for >
161 scalargejoinsel for >=
162 matchingjoinsel for generic matching operators
163 areajoinsel for 2D area-based comparisons
164 positionjoinsel for 2D position-based comparisons
165 contjoinsel for 2D containment-based comparisons
169 The HASHES clause, if present, tells the system that it is permissible
170 to use the hash join method for a join based on this operator. HASHES
171 only makes sense for a binary operator that returns boolean, and in
172 practice the operator must represent equality for some data type or
175 The assumption underlying hash join is that the join operator can only
176 return true for pairs of left and right values that hash to the same
177 hash code. If two values get put in different hash buckets, the join
178 will never compare them at all, implicitly assuming that the result of
179 the join operator must be false. So it never makes sense to specify
180 HASHES for operators that do not represent some form of equality. In
181 most cases it is only practical to support hashing for operators that
182 take the same data type on both sides. However, sometimes it is
183 possible to design compatible hash functions for two or more data
184 types; that is, functions that will generate the same hash codes for
185 “equal” values, even though the values have different representations.
186 For example, it's fairly simple to arrange this property when hashing
187 integers of different widths.
189 To be marked HASHES, the join operator must appear in a hash index
190 operator family. This is not enforced when you create the operator,
191 since of course the referencing operator family couldn't exist yet. But
192 attempts to use the operator in hash joins will fail at run time if no
193 such operator family exists. The system needs the operator family to
194 find the data-type-specific hash function(s) for the operator's input
195 data type(s). Of course, you must also create suitable hash functions
196 before you can create the operator family.
198 Care should be exercised when preparing a hash function, because there
199 are machine-dependent ways in which it might fail to do the right
200 thing. For example, if your data type is a structure in which there
201 might be uninteresting pad bits, you cannot simply pass the whole
202 structure to hash_any. (Unless you write your other operators and
203 functions to ensure that the unused bits are always zero, which is the
204 recommended strategy.) Another example is that on machines that meet
205 the IEEE floating-point standard, negative zero and positive zero are
206 different values (different bit patterns) but they are defined to
207 compare equal. If a float value might contain negative zero then extra
208 steps are needed to ensure it generates the same hash value as positive
211 A hash-joinable operator must have a commutator (itself if the two
212 operand data types are the same, or a related equality operator if they
213 are different) that appears in the same operator family. If this is not
214 the case, planner errors might occur when the operator is used. Also,
215 it is a good idea (but not strictly required) for a hash operator
216 family that supports multiple data types to provide equality operators
217 for every combination of the data types; this allows better
222 The function underlying a hash-joinable operator must be marked
223 immutable or stable. If it is volatile, the system will never attempt
224 to use the operator for a hash join.
228 If a hash-joinable operator has an underlying function that is marked
229 strict, the function must also be complete: that is, it should return
230 true or false, never null, for any two nonnull inputs. If this rule is
231 not followed, hash-optimization of IN operations might generate wrong
232 results. (Specifically, IN might return false where the correct answer
233 according to the standard would be null; or it might yield an error
234 complaining that it wasn't prepared for a null result.)
238 The MERGES clause, if present, tells the system that it is permissible
239 to use the merge-join method for a join based on this operator. MERGES
240 only makes sense for a binary operator that returns boolean, and in
241 practice the operator must represent equality for some data type or
244 Merge join is based on the idea of sorting the left- and right-hand
245 tables into order and then scanning them in parallel. So, both data
246 types must be capable of being fully ordered, and the join operator
247 must be one that can only succeed for pairs of values that fall at the
248 “same place” in the sort order. In practice this means that the join
249 operator must behave like equality. But it is possible to merge-join
250 two distinct data types so long as they are logically compatible. For
251 example, the smallint-versus-integer equality operator is
252 merge-joinable. We only need sorting operators that will bring both
253 data types into a logically compatible sequence.
255 To be marked MERGES, the join operator must appear as an equality
256 member of a btree index operator family. This is not enforced when you
257 create the operator, since of course the referencing operator family
258 couldn't exist yet. But the operator will not actually be used for
259 merge joins unless a matching operator family can be found. The MERGES
260 flag thus acts as a hint to the planner that it's worth looking for a
261 matching operator family.
263 A merge-joinable operator must have a commutator (itself if the two
264 operand data types are the same, or a related equality operator if they
265 are different) that appears in the same operator family. If this is not
266 the case, planner errors might occur when the operator is used. Also,
267 it is a good idea (but not strictly required) for a btree operator
268 family that supports multiple data types to provide equality operators
269 for every combination of the data types; this allows better
274 The function underlying a merge-joinable operator must be marked
275 immutable or stable. If it is volatile, the system will never attempt
276 to use the operator for a merge join.