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
|
<html>
<head>
<meta http-equiv="Content-Type" content="text/html; charset=ISO-8859-1">
<title>32.13.Operator Optimization Information</title>
<link rel="stylesheet" href="stylesheet.css" type="text/css">
<link rev="made" href="pgsql-docs@postgresql.org">
<meta name="generator" content="DocBook XSL Stylesheets V1.70.0">
<link rel="start" href="index.html" title="PostgreSQL 8.1.4 Documentation">
<link rel="up" href="extend.html" title="Chapter32.Extending SQL">
<link rel="prev" href="xoper.html" title="32.12.User-Defined Operators">
<link rel="next" href="xindex.html" title="32.14.Interfacing Extensions To Indexes">
<link rel="copyright" href="ln-legalnotice.html" title="Legal Notice">
</head>
<body bgcolor="white" text="black" link="#0000FF" vlink="#840084" alink="#0000FF"><div class="sect1" lang="en">
<div class="titlepage"><div><div><h2 class="title" style="clear: both">
<a name="xoper-optimization"></a>32.13.Operator Optimization Information</h2></div></div></div>
<p> A <span class="productname">PostgreSQL</span> operator definition can include
several optional clauses that tell the system useful things about how
the operator behaves. These clauses should be provided whenever
appropriate, because they can make for considerable speedups in execution
of queries that use the operator. But if you provide them, you must be
sure that they are right! Incorrect use of an optimization clause can
result in server process crashes, subtly wrong output, or other Bad Things.
You can always leave out an optimization clause if you are not sure
about it; the only consequence is that queries might run slower than
they need to.
</p>
<p> Additional optimization clauses might be added in future versions of
<span class="productname">PostgreSQL</span>. The ones described here are all
the ones that release 8.1.4 understands.
</p>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id711539"></a>32.13.1.<code class="literal">COMMUTATOR</code></h3></div></div></div>
<p> The <code class="literal">COMMUTATOR</code> clause, if provided, names an operator that is the
commutator of the operator being defined. We say that operator A is the
commutator of operator B if (x A y) equals (y B x) for all possible input
values x, y. Notice that B is also the commutator of A. For example,
operators <code class="literal"><</code> and <code class="literal">></code> for a particular data type are usually each others'
commutators, and operator <code class="literal">+</code> is usually commutative with itself.
But operator <code class="literal">-</code> is usually not commutative with anything.
</p>
<p> The left operand type of a commutable operator is the same as the
right operand type of its commutator, and vice versa. So the name of
the commutator operator is all that <span class="productname">PostgreSQL</span>
needs to be given to look up the commutator, and that's all that needs to
be provided in the <code class="literal">COMMUTATOR</code> clause.
</p>
<p> It's critical to provide commutator information for operators that
will be used in indexes and join clauses, because this allows the
query optimizer to “<span class="quote">flip around</span>” such a clause to the forms
needed for different plan types. For example, consider a query with
a WHERE clause like <code class="literal">tab1.x = tab2.y</code>, where <code class="literal">tab1.x</code>
and <code class="literal">tab2.y</code> are of a user-defined type, and suppose that
<code class="literal">tab2.y</code> is indexed. The optimizer cannot generate an
index scan unless it can determine how to flip the clause around to
<code class="literal">tab2.y = tab1.x</code>, because the index-scan machinery expects
to see the indexed column on the left of the operator it is given.
<span class="productname">PostgreSQL</span> will <span class="emphasis"><em>not</em></span> simply
assume that this is a valid transformation [mdash ] the creator of the
<code class="literal">=</code> operator must specify that it is valid, by marking the
operator with commutator information.
</p>
<p> When you are defining a self-commutative operator, you just do it.
When you are defining a pair of commutative operators, things are
a little trickier: how can the first one to be defined refer to the
other one, which you haven't defined yet? There are two solutions
to this problem:
</p>
<div class="itemizedlist"><ul type="disc">
<li><p> One way is to omit the <code class="literal">COMMUTATOR</code> clause in the first operator that
you define, and then provide one in the second operator's definition.
Since <span class="productname">PostgreSQL</span> knows that commutative
operators come in pairs, when it sees the second definition it will
automatically go back and fill in the missing <code class="literal">COMMUTATOR</code> clause in
the first definition.
</p></li>
<li><p> The other, more straightforward way is just to include <code class="literal">COMMUTATOR</code> clauses
in both definitions. When <span class="productname">PostgreSQL</span> processes
the first definition and realizes that <code class="literal">COMMUTATOR</code> refers to a nonexistent
operator, the system will make a dummy entry for that operator in the
system catalog. This dummy entry will have valid data only
for the operator name, left and right operand types, and result type,
since that's all that <span class="productname">PostgreSQL</span> can deduce
at this point. The first operator's catalog entry will link to this
dummy entry. Later, when you define the second operator, the system
updates the dummy entry with the additional information from the second
definition. If you try to use the dummy operator before it's been filled
in, you'll just get an error message.
</p></li>
</ul></div>
<p>
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id711762"></a>32.13.2.<code class="literal">NEGATOR</code></h3></div></div></div>
<p> The <code class="literal">NEGATOR</code> clause, if provided, names an operator that is the
negator of the operator being defined. We say that operator A
is the negator of operator B if both return Boolean results and
(x A y) equals NOT (x B y) for all possible inputs x, y.
Notice that B is also the negator of A.
For example, <code class="literal"><</code> and <code class="literal">>=</code> are a negator pair for most data types.
An operator can never validly be its own negator.
</p>
<p> Unlike commutators, a pair of unary operators could validly be marked
as each others' negators; that would mean (A x) equals NOT (B x)
for all x, or the equivalent for right unary operators.
</p>
<p> An operator's negator must have the same left and/or right operand types
as the operator to be defined, so just as with <code class="literal">COMMUTATOR</code>, only the operator
name need be given in the <code class="literal">NEGATOR</code> clause.
</p>
<p> Providing a negator is very helpful to the query optimizer since
it allows expressions like <code class="literal">NOT (x = y)</code> to be simplified into
<code class="literal">x <> y</code>. This comes up more often than you might think, because
<code class="literal">NOT</code> operations can be inserted as a consequence of other rearrangements.
</p>
<p> Pairs of negator operators can be defined using the same methods
explained above for commutator pairs.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id711854"></a>32.13.3.<code class="literal">RESTRICT</code></h3></div></div></div>
<p> The <code class="literal">RESTRICT</code> clause, if provided, names a restriction selectivity
estimation function for the operator. (Note that this is a function
name, not an operator name.) <code class="literal">RESTRICT</code> clauses only make sense for
binary operators that return <code class="type">boolean</code>. The idea behind a restriction
selectivity estimator is to guess what fraction of the rows in a
table will satisfy a <code class="literal">WHERE</code>-clause condition of the form
</p>
<pre class="programlisting">column OP constant</pre>
<p>
for the current operator and a particular constant value.
This assists the optimizer by
giving it some idea of how many rows will be eliminated by <code class="literal">WHERE</code>
clauses that have this form. (What happens if the constant is on
the left, you may be wondering? Well, that's one of the things that
<code class="literal">COMMUTATOR</code> is for...)
</p>
<p> Writing new restriction selectivity estimation functions is far beyond
the scope of this chapter, but fortunately you can usually just use
one of the system's standard estimators for many of your own operators.
These are the standard restriction estimators:
</p>
<table class="simplelist" border="0" summary="Simple list">
<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> or <code class="literal"><=</code>
</td></tr>
<tr><td>
<code class="function">scalargtsel</code> for <code class="literal">></code> or <code class="literal">>=</code>
</td></tr>
</table>
<p>
It might seem a little odd that these are the categories, but they
make sense if you think about it. <code class="literal">=</code> will typically accept only
a small fraction of the rows in a table; <code class="literal"><></code> will typically reject
only a small fraction. <code class="literal"><</code> will accept a fraction that depends on
where the given constant falls in the range of values for that table
column (which, it just so happens, is information collected by
<code class="command">ANALYZE</code> and made available to the selectivity estimator).
<code class="literal"><=</code> will accept a slightly larger fraction than <code class="literal"><</code> for the same
comparison constant, but they're close enough to not be worth
distinguishing, especially since we're not likely to do better than a
rough guess anyhow. Similar remarks apply to <code class="literal">></code> and <code class="literal">>=</code>.
</p>
<p> You can frequently get away with using either <code class="function">eqsel</code> or <code class="function">neqsel</code> for
operators that have very high or very low selectivity, even if they
aren't really equality or inequality. For example, the
approximate-equality geometric operators use <code class="function">eqsel</code> on the assumption that
they'll usually only match a small fraction of the entries in a table.
</p>
<p> You can use <code class="function">scalarltsel</code> and <code class="function">scalargtsel</code> for comparisons on data types that
have some sensible means of being converted into numeric scalars for
range comparisons. If possible, add the data type to those understood
by the function <code class="function">convert_to_scalar()</code> in <code class="filename">src/backend/utils/adt/selfuncs.c</code>.
(Eventually, this function should be replaced by per-data-type functions
identified through a column of the <code class="classname">pg_type</code> system catalog; but that hasn't happened
yet.) If you do not do this, things will still work, but the optimizer's
estimates won't be as good as they could be.
</p>
<p> There are additional selectivity estimation functions designed for geometric
operators in <code class="filename">src/backend/utils/adt/geo_selfuncs.c</code>: <code class="function">areasel</code>, <code class="function">positionsel</code>,
and <code class="function">contsel</code>. At this writing these are just stubs, but you may want
to use them (or even better, improve them) anyway.
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id712162"></a>32.13.4.<code class="literal">JOIN</code></h3></div></div></div>
<p> The <code class="literal">JOIN</code> clause, if provided, names a join selectivity
estimation function for the operator. (Note that this is a function
name, not an operator name.) <code class="literal">JOIN</code> clauses only make sense for
binary operators that return <code class="type">boolean</code>. The idea behind a join
selectivity estimator is to guess what fraction of the rows in a
pair of tables will satisfy a <code class="literal">WHERE</code>-clause condition of the form
</p>
<pre class="programlisting">table1.column1 OP table2.column2</pre>
<p>
for the current operator. As with the <code class="literal">RESTRICT</code> clause, this helps
the optimizer very substantially by letting it figure out which
of several possible join sequences is likely to take the least work.
</p>
<p> As before, this chapter will make no attempt to explain how to write
a join selectivity estimator function, but will just suggest that
you use one of the standard estimators if one is applicable:
</p>
<table class="simplelist" border="0" summary="Simple list">
<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> or <code class="literal"><=</code>
</td></tr>
<tr><td>
<code class="function">scalargtjoinsel</code> for <code class="literal">></code> or <code class="literal">>=</code>
</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>
</p>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id712320"></a>32.13.5.<code class="literal">HASHES</code></h3></div></div></div>
<p> The <code class="literal">HASHES</code> clause, if present, tells the system that
it is permissible to use the hash join method for a join based on this
operator. <code class="literal">HASHES</code> only makes sense for a binary operator that
returns <code class="literal">boolean</code>, and in practice the operator had better be
equality for some data type.
</p>
<p> The assumption underlying hash join is that the join operator can
only return true for pairs of left and right values that hash to the
same hash code. If two values get put in different hash buckets, the
join will never compare them at all, implicitly assuming that the
result of the join operator must be false. So it never makes sense
to specify <code class="literal">HASHES</code> for operators that do not represent
equality.
</p>
<p> To be marked <code class="literal">HASHES</code>, the join operator must appear
in a hash index operator class. This is not enforced when you create
the operator, since of course the referencing operator class couldn't
exist yet. But attempts to use the operator in hash joins will fail
at run time if no such operator class exists. The system needs the
operator class to find the data-type-specific hash function for the
operator's input data type. Of course, you must also supply a suitable
hash function before you can create the operator class.
</p>
<p> Care should be exercised when preparing a hash function, because there
are machine-dependent ways in which it might fail to do the right thing.
For example, if your data type is a structure in which there may be
uninteresting pad bits, you can't simply pass the whole structure to
<code class="function">hash_any</code>. (Unless you write your other operators and
functions to ensure that the unused bits are always zero, which is the
recommended strategy.)
Another example is that on machines that meet the <acronym class="acronym">IEEE</acronym>
floating-point standard, negative zero and positive zero are different
values (different bit patterns) but they are defined to compare equal.
If a float value might contain negative zero then extra steps are needed
to ensure it generates the same hash value as positive zero.
</p>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> The function underlying a hash-joinable operator must be marked
immutable or stable. If it is volatile, the system will never
attempt to use the operator for a hash join.
</p>
</div>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> If a hash-joinable operator has an underlying function that is marked
strict, the
function must also be complete: that is, it should return true or
false, never null, for any two nonnull inputs. If this rule is
not followed, hash-optimization of <code class="literal">IN</code> operations may
generate wrong results. (Specifically, <code class="literal">IN</code> might return
false where the correct answer according to the standard would be null; or it might
yield an error complaining that it wasn't prepared for a null result.)
</p>
</div>
</div>
<div class="sect2" lang="en">
<div class="titlepage"><div><div><h3 class="title">
<a name="id712448"></a>32.13.6.<code class="literal">MERGES</code> (<code class="literal">SORT1</code>, <code class="literal">SORT2</code>, <code class="literal">LTCMP</code>, <code class="literal">GTCMP</code>)</h3></div></div></div>
<p> The <code class="literal">MERGES</code> clause, if present, tells the system that
it is permissible to use the merge-join method for a join based on this
operator. <code class="literal">MERGES</code> only makes sense for a binary operator that
returns <code class="literal">boolean</code>, and in practice the operator must represent
equality for some data type or pair of data types.
</p>
<p> Merge join is based on the idea of sorting the left- and right-hand tables
into order and then scanning them in parallel. So, both data types must
be capable of being fully ordered, and the join operator must be one
that can only succeed for pairs of values that fall at the
“<span class="quote">same place</span>”
in the sort order. In practice this means that the join operator must
behave like equality. But unlike hash join, where the left and right
data types had better be the same (or at least bitwise equivalent),
it is possible to merge-join two
distinct data types so long as they are logically compatible. For
example, the <code class="type">smallint</code>-versus-<code class="type">integer</code> equality operator
is merge-joinable.
We only need sorting operators that will bring both data types into a
logically compatible sequence.
</p>
<p> Execution of a merge join requires that the system be able to identify
four operators related to the merge-join equality operator: less-than
comparison for the left operand data type, less-than comparison for the
right operand data type, less-than comparison between the two data types, and
greater-than comparison between the two data types. (These are actually
four distinct operators if the merge-joinable operator has two different
operand data types; but when the operand types are the same the three
less-than operators are all the same operator.)
It is possible to
specify these operators individually by name, as the <code class="literal">SORT1</code>,
<code class="literal">SORT2</code>, <code class="literal">LTCMP</code>, and <code class="literal">GTCMP</code> options
respectively. The system will fill in the default names
<code class="literal"><</code>, <code class="literal"><</code>, <code class="literal"><</code>, <code class="literal">></code>
respectively if any of these are omitted when <code class="literal">MERGES</code> is
specified. Also, <code class="literal">MERGES</code> will be assumed to be implied if any
of these four operator options appear, so it is possible to specify
just some of them and let the system fill in the rest.
</p>
<p> The operand data types of the four comparison operators can be deduced
from the operand types of the merge-joinable operator, so just as with
<code class="literal">COMMUTATOR</code>, only the operator names need be given in these
clauses. Unless you are using peculiar choices of operator names,
it's sufficient to write <code class="literal">MERGES</code> and let the system fill in
the details.
(As with <code class="literal">COMMUTATOR</code> and <code class="literal">NEGATOR</code>, the system is
able to make dummy
operator entries if you happen to define the equality operator before
the other ones.)
</p>
<p> There are additional restrictions on operators that you mark
merge-joinable. These restrictions are not currently checked by
<code class="command">CREATE OPERATOR</code>, but errors may occur when
the operator is used if any are not true:
</p>
<div class="itemizedlist"><ul type="disc">
<li><p> A merge-joinable equality operator must have a merge-joinable
commutator (itself if the two operand data types are the same, or a related
equality operator if they are different).
</p></li>
<li><p> If there is a merge-joinable operator relating any two data types
A and B, and another merge-joinable operator relating B to any
third data type C, then A and C must also have a merge-joinable
operator; in other words, having a merge-joinable operator must
be transitive.
</p></li>
<li><p> Bizarre results will ensue at run time if the four comparison
operators you name do not sort the data values compatibly.
</p></li>
</ul></div>
<p>
</p>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> The function underlying a merge-joinable operator must be marked
immutable or stable. If it is volatile, the system will never
attempt to use the operator for a merge join.
</p>
</div>
<div class="note" style="margin-left: 0.5in; margin-right: 0.5in;">
<h3 class="title">Note</h3>
<p> In <span class="productname">PostgreSQL</span> versions before 7.3,
the <code class="literal">MERGES</code> shorthand was not available: to make a
merge-joinable operator one had to write both <code class="literal">SORT1</code> and
<code class="literal">SORT2</code> explicitly. Also, the <code class="literal">LTCMP</code> and
<code class="literal">GTCMP</code>
options did not exist; the names of those operators were hardwired as
<code class="literal"><</code> and <code class="literal">></code> respectively.
</p>
</div>
</div>
</div></body>
</html>
|