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
|
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/create_operator.sgml,v 1.24 2002/01/20 22:19:56 petere Exp $
PostgreSQL documentation
-->
<refentry id="SQL-CREATEOPERATOR">
<refmeta>
<refentrytitle id="sql-createoperator-title">
CREATE OPERATOR
</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>
CREATE OPERATOR
</refname>
<refpurpose>
define a new operator
</refpurpose>
</refnamediv>
<refsynopsisdiv>
<refsynopsisdivinfo>
<date>2000-03-25</date>
</refsynopsisdivinfo>
<synopsis>
CREATE OPERATOR <replaceable>name</replaceable> ( PROCEDURE = <replaceable class="parameter">func_name</replaceable>
[, LEFTARG = <replaceable class="parameter">lefttype</replaceable>
] [, RIGHTARG = <replaceable class="parameter">righttype</replaceable> ]
[, COMMUTATOR = <replaceable class="parameter">com_op</replaceable> ] [, NEGATOR = <replaceable class="parameter">neg_op</replaceable> ]
[, RESTRICT = <replaceable class="parameter">res_proc</replaceable> ] [, JOIN = <replaceable class="parameter">join_proc</replaceable> ]
[, HASHES ] [, SORT1 = <replaceable class="parameter">left_sort_op</replaceable> ] [, SORT2 = <replaceable class="parameter">right_sort_op</replaceable> ] )
</synopsis>
<refsect2 id="R2-SQL-CREATEOPERATOR-1">
<refsect2info>
<date>2000-03-25</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term><replaceable class="parameter">name</replaceable></term>
<listitem>
<para>
The operator to be defined. See below for allowable characters.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">func_name</replaceable></term>
<listitem>
<para>
The function used to implement this operator.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">lefttype</replaceable></term>
<listitem>
<para>
The type of the left-hand argument of the operator, if any.
This option would be omitted for a left-unary operator.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">righttype</replaceable></term>
<listitem>
<para>
The type of the right-hand argument of the operator, if any.
This option would be omitted for a right-unary operator.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">com_op</replaceable></term>
<listitem>
<para>
The commutator of this operator.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">neg_op</replaceable></term>
<listitem>
<para>
The negator of this operator.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">res_proc</replaceable></term>
<listitem>
<para>
The restriction selectivity estimator function for this operator.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">join_proc</replaceable></term>
<listitem>
<para>
The join selectivity estimator function for this operator.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>HASHES</term>
<listitem>
<para>
Indicates this operator can support a hash join.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">left_sort_op</replaceable></term>
<listitem>
<para>
If this operator can support a merge join, the
operator that sorts the left-hand data type of this operator.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">right_sort_op</replaceable></term>
<listitem>
<para>
If this operator can support a merge join, the
operator that sorts the right-hand data type of this operator.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-CREATEOPERATOR-2">
<refsect2info>
<date>2000-03-25</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
CREATE
</computeroutput></term>
<listitem>
<para>
Message returned if the operator is successfully created.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv>
<refsect1 id="R1-SQL-CREATEOPERATOR-1">
<refsect1info>
<date>2000-03-25</date>
</refsect1info>
<title>
Description
</title>
<para>
<command>CREATE OPERATOR</command> defines a new operator,
<replaceable class="parameter">name</replaceable>.
The user who defines an operator becomes its owner.
</para>
<para>
The operator <replaceable class="parameter">name</replaceable>
is a sequence of up to <symbol>NAMEDATALEN</>-1 (31 by default) characters
from the following list:
<literallayout>
+ - * / < > = ~ ! @ # % ^ & | ` ? $
</literallayout>
There are a few restrictions on your choice of name:
<itemizedlist>
<listitem>
<para>
<literal>$</literal> cannot be defined as a single-character operator,
although it can be part of a multicharacter operator name.
</para>
</listitem>
<listitem>
<para>
<literal>--</literal> and <literal>/*</literal> cannot appear anywhere in an operator name,
since they will be taken as the start of a comment.
</para>
</listitem>
<listitem>
<para>
A multicharacter operator name cannot end in <literal>+</literal> or
<literal>-</literal>,
unless the name also contains at least one of these characters:
<literallayout>
~ ! @ # % ^ & | ` ? $
</literallayout>
For example, <literal>@-</literal> is an allowed operator name,
but <literal>*-</literal> is not.
This restriction allows <productname>PostgreSQL</productname> to
parse SQL-compliant queries without requiring spaces between tokens.
</para>
</listitem>
</itemizedlist>
<note>
<para>
When working with non-SQL-standard operator names, you will usually
need to separate adjacent operators with spaces to avoid ambiguity.
For example, if you have defined a left-unary operator named <literal>@</literal>,
you cannot write <literal>X*@Y</literal>; you must write
<literal>X* @Y</literal> to ensure that
<productname>PostgreSQL</productname> reads it as two operator names
not one.
</para>
</note>
</para>
<para>
The operator <literal>!=</literal> is mapped to <literal><></literal> on input, so these two names
are always equivalent.
</para>
<para>
At least one of LEFTARG and RIGHTARG must be defined. For
binary operators, both should be defined. For right unary
operators, only LEFTARG should be defined, while for left
unary operators only RIGHTARG should be defined.
</para>
<para>
The
<replaceable class="parameter">func_name</replaceable> procedure must have
been previously defined using <command>CREATE FUNCTION</command> and must
be defined to accept the correct number of arguments
(either one or two) of the indicated types.
</para>
<para>
The commutator operator should be identified if one exists,
so that <productname>PostgreSQL</productname> can
reverse the order of the operands if it wishes.
For example, the operator area-less-than, <<<,
would probably have a commutator
operator, area-greater-than, >>>.
Hence, the query optimizer could freely convert:
<programlisting>
box '((0,0), (1,1))' >>> MYBOXES.description
</programlisting>
to
<programlisting>
MYBOXES.description <<< box '((0,0), (1,1))'
</programlisting>
</para>
<para>
This allows the execution code to always use the latter
representation and simplifies the query optimizer somewhat.
</para>
<para>
Similarly, if there is a negator operator then it should be
identified.
Suppose that an
operator, area-equal, ===, exists, as well as an area not
equal, !==.
The negator link allows the query optimizer to simplify
<programlisting>
NOT MYBOXES.description === box '((0,0), (1,1))'
</programlisting>
to
<programlisting>
MYBOXES.description !== box '((0,0), (1,1))'
</programlisting>
</para>
<para>
If a commutator operator name is supplied,
<productname>PostgreSQL</productname>
searches for it in the catalog. If it is found and it
does not yet have a commutator itself, then the commutator's
entry is updated to have the newly created operator as its
commutator. This applies to the negator, as well.
This is to allow the definition of two operators that are
the commutators or the negators of each other. The first
operator should be defined without a commutator or negator
(as appropriate). When the second operator is defined,
name the first as the commutator or negator. The first
will be updated as a side effect. (As of
<application>PostgreSQL</application> <literal>6.5</literal>,
it also works to just have both operators refer to each other.)
</para>
<para>
The HASHES, SORT1, and SORT2 options are present to support the
query optimizer in performing joins.
<productname>PostgreSQL</productname> can always
evaluate a join (i.e., processing a clause with two tuple
variables separated by an operator that returns a <type>boolean</type>)
by iterative substitution [WONG76].
In addition, <productname>PostgreSQL</productname>
can use a hash-join algorithm along
the lines of [SHAP86]; however, it must know whether this
strategy is applicable. The current hash-join algorithm
is only correct for operators that represent equality tests;
furthermore, equality of the data type must mean bitwise equality
of the representation of the type. (For example, a data type that
contains unused bits that don't matter for equality tests could
not be hashjoined.)
The HASHES flag indicates to the query optimizer that a hash join
may safely be used with this operator.</para>
<para>
Similarly, the two sort operators indicate to the query
optimizer whether merge-sort is a usable join strategy and
which operators should be used to sort the two operand
classes. Sort operators should only be provided for an equality
operator, and they should refer to less-than operators for the
left and right side data types respectively.
</para>
<para>
If other join strategies are found to be practical,
<productname>PostgreSQL</productname>
will change the optimizer and run-time system to use
them and will require additional specification when an
operator is defined. Fortunately, the research community
invents new join strategies infrequently, and the added
generality of user-defined join strategies was not felt to
be worth the complexity involved.
</para>
<para>
The RESTRICT and JOIN options assist the query optimizer in estimating
result sizes. If a clause of the form:
<programlisting>
MYBOXES.description <<< box '((0,0), (1,1))'
</programlisting>
is present in the qualification,
then <productname>PostgreSQL</productname> may have to
estimate the fraction of the instances in MYBOXES that
satisfy the clause. The function
<replaceable class="parameter">res_proc</replaceable>
must be a registered function (meaning it is already defined using
<command>CREATE FUNCTION</command>) which accepts arguments of the correct
data types and returns a floating-point number. The
query optimizer simply calls this function, passing the
parameter <literal>((0,0), (1,1))</literal> and multiplies the result by the relation
size to get the expected number of instances.
</para>
<para>
Similarly, when the operands of the operator both contain
instance variables, the query optimizer must estimate the
size of the resulting join. The function join_proc will
return another floating-point number which will be multiplied
by the cardinalities of the two tables involved to
compute the expected result size.
</para>
<para>
The difference between the function
<programlisting>
my_procedure_1 (MYBOXES.description, box '((0,0), (1,1))')
</programlisting>
and the operator
<programlisting>
MYBOXES.description === box '((0,0), (1,1))'
</programlisting>
is that <productname>PostgreSQL</productname>
attempts to optimize operators and can
decide to use an index to restrict the search space when
operators are involved. However, there is no attempt to
optimize functions, and they are performed by brute force.
Moreover, functions can have any number of arguments while
operators are restricted to one or two.
</para>
<refsect2 id="R2-SQL-CREATEOPERATOR-3">
<refsect2info>
<date>2000-03-25</date>
</refsect2info>
<title>
Notes
</title>
<para>
Refer to the chapter on operators in the
<citetitle>PostgreSQL User's Guide</citetitle>
for further information.
Refer to <command>DROP OPERATOR</command> to delete
user-defined operators from a database.
</para>
</refsect2>
</refsect1>
<refsect1 id="R1-SQL-CREATEOPERATOR-2">
<title>
Usage
</title>
<para>The following command defines a new operator,
area-equality, for the BOX data type:
</para>
<programlisting>
CREATE OPERATOR === (
LEFTARG = box,
RIGHTARG = box,
PROCEDURE = area_equal_procedure,
COMMUTATOR = ===,
NEGATOR = !==,
RESTRICT = area_restriction_procedure,
JOIN = area_join_procedure,
HASHES,
SORT1 = <<<,
SORT2 = <<<
);
</programlisting>
</refsect1>
<refsect1 id="R1-SQL-CREATEOPERATOR-3">
<title>
Compatibility
</title>
<refsect2 id="R2-SQL-CREATEOPERATOR-4">
<refsect2info>
<date>2000-03-25</date>
</refsect2info>
<title>
SQL92
</title>
<para>
<command>CREATE OPERATOR</command>
is a <productname>PostgreSQL</productname> extension.
There is no <command>CREATE OPERATOR</command>
statement in <acronym>SQL92</acronym>.
</para>
</refsect2>
</refsect1>
</refentry>
<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->
|