1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>36.15. Operator Optimization Information</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="xoper.html" title="36.14. User-Defined Operators" /><link rel="next" href="xindex.html" title="36.16. Interfacing Extensions to Indexes" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">36.15. Operator Optimization Information</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="xoper.html" title="36.14. User-Defined Operators">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="extend.html" title="Chapter 36. Extending SQL">Up</a></td><th width="60%" align="center">Chapter 36. Extending <acronym class="acronym">SQL</acronym></th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="xindex.html" title="36.16. Interfacing Extensions to Indexes">Next</a></td></tr></table><hr /></div><div class="sect1" id="XOPER-OPTIMIZATION"><div class="titlepage"><div><div><h2 class="title" style="clear: both">36.15. Operator Optimization Information <a href="#XOPER-OPTIMIZATION" class="id_link">#</a></h2></div></div></div><div class="toc"><dl class="toc"><dt><span class="sect2"><a href="xoper-optimization.html#XOPER-COMMUTATOR">36.15.1. <code class="literal">COMMUTATOR</code></a></span></dt><dt><span class="sect2"><a href="xoper-optimization.html#XOPER-NEGATOR">36.15.2. <code class="literal">NEGATOR</code></a></span></dt><dt><span class="sect2"><a href="xoper-optimization.html#XOPER-RESTRICT">36.15.3. <code class="literal">RESTRICT</code></a></span></dt><dt><span class="sect2"><a href="xoper-optimization.html#XOPER-JOIN">36.15.4. <code class="literal">JOIN</code></a></span></dt><dt><span class="sect2"><a href="xoper-optimization.html#XOPER-HASHES">36.15.5. <code class="literal">HASHES</code></a></span></dt><dt><span class="sect2"><a href="xoper-optimization.html#XOPER-MERGES">36.15.6. <code class="literal">MERGES</code></a></span></dt></dl></div><a id="id-1.8.3.18.2" class="indexterm"></a><p>
3 A <span class="productname">PostgreSQL</span> operator definition can include
4 several optional clauses that tell the system useful things about how
5 the operator behaves. These clauses should be provided whenever
6 appropriate, because they can make for considerable speedups in execution
7 of queries that use the operator. But if you provide them, you must be
8 sure that they are right! Incorrect use of an optimization clause can
9 result in slow queries, subtly wrong output, or other Bad Things.
10 You can always leave out an optimization clause if you are not sure
11 about it; the only consequence is that queries might run slower than
14 Additional optimization clauses might be added in future versions of
15 <span class="productname">PostgreSQL</span>. The ones described here are all
16 the ones that release 18.0 understands.
18 It is also possible to attach a planner support function to the function
19 that underlies an operator, providing another way of telling the system
20 about the behavior of the operator.
21 See <a class="xref" href="xfunc-optimization.html" title="36.11. Function Optimization Information">Section 36.11</a> for more information.
22 </p><div class="sect2" id="XOPER-COMMUTATOR"><div class="titlepage"><div><div><h3 class="title">36.15.1. <code class="literal">COMMUTATOR</code> <a href="#XOPER-COMMUTATOR" class="id_link">#</a></h3></div></div></div><p>
23 The <code class="literal">COMMUTATOR</code> clause, if provided, names an operator that is the
24 commutator of the operator being defined. We say that operator A is the
25 commutator of operator B if (x A y) equals (y B x) for all possible input
26 values x, y. Notice that B is also the commutator of A. For example,
27 operators <code class="literal"><</code> and <code class="literal">></code> for a particular data type are usually each others'
28 commutators, and operator <code class="literal">+</code> is usually commutative with itself.
29 But operator <code class="literal">-</code> is usually not commutative with anything.
31 The left operand type of a commutable operator is the same as the
32 right operand type of its commutator, and vice versa. So the name of
33 the commutator operator is all that <span class="productname">PostgreSQL</span>
34 needs to be given to look up the commutator, and that's all that needs to
35 be provided in the <code class="literal">COMMUTATOR</code> clause.
37 It's critical to provide commutator information for operators that
38 will be used in indexes and join clauses, because this allows the
39 query optimizer to <span class="quote">“<span class="quote">flip around</span>”</span> such a clause to the forms
40 needed for different plan types. For example, consider a query with
41 a WHERE clause like <code class="literal">tab1.x = tab2.y</code>, where <code class="literal">tab1.x</code>
42 and <code class="literal">tab2.y</code> are of a user-defined type, and suppose that
43 <code class="literal">tab2.y</code> is indexed. The optimizer cannot generate an
44 index scan unless it can determine how to flip the clause around to
45 <code class="literal">tab2.y = tab1.x</code>, because the index-scan machinery expects
46 to see the indexed column on the left of the operator it is given.
47 <span class="productname">PostgreSQL</span> will <span class="emphasis"><em>not</em></span> simply
48 assume that this is a valid transformation — the creator of the
49 <code class="literal">=</code> operator must specify that it is valid, by marking the
50 operator with commutator information.
51 </p></div><div class="sect2" id="XOPER-NEGATOR"><div class="titlepage"><div><div><h3 class="title">36.15.2. <code class="literal">NEGATOR</code> <a href="#XOPER-NEGATOR" class="id_link">#</a></h3></div></div></div><p>
52 The <code class="literal">NEGATOR</code> clause, if provided, names an operator that is the
53 negator of the operator being defined. We say that operator A
54 is the negator of operator B if both return Boolean results and
55 (x A y) equals NOT (x B y) for all possible inputs x, y.
56 Notice that B is also the negator of A.
57 For example, <code class="literal"><</code> and <code class="literal">>=</code> are a negator pair for most data types.
58 An operator can never validly be its own negator.
60 Unlike commutators, a pair of unary operators could validly be marked
61 as each other's negators; that would mean (A x) equals NOT (B x)
64 An operator's negator must have the same left and/or right operand types
65 as the operator to be defined, so just as with <code class="literal">COMMUTATOR</code>, only the operator
66 name need be given in the <code class="literal">NEGATOR</code> clause.
68 Providing a negator is very helpful to the query optimizer since
69 it allows expressions like <code class="literal">NOT (x = y)</code> to be simplified into
70 <code class="literal">x <> y</code>. This comes up more often than you might think, because
71 <code class="literal">NOT</code> operations can be inserted as a consequence of other rearrangements.
72 </p></div><div class="sect2" id="XOPER-RESTRICT"><div class="titlepage"><div><div><h3 class="title">36.15.3. <code class="literal">RESTRICT</code> <a href="#XOPER-RESTRICT" class="id_link">#</a></h3></div></div></div><p>
73 The <code class="literal">RESTRICT</code> clause, if provided, names a restriction selectivity
74 estimation function for the operator. (Note that this is a function
75 name, not an operator name.) <code class="literal">RESTRICT</code> clauses only make sense for
76 binary operators that return <code class="type">boolean</code>. The idea behind a restriction
77 selectivity estimator is to guess what fraction of the rows in a
78 table will satisfy a <code class="literal">WHERE</code>-clause condition of the form:
79 </p><pre class="programlisting">
82 for the current operator and a particular constant value.
83 This assists the optimizer by
84 giving it some idea of how many rows will be eliminated by <code class="literal">WHERE</code>
85 clauses that have this form. (What happens if the constant is on
86 the left, you might be wondering? Well, that's one of the things that
87 <code class="literal">COMMUTATOR</code> is for...)
89 Writing new restriction selectivity estimation functions is far beyond
90 the scope of this chapter, but fortunately you can usually just use
91 one of the system's standard estimators for many of your own operators.
92 These are the standard restriction estimators:
93 </p><table border="0" summary="Simple list" class="simplelist"><tr><td><code class="function">eqsel</code> for <code class="literal">=</code></td></tr><tr><td><code class="function">neqsel</code> for <code class="literal"><></code></td></tr><tr><td><code class="function">scalarltsel</code> for <code class="literal"><</code></td></tr><tr><td><code class="function">scalarlesel</code> for <code class="literal"><=</code></td></tr><tr><td><code class="function">scalargtsel</code> for <code class="literal">></code></td></tr><tr><td><code class="function">scalargesel</code> for <code class="literal">>=</code></td></tr></table><p>
95 You can frequently get away with using either <code class="function">eqsel</code> or <code class="function">neqsel</code> for
96 operators that have very high or very low selectivity, even if they
97 aren't really equality or inequality. For example, the
98 approximate-equality geometric operators use <code class="function">eqsel</code> on the assumption that
99 they'll usually only match a small fraction of the entries in a table.
101 You can use <code class="function">scalarltsel</code>, <code class="function">scalarlesel</code>,
102 <code class="function">scalargtsel</code> and <code class="function">scalargesel</code> for comparisons on
103 data types that have some sensible means of being converted into numeric
104 scalars for range comparisons. If possible, add the data type to those
105 understood by the function <code class="function">convert_to_scalar()</code> in
106 <code class="filename">src/backend/utils/adt/selfuncs.c</code>.
107 (Eventually, this function should be replaced by per-data-type functions
108 identified through a column of the <code class="classname">pg_type</code> system catalog; but that hasn't happened
109 yet.) If you do not do this, things will still work, but the optimizer's
110 estimates won't be as good as they could be.
112 Another useful built-in selectivity estimation function
113 is <code class="function">matchingsel</code>, which will work for almost any
114 binary operator, if standard MCV and/or histogram statistics are
115 collected for the input data type(s). Its default estimate is set to
116 twice the default estimate used in <code class="function">eqsel</code>, making
117 it most suitable for comparison operators that are somewhat less
118 strict than equality. (Or you could call the
119 underlying <code class="function">generic_restriction_selectivity</code>
120 function, providing a different default estimate.)
122 There are additional selectivity estimation functions designed for geometric
123 operators in <code class="filename">src/backend/utils/adt/geo_selfuncs.c</code>: <code class="function">areasel</code>, <code class="function">positionsel</code>,
124 and <code class="function">contsel</code>. At this writing these are just stubs, but you might want
125 to use them (or even better, improve them) anyway.
126 </p></div><div class="sect2" id="XOPER-JOIN"><div class="titlepage"><div><div><h3 class="title">36.15.4. <code class="literal">JOIN</code> <a href="#XOPER-JOIN" class="id_link">#</a></h3></div></div></div><p>
127 The <code class="literal">JOIN</code> clause, if provided, names a join selectivity
128 estimation function for the operator. (Note that this is a function
129 name, not an operator name.) <code class="literal">JOIN</code> clauses only make sense for
130 binary operators that return <code class="type">boolean</code>. The idea behind a join
131 selectivity estimator is to guess what fraction of the rows in a
132 pair of tables will satisfy a <code class="literal">WHERE</code>-clause condition of the form:
133 </p><pre class="programlisting">
134 table1.column1 OP table2.column2
136 for the current operator. As with the <code class="literal">RESTRICT</code> clause, this helps
137 the optimizer very substantially by letting it figure out which
138 of several possible join sequences is likely to take the least work.
140 As before, this chapter will make no attempt to explain how to write
141 a join selectivity estimator function, but will just suggest that
142 you use one of the standard estimators if one is applicable:
143 </p><table border="0" summary="Simple list" class="simplelist"><tr><td><code class="function">eqjoinsel</code> for <code class="literal">=</code></td></tr><tr><td><code class="function">neqjoinsel</code> for <code class="literal"><></code></td></tr><tr><td><code class="function">scalarltjoinsel</code> for <code class="literal"><</code></td></tr><tr><td><code class="function">scalarlejoinsel</code> for <code class="literal"><=</code></td></tr><tr><td><code class="function">scalargtjoinsel</code> for <code class="literal">></code></td></tr><tr><td><code class="function">scalargejoinsel</code> for <code class="literal">>=</code></td></tr><tr><td><code class="function">matchingjoinsel</code> for generic matching operators</td></tr><tr><td><code class="function">areajoinsel</code> for 2D area-based comparisons</td></tr><tr><td><code class="function">positionjoinsel</code> for 2D position-based comparisons</td></tr><tr><td><code class="function">contjoinsel</code> for 2D containment-based comparisons</td></tr></table><p>
144 </p></div><div class="sect2" id="XOPER-HASHES"><div class="titlepage"><div><div><h3 class="title">36.15.5. <code class="literal">HASHES</code> <a href="#XOPER-HASHES" class="id_link">#</a></h3></div></div></div><p>
145 The <code class="literal">HASHES</code> clause, if present, tells the system that
146 it is permissible to use the hash join method for a join based on this
147 operator. <code class="literal">HASHES</code> only makes sense for a binary operator that
148 returns <code class="literal">boolean</code>, and in practice the operator must represent
149 equality for some data type or pair of data types.
151 The assumption underlying hash join is that the join operator can
152 only return true for pairs of left and right values that hash to the
153 same hash code. If two values get put in different hash buckets, the
154 join will never compare them at all, implicitly assuming that the
155 result of the join operator must be false. So it never makes sense
156 to specify <code class="literal">HASHES</code> for operators that do not represent
157 some form of equality. In most cases it is only practical to support
158 hashing for operators that take the same data type on both sides.
159 However, sometimes it is possible to design compatible hash functions
160 for two or more data types; that is, functions that will generate the
161 same hash codes for <span class="quote">“<span class="quote">equal</span>”</span> values, even though the values
162 have different representations. For example, it's fairly simple
163 to arrange this property when hashing integers of different widths.
165 To be marked <code class="literal">HASHES</code>, the join operator must appear
166 in a hash index operator family. This is not enforced when you create
167 the operator, since of course the referencing operator family couldn't
168 exist yet. But attempts to use the operator in hash joins will fail
169 at run time if no such operator family exists. The system needs the
170 operator family to find the data-type-specific hash function(s) for the
171 operator's input data type(s). Of course, you must also create suitable
172 hash functions before you can create the operator family.
174 Care should be exercised when preparing a hash function, because there
175 are machine-dependent ways in which it might fail to do the right thing.
176 For example, if your data type is a structure in which there might be
177 uninteresting pad bits, you cannot simply pass the whole structure to
178 <code class="function">hash_any</code>. (Unless you write your other operators and
179 functions to ensure that the unused bits are always zero, which is the
180 recommended strategy.)
181 Another example is that on machines that meet the <acronym class="acronym">IEEE</acronym>
182 floating-point standard, negative zero and positive zero are different
183 values (different bit patterns) but they are defined to compare equal.
184 If a float value might contain negative zero then extra steps are needed
185 to ensure it generates the same hash value as positive zero.
187 A hash-joinable operator must have a commutator (itself if the two
188 operand data types are the same, or a related equality operator
189 if they are different) that appears in the same operator family.
190 If this is not the case, planner errors might occur when the operator
191 is used. Also, it is a good idea (but not strictly required) for
192 a hash operator family that supports multiple data types to provide
193 equality operators for every combination of the data types; this
194 allows better optimization.
195 </p><div class="note"><h3 class="title">Note</h3><p>
196 The function underlying a hash-joinable operator must be marked
197 immutable or stable. If it is volatile, the system will never
198 attempt to use the operator for a hash join.
199 </p></div><div class="note"><h3 class="title">Note</h3><p>
200 If a hash-joinable operator has an underlying function that is marked
202 function must also be complete: that is, it should return true or
203 false, never null, for any two nonnull inputs. If this rule is
204 not followed, hash-optimization of <code class="literal">IN</code> operations might
205 generate wrong results. (Specifically, <code class="literal">IN</code> might return
206 false where the correct answer according to the standard would be null;
207 or it might yield an error complaining that it wasn't prepared for a
209 </p></div></div><div class="sect2" id="XOPER-MERGES"><div class="titlepage"><div><div><h3 class="title">36.15.6. <code class="literal">MERGES</code> <a href="#XOPER-MERGES" class="id_link">#</a></h3></div></div></div><p>
210 The <code class="literal">MERGES</code> clause, if present, tells the system that
211 it is permissible to use the merge-join method for a join based on this
212 operator. <code class="literal">MERGES</code> only makes sense for a binary operator that
213 returns <code class="literal">boolean</code>, and in practice the operator must represent
214 equality for some data type or pair of data types.
216 Merge join is based on the idea of sorting the left- and right-hand tables
217 into order and then scanning them in parallel. So, both data types must
218 be capable of being fully ordered, and the join operator must be one
219 that can only succeed for pairs of values that fall at the
220 <span class="quote">“<span class="quote">same place</span>”</span>
221 in the sort order. In practice this means that the join operator must
222 behave like equality. But it is possible to merge-join two
223 distinct data types so long as they are logically compatible. For
224 example, the <code class="type">smallint</code>-versus-<code class="type">integer</code>
225 equality operator is merge-joinable.
226 We only need sorting operators that will bring both data types into a
227 logically compatible sequence.
229 To be marked <code class="literal">MERGES</code>, the join operator must appear
230 as an equality member of a <code class="literal">btree</code> index operator family.
231 This is not enforced when you create
232 the operator, since of course the referencing operator family couldn't
233 exist yet. But the operator will not actually be used for merge joins
234 unless a matching operator family can be found. The
235 <code class="literal">MERGES</code> flag thus acts as a hint to the planner that
236 it's worth looking for a matching operator family.
238 A merge-joinable operator must have a commutator (itself if the two
239 operand data types are the same, or a related equality operator
240 if they are different) that appears in the same operator family.
241 If this is not the case, planner errors might occur when the operator
242 is used. Also, it is a good idea (but not strictly required) for
243 a <code class="literal">btree</code> operator family that supports multiple data types to provide
244 equality operators for every combination of the data types; this
245 allows better optimization.
246 </p><div class="note"><h3 class="title">Note</h3><p>
247 The function underlying a merge-joinable operator must be marked
248 immutable or stable. If it is volatile, the system will never
249 attempt to use the operator for a merge join.
250 </p></div></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="xoper.html" title="36.14. User-Defined Operators">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="extend.html" title="Chapter 36. Extending SQL">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="xindex.html" title="36.16. Interfacing Extensions to Indexes">Next</a></td></tr><tr><td width="40%" align="left" valign="top">36.14. User-Defined Operators </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> 36.16. Interfacing Extensions to Indexes</td></tr></table></div></body></html>