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 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672
|
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.0 Transitional//EN">
<HTML
><HEAD
><TITLE
> CREATE OPERATOR
</TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet version 1.19"><LINK
REL="HOME"
TITLE="PostgreSQL User's Guide"
HREF="user.html"><LINK
REL="UP"
TITLE="SQL Commands"
HREF="sql-commands.html"><LINK
REL="PREVIOUS"
TITLE=" CREATE LANGUAGE
"
HREF="sql-createlanguage.html"><LINK
REL="NEXT"
TITLE=" CREATE RULE
"
HREF="sql-createrule.html"></HEAD
><BODY
BGCOLOR="#FFFFFF"
TEXT="#000000"
><DIV
CLASS="NAVHEADER"
><TABLE
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="3"
ALIGN="center"
>PostgreSQL User's Guide</TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="bottom"
><A
HREF="sql-createlanguage.html"
>Prev</A
></TD
><TD
WIDTH="80%"
ALIGN="center"
VALIGN="bottom"
></TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="bottom"
><A
HREF="sql-createrule.html"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><H1
>CREATE OPERATOR</H1
><DIV
CLASS="REFNAMEDIV"
><H2
>Name</H2
> CREATE OPERATOR
— Defines a new user operator
</DIV
><DIV
CLASS="REFSYNOPSISDIV"
><PRE
CLASS="SYNOPSIS"
>CREATE OPERATOR <TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
> (
PROCEDURE = <TT
CLASS="REPLACEABLE"
><I
>func_name</I
></TT
>
[, LEFTARG = <TT
CLASS="REPLACEABLE"
><I
>type1</I
></TT
> ]
[, RIGHTARG = <TT
CLASS="REPLACEABLE"
><I
>type2</I
></TT
> ]
[, COMMUTATOR = <TT
CLASS="REPLACEABLE"
><I
>com_op</I
></TT
> ]
[, NEGATOR = <TT
CLASS="REPLACEABLE"
><I
>neg_op</I
></TT
> ]
[, RESTRICT = <TT
CLASS="REPLACEABLE"
><I
>res_proc</I
></TT
> ]
[, HASHES ]
[, JOIN = <TT
CLASS="REPLACEABLE"
><I
>join_proc</I
></TT
> ]
[, SORT = <TT
CLASS="REPLACEABLE"
><I
>sort_op</I
></TT
> [, ...] ]
)
</PRE
><DIV
CLASS="REFSECT2"
><H3
> Inputs
</H3
><P
> </P
><P
></P
><DL
><DT
><TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
></DT
><DD
><P
> The operator to be defined. See below for allowable characters.
</P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>func_name</I
></TT
></DT
><DD
><P
>The function used to implement this operator.
</P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>type1</I
></TT
></DT
><DD
><P
>The type for the left-hand side of the operator, if any. This option would be
omitted for a right-unary operator.
</P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>type2</I
></TT
></DT
><DD
><P
>The type for the right-hand side of the operator, if any. This option would be
omitted for a left-unary operator.
</P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>com_op</I
></TT
></DT
><DD
><P
>The corresponding commutative operator.
</P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>neg_op</I
></TT
></DT
><DD
><P
>The corresponding negation operator.
</P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>res_proc</I
></TT
></DT
><DD
><P
>The corresponding restriction operator.
</P
></DD
><DT
>HASHES</DT
><DD
><P
>This operator can support a hash-join algorithm.
</P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>join_proc</I
></TT
></DT
><DD
><P
>Procedure supporting table joins.
</P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>sort_op</I
></TT
></DT
><DD
><P
>Operator to use for sorting.
</P
></DD
></DL
></DIV
><DIV
CLASS="REFSECT2"
><H3
> Outputs
</H3
><P
> <P
></P
></P><DL
><DT
><SPAN
CLASS="RETURNVALUE"
>CREATE</SPAN
></DT
><DD
><P
> Message returned if the operator is successfully created.
</P
></DD
></DL
><P>
</P
></DIV
></DIV
><DIV
CLASS="REFSECT1"
><H2
> Description
</H2
><P
><B
CLASS="COMMAND"
>CREATE OPERATOR</B
> defines a new operator,
<TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
>.
The user who defines an operator becomes its owner.
</P
><P
> The operator <TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
>
is a sequence of up to thirty two (32) characters in any combination
from the following:
<P
CLASS="LITERALLAYOUT"
>; + - * / < > = ~ ! @ # % ^ & | ` ? $ : </P
>
<BLOCKQUOTE
CLASS="NOTE"
><P
><B
>Note: </B
>No alphabetic characters are allowed in an operator name.
This enables <SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
> to parse SQL input
into tokens without requiring spaces between each token.</P
></BLOCKQUOTE
>
</P
><P
> The operator "!=" is mapped to "<>" on input, so they are
therefore equivalent.
</P
><P
> 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.
</P
><P
>Also, the
<TT
CLASS="REPLACEABLE"
><I
>func_name</I
></TT
> procedure must have
been previously defined using <B
CLASS="COMMAND"
>CREATE FUNCTION</B
> and must
be defined to accept the correct number of arguments
(either one or two).
</P
><P
> The commutator operator is present so that
<SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
> can
reverse the order of the operands if it wishes.
For example, the operator area-less-than, <<<,
would have a commutator
operator, area-greater-than, >>>.
Hence, the query optimizer could freely convert:
<PRE
CLASS="PROGRAMLISTING"
>"0,0,1,1"::box >>> MYBOXES.description
</PRE
>
to
<PRE
CLASS="PROGRAMLISTING"
>MYBOXES.description <<< "0,0,1,1"::box</PRE
>
</P
><P
> This allows the execution code to always use the latter
representation and simplifies the query optimizer some
what.
</P
><P
> Suppose that an
operator, area-equal, ===, exists, as well as an area not
equal, !==.
The negator operator allows the query optimizer to convert
<PRE
CLASS="PROGRAMLISTING"
>NOT MYBOXES.description === "0,0,1,1"::box
</PRE
>
to
<PRE
CLASS="PROGRAMLISTING"
>MYBOXES.description !== "0,0,1,1"::box
</PRE
>
</P
><P
> If a commutator operator name is supplied,
<SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
>
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 current (new) operator
as its commutator. This applies to the negator, as well.
</P
><P
> 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.
</P
><P
> The next two specifications are present to support the
query optimizer in performing joins.
<SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
> can always
evaluate a join (i.e., processing a clause with two tuple
variables separated by an operator that returns a boolean)
by iterative substitution [WONG76].
In addition, <SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
>
is planning on implementing a hash-join algorithm along
the lines of [SHAP86]; however, it must know whether this
strategy is applicable.
For example, a hash-join
algorithm is usable for a clause of the form:
<PRE
CLASS="PROGRAMLISTING"
>MYBOXES.description === MYBOXES2.description
</PRE
>
but not for a clause of the form:
<PRE
CLASS="PROGRAMLISTING"
>MYBOXES.description <<< MYBOXES2.description.
</PRE
>
The HASHES flag gives the needed information to the query
optimizer concerning whether a hash join strategy is
usable for the operator in question.</P
><P
> Similarly, the two sort operators indicate to the query
optimizer whether merge-sort is a usable join strategy and
what operators should be used to sort the two operand
classes. For the === clause above, the optimizer must
sort both relations using the operator, <<<. On the other
hand, merge-sort is not usable with the clause:
<PRE
CLASS="PROGRAMLISTING"
>MYBOXES.description <<< MYBOXES2.description
</PRE
>
</P
><P
> If other join strategies are found to be practical,
<SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
>
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.
</P
><P
> The last two pieces of the specification are present so
the query optimizer can estimate result sizes. If a
clause of the form:
<PRE
CLASS="PROGRAMLISTING"
>MYBOXES.description <<< "0,0,1,1"::box
</PRE
>
is present in the qualification,
then <SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
> may have to
estimate the fraction of the instances in MYBOXES that
satisfy the clause. The function
<TT
CLASS="REPLACEABLE"
><I
>res_proc</I
></TT
>
must be a registered function (meaning it is already defined using
define function(l)) which accepts one argument of the correct
data type and returns a floating point number. The
query optimizer simply calls this function, passing the
parameter "0,0,1,1" and multiplies the result by the relation
size to get the desired expected number of instances.
</P
><P
> 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 classes involved to
compute the desired expected result size.
</P
><P
> The difference between the function
<PRE
CLASS="PROGRAMLISTING"
>my_procedure_1 (MYBOXES.description, "0,0,1,1"::box)
</PRE
>
and the operator
<PRE
CLASS="PROGRAMLISTING"
>MYBOXES.description === "0,0,1,1"::box
</PRE
>
is that <SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
>
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.
</P
><DIV
CLASS="REFSECT2"
><H3
> Notes
</H3
><P
> Refer to the chapter on operators in the
<I
CLASS="CITETITLE"
>PostgreSQL User's Guide</I
>
for further information.
Refer to <B
CLASS="COMMAND"
>DROP OPERATOR</B
> to delete
user-defined operators from a database.
</P
></DIV
></DIV
><DIV
CLASS="REFSECT1"
><H2
> Usage
</H2
><P
>The following command defines a new operator,
area-equality, for the BOX data type.
</P
><PRE
CLASS="PROGRAMLISTING"
>CREATE OPERATOR === (
LEFTARG = box,
RIGHTARG = box,
PROCEDURE = area_equal_procedure,
COMMUTATOR = ===,
NEGATOR = !==,
RESTRICT = area_restriction_procedure,
HASHES,
JOIN = area-join-procedure,
SORT = <<<, <<<)
</PRE
></DIV
><DIV
CLASS="REFSECT1"
><H2
> Compatibility
</H2
><P
> CREATE OPERATOR is a <SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
> extension.
</P
><DIV
CLASS="REFSECT2"
><H3
> SQL92
</H3
><P
> There is no CREATE OPERATOR statement in <SPAN
CLASS="ACRONYM"
>SQL92</SPAN
>.
</P
></DIV
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="sql-createlanguage.html"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="user.html"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="sql-createrule.html"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>CREATE LANGUAGE</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="sql-commands.html"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>CREATE RULE</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>
|