func.sgml 91.7 KB
Newer Older
Peter Eisentraut's avatar
Peter Eisentraut committed
1
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/func.sgml,v 1.50 2001/02/05 19:21:45 petere Exp $ -->
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

<chapter id="functions">
 <title>Functions and Operators</title>

 <para>
  <productname>Postgres</productname> provides a large number of
  functions and operators for the built-in data types.  Users can also
  define their own functions and operators, as described in the
  <citetitle>Programmer's Guide</citetitle>.  The
  <application>psql</application> commands <command>\df</command> and
  <command>\do</command> can be used to show the list of all actually
  available function and operators, respectively.
 </para>

 <para>
  If you are concerned about portability then take note that most of
  the functions and operators described in this chapter, with the
  exception of the most trivial arithmetic and comparison operators
  and some explicitly marked functions, are not specified by the SQL
  standard.  However, many other RDBMS packages provide a lot of the
  same or similar functions, and some of the ones provided in
  <productname>Postgres</productname> have in fact been inspired by
  other implementations.
 </para>

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

 <sect1 id="functions-logical">
  <title>Logical Operators</title>

  <para>
   The usual logical operators are available:

   <simplelist>
    <member>AND</member>
    <member>OR</member>
    <member>NOT</member>
   </simplelist>

   SQL uses a three-valued boolean logic where NULL represents
   <quote>unknown</quote>.  Observe the following truth tables:

   <informaltable>
    <tgroup cols="4">
     <thead>
      <row>
       <entry><replaceable>a</replaceable></entry>
       <entry><replaceable>b</replaceable></entry>
       <entry><replaceable>a</replaceable> AND <replaceable>b</replaceable></entry>
       <entry><replaceable>a</replaceable> OR <replaceable>b</replaceable></entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry>TRUE</entry>
       <entry>TRUE</entry>
       <entry>TRUE</entry>
       <entry>TRUE</entry>
      </row>

      <row>
       <entry>TRUE</entry>
       <entry>FALSE</entry>
       <entry>FALSE</entry>
       <entry>TRUE</entry>
      </row>

      <row>
       <entry>TRUE</entry>
       <entry>NULL</entry>
       <entry>NULL</entry>
       <entry>TRUE</entry>
      </row>

      <row>
       <entry>FALSE</entry>
       <entry>FALSE</entry>
       <entry>FALSE</entry>
       <entry>FALSE</entry>
      </row>

      <row>
       <entry>FALSE</entry>
       <entry>NULL</entry>
       <entry>FALSE</entry>
       <entry>NULL</entry>
      </row>
     </tbody>
    </tgroup>
   </informaltable>

   <informaltable>
    <tgroup cols="2">
     <thead>
      <row>
       <entry><replaceable>a</replaceable></entry>
       <entry>NOT <replaceable>a</replaceable></entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry>TRUE</entry>
       <entry>FALSE</entry>
      </row>

      <row>
       <entry>FALSE</entry>
       <entry>TRUE</entry>
      </row>

      <row>
       <entry>NULL</entry>
       <entry>NULL</entry>
      </row>
     </tbody>
    </tgroup>
   </informaltable>
  </para>
 </sect1>

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
 <sect1 id="functions-comparison">
  <title>Comparison Operators</title>

  <table>
   <title>Comparison Operators</TITLE>
   <tgroup cols="2">
    <thead>
     <row>
      <entry>Operator</entry>
      <entry>Description</entry>
     </row>
    </thead>

    <tbody>
     <row>
      <entry> <literal>&lt;</literal> </entry>
      <entry>less than</entry>
     </row>

     <row>
      <entry> <literal>&gt;</literal> </entry>
      <entry>greater than</entry>
     </row>

     <row>
      <entry> <literal>&lt;=</literal> </entry>
      <entry>less than or equal to</entry>
     </row>

     <row>
      <entry> <literal>&gt;=</literal> </entry>
      <entry>greater than or equal to</entry>
     </row>

     <row>
      <entry> <literal>=</literal> </entry>
      <entry>equal</entry>
     </row>

     <row>
      <entry> <literal>&lt;&gt;</literal> or <literal>!=</literal> </entry>
      <entry>not equal</entry>
     </row>
    </tbody>
   </tgroup>
  </table>

  <note>
171
   <para>
172 173 174 175
    The <literal>!=</literal> operator is converted to
    <literal>&lt;&gt;</literal> in the parser stage.  It is not
    possible to implement <literal>!=</literal> and
    <literal>&lt;&gt;</literal> operators that do different things.
176
   </para>
177 178 179 180 181 182 183 184 185 186
  </note>

  <para>
   Comparison operators are available for all data types where this
   makes sense.  All comparison operators are binary operators that
   return boolean values; expressions like <literal>1 &lt; 2 &lt;
   3</literal> are not valid (because there is no
   <literal>&lt;</literal> operator to compare a boolean with
   <literal>3</literal>).
  </para>
187

Peter Eisentraut's avatar
Peter Eisentraut committed
188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210
  <para>
   In addition to the comparison operators, the special
   <token>BETWEEN</token> construct is available.
<synopsis>
<replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
</synopsis>
   is equivalent to
<synopsis>
<replaceable>a</replaceable> &gt;= <replaceable>x</replaceable> AND <replaceable>a</replaceable> &lt;= <replaceable>y</replaceable>
</synopsis>
   Similarly,
<synopsis>
<replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
</synopsis>
   is equivalent to
<synopsis>
<replaceable>a</replaceable> &lt; <replaceable>x</replaceable> OR <replaceable>a</replaceable> &gt; <replaceable>y</replaceable>
</synopsis>
   There is no difference between the two respective forms apart from
   the <acronym>CPU</acronym> cycles required to rewrite the first one
   into the second one internally.
  </para>

211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226
  <para>
   To check whether a value is or is not NULL, use the constructs
<synopsis>
<replaceable>expression</replaceable> IS NULL
<replaceable>expression</replaceable> IS NOT NULL
</synopsis>
   Do <emphasis>not</emphasis> use
   <literal><replaceable>expression</replaceable> = NULL</literal>
   because NULL is not <quote>equal to</quote> NULL.  (NULL represents
   an unknown value, so it is not known whether two unknown values are
   equal.)  <productname>Postgres</productname> implicitly converts
   <literal>= NULL</literal> clauses to <literal>IS NULL</literal> to
   allow some broken client applications (such as
   <productname>Microsoft Access</productname>) to work, but this may
   be discontinued in a future release.
  </para>
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
 </sect1>


 <sect1 id="functions-math">
  <title>Mathematical Functions and Operators</title>

  <table>
   <title>Mathematical Operators</TITLE>

   <tgroup cols="4">
    <thead>
     <row>
      <entry>Name</entry>
      <entry>Description</entry>
      <entry>Example</entry>
      <entry>Result</entry>
     </row>
    </thead>

    <tbody>
     <row>
      <entry> <literal>+</literal> </entry>
      <entry>Addition</entry>
      <entry>2 + 3</entry>
      <entry>5</entry>
     </row>

     <row>
      <entry> <literal>-</literal> </entry>
      <entry>Subtraction</entry>
      <entry>2 - 3</entry>
      <entry>-1</entry>
     </row>

     <row>
      <entry> <literal>*</literal> </entry>
      <entry>Multiplication</entry>
      <entry>2 * 3</entry>
      <entry>6</entry>
     </row>

     <row>
      <entry> <literal>/</literal> </entry>
      <entry>Division (integer division truncates results)</entry>
      <entry>4 / 2</entry>
      <entry>2</entry>
     </row>

     <row>
      <entry> <literal>%</literal> </entry>
      <entry>Modulo (remainder)</entry>
      <entry>5 % 4</entry>
      <entry>1</entry>
     </row>

     <row>
      <entry> <literal>^</literal> </entry>
      <entry>Exponentiation</entry>
      <entry>2.0 ^ 3.0</entry>
      <entry>8.0</entry>
     </row>

     <row>
      <entry> <literal>|/</literal> </entry>
      <entry>Square root</entry>
      <entry>|/ 25.0</entry>
      <entry>5.0</entry>
     </row>

     <row>
      <entry> <literal>||/</literal> </entry>
      <entry>Cube root</entry>
      <entry>||/ 27.0</entry>
      <entry>3</entry>
     </row>

     <row>
      <entry> <literal>!</literal> </entry>
      <entry>Factorial</entry>
      <entry>5 !</entry>
      <entry>120</entry>
     </row>

     <row>
      <entry> <literal>!!</literal> </entry>
      <entry>Factorial (left operator)</entry>
      <entry>!! 5</entry>
      <entry>120</entry>
     </row>

     <row>
      <entry> <literal>@</literal> </entry>
      <entry>Absolute value</entry>
      <entry>@ -5.0</entry>
      <entry>5.0</entry>
     </row>
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

     <row>
      <entry> <literal>&amp;</literal> </entry>
      <entry>Binary AND</entry>
      <entry>91 & 15</entry>
      <entry>11</entry>
     </row>

     <row>
      <entry> <literal>|</literal> </entry>
      <entry>Binary OR</entry>
      <entry>32 | 3</entry>
      <entry>35</entry>
     </row>

     <row>
      <entry> <literal>#</literal> </entry>
      <entry>Binary XOR</entry>
      <entry>17 # 5</entry>
      <entry>20</entry>
     </row>

     <row>
      <entry> <literal>~</literal> </entry>
      <entry>Binary NOT</entry>
      <entry>~1</entry>
      <entry>-2</entry>
     </row>

     <row>
      <entry> &lt;&lt; </entry>
      <entry>Binary shift left</entry>
      <entry>1 &lt;&lt; 4</entry>
      <entry>16</entry>
     </row>

     <row>
      <entry> &gt;&gt; </entry>
      <entry>Binary shift right</entry>
      <entry>8 &gt;&gt; 2</entry>
      <entry>2</entry>
     </row>

366 367 368 369
    </tbody>
   </tgroup>
  </table>

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
  <para>
   The <quote>binary</quote> operators are also available for the bit
   string types <type>BIT</type> and <type>BIT VARYING</type>.

   <table>
    <title>Bit String Binary Operators</title>

    <tgroup cols="2">
     <thead>
      <row>
       <entry>Example</entry>
       <entry>Result</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry>B'10001' & B'01101'</entry>
       <entry>00001</entry>
      </row>
      <row>
       <entry>B'10001' | B'01101'</entry>
       <entry>11101</entry>
      </row>
      <row>
       <entry>B'10001' # B'01101'</entry>
       <entry>11110</entry>
      </row>
      <row>
       <entry>~ B'10001'</entry>
       <entry>01110</entry>
      </row>
      <row>
       <entry>B'10001' << 3</entry>
       <entry>01000</entry>
      </row>
      <row>
       <entry>B'10001' >> 2</entry>
       <entry>00100</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   Bit string arguments to <literal>&</literal>, <literal>|</literal>,
   and <literal>#</literal> must be of equal length.  When bit
   shifting, the original length of the string is preserved, as shown
   here.
  </para>
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

  <table tocentry="1">
   <title>Mathematical Functions</title>
   <tgroup cols="5">
    <thead>
     <row>
      <entry>Function</entry>
      <entry>Return Type</entry>
      <entry>Description</entry>
      <entry>Example</entry>
      <entry>Result</entry>
     </row>
    </thead>

    <tbody>
     <row>
      <entry>abs(<replaceable>x</replaceable>)</entry>
      <entry>(same as argument type)</entry>
      <entry>absolute value</entry>
      <entry>abs(-17.4)</entry>
      <entry>17.4</entry>
     </row>

     <row>
      <entry>cbrt(<type>double precision</type>)</entry>
      <entry><type>double precision</type></entry>
      <entry>cube root</entry>
      <entry>cbrt(27.0)</entry>
447
      <entry>3.0</entry>
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
     </row>

     <row>
      <entry>ceil(<type>numeric</type>)</entry>
      <entry><type>numeric</type></entry>
      <entry>smallest integer not less than argument</entry>
      <entry>ceil(-42.8)</entry>
      <entry>-42</entry>
     </row>

     <row>
      <entry>degrees(<type>double precision</type>)</entry>
      <entry><type>double precision</type></entry>
      <entry>convert radians to degrees</entry>
      <entry>degrees(0.5)</entry>
      <entry>28.6478897565412</entry>
     </row>

     <row>
      <entry>exp(<type>double precision</type>)</entry>
      <entry><type>double precision</type></entry>
      <entry>exponential function</entry>
      <entry>exp(1.0)</entry>
      <entry>2.71828182845905</entry>
     </row>

     <row>
      <entry>floor(<type>numeric</type>)</entry>
      <entry><type>numeric</type></entry>
      <entry>largest integer not greater than argument</entry>
      <entry>floor(-42.8)</entry>
479
      <entry>-43</entry>
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 673 674 675 676 677 678 679 680 681 682
     </row>

     <row>
      <entry>ln(<type>double precision</type>)</entry>
      <entry><type>double precision</type></entry>
      <entry>natural logarithm</entry>
      <entry>ln(2.0)</entry>
      <entry>0.693147180559945</entry>
     </row>

     <row>
      <entry>log(<type>double precision</type>)</entry>
      <entry><type>double precision</type></entry>
      <entry>base 10 logarithm</entry>
      <entry>log(100.0)</entry>
      <entry>2.0</entry>
     </row>

     <row>
      <entry>log(<parameter>base</parameter> <type>numeric</type>, <parameter>x</parameter> <type>numeric</type>)</entry>
      <entry><type>numeric</type></entry>
      <entry>logarithm to specified base</entry>
      <entry>log(2.0, 64.0)</entry>
      <entry>6.0</entry>
     </row>

     <row>
      <entry>mod(<parameter>y</parameter>, <parameter>x</parameter>)</entry>
      <entry>(same as argument types)</entry>
      <entry>remainder (modulo) of the division <parameter>y</parameter>/<parameter>x</parameter></entry>
      <entry>mod(9,4)</entry>
      <entry>1</entry>
     </row>

     <row>
      <entry>pi()</entry>
      <entry><type>double precision</type></entry>
      <entry><quote>Pi</quote> constant</entry>
      <entry>pi()</entry>
      <entry>3.14159265358979</entry>
     </row>

     <row>
      <entry>pow(<type>double precision</type>, <type>double precision</type>)</entry>
      <entry><type>double precision</type></entry>
      <entry>raise a number to the specified exponent</entry>
      <entry>pow(9.0, 3.0)</entry>
      <entry>729.0</entry>
     </row>

     <row>
      <entry>radians(<type>double precision</type>)</entry>
      <entry><type>double precision</type></entry>
      <entry>convert degrees to radians</entry>
      <entry>radians(45.0)</entry>
      <entry>0.785398163397448</entry>
     </row>

     <row>
      <entry>random()</entry>
      <entry><type>double precision</type></entry>
      <entry>a pseudo-random value between 0.0 to 1.0</entry>
      <entry>random()</entry>
      <entry></entry>
     </row>

     <row>
      <entry>round(<type>double precision</type>)</entry>
      <entry><type>double precision</type></entry>
      <entry>round to nearest integer</entry>
      <entry>round(42.4)</entry>
      <entry>42</entry>
     </row>

     <row>
      <entry>round(<parameter>value</parameter> <type>numeric</type>, <parameter>scale</parameter> <type>integer</type>)</entry>
      <entry><type>numeric</type></entry>
      <entry>round to specified number of decimal places</entry>
      <entry>round(42.4382, 2)</entry>
      <entry>42.44</entry>
     </row>
<!--
     <row>
      <entry>setseed(<replaceable>new-seed</replaceable>)</entry>
      <entry>set seed for subsequent random() calls</entry>
      <entry>setseed(0.54823)</entry>
      <entry></entry>
     </row>
-->
     <row>
      <entry>sqrt(<type>double precision</type>)</entry>
      <entry><type>double precision</type></entry>
      <entry>square root</entry>
      <entry>sqrt(2.0)</entry>
      <entry>1.4142135623731</entry>
     </row>

     <row>
      <entry>trunc(<type>double precision</type>)</entry>
      <entry><type>double precision</type></entry>
      <entry>truncate (toward zero)</entry>
      <entry>trunc(42.8)</entry>
      <entry>42</entry>
     </row>

     <row>
      <entry>trunc(<parameter>value</parameter> <type>numeric</type>, <parameter>scale</parameter> <type>integer</type>)</entry>
      <entry><type>numeric</type></entry>
      <entry>truncate to specified number of decimal places</entry>
      <entry>round(42.4382, 2)</entry>
      <entry>42.43</entry>
     </row>

    </tbody>
   </tgroup>
  </table>

  <para>
   The functions <function>exp</function>, <function>ln</function>,
   <function>log</function>, <function>pow</function>,
   <function>round</function> (1 argument), <function>sqrt</function>,
   and <function>trunc</function> (1 argument) are also available for
   the type <type>numeric</type> in place of <type>double
   precision</type>.  Many of these functions are implemented on top
   of the host system's C library and behavior in boundary cases could
   therefore vary depending on the operating system.
  </para>

  <table>
   <title>Trigonometric Functions</title>

   <tgroup cols="2">
    <thead>
     <row>
      <entry>Function</entry>
      <entry>Description</entry>
     </row>
    </thead>

    <tbody>
     <row>
      <entry>acos(<replaceable>x</replaceable>)</entry>
      <entry>inverse cosine</entry>
     </row>

     <row>
      <entry>asin(<replaceable>x</replaceable>)</entry>
      <entry>inverse sine</entry>
     </row>

     <row>
      <entry>atan(<replaceable>x</replaceable>)</entry>
      <entry>inverse tangent</entry>
     </row>

     <row>
      <entry>atan2(<replaceable>x</replaceable>, <replaceable>y</replaceable>)</entry>
      <entry>inverse tangent of <replaceable>y</replaceable>/<replaceable>x</replaceable></entry>
     </row>

     <row>
      <entry>cos(<replaceable>x</replaceable>)</entry>
      <entry>cosine</entry>
     </row>

     <row>
      <entry>cot(<replaceable>x</replaceable>)</entry>
      <entry>cotangent</entry>
     </row>

     <row>
      <entry>sin(<replaceable>x</replaceable>)</entry>
      <entry>sine</entry>
     </row>

     <row>
      <entry>tan(<replaceable>x</replaceable>)</entry>
      <entry>tangent</entry>
     </row>
    </tbody>
   </tgroup>
  </table>

  <para>
   All trigonometric functions have arguments and return values of
   type <type>double precision</type>.
  </para>

 </sect1>


 <sect1 id="functions-string">
  <title>String Functions and Operators</title>

  <para>
   This section describes functions and operators for examining and
   manipulating string values.  Strings in this context include values
   of all the types <type>CHARACTER</type>, <type>CHARACTER
   VARYING</type>, and <type>TEXT</type>.  Unless otherwise noted, all
   of the functions listed below work on all of these types, but be
   wary of potential effects of the automatic padding when using the
   <type>CHARACTER</type> type.  Generally the functions described
   here also work on data of non-string types by converting that data
683 684
   to a string representation first.  Some functions also exist
   natively for bit string types.
685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782
  </para>

  <para>
   SQL defines some string functions with a special syntax where
   certain keywords rather than commas are used to separate the
   arguments.  Details are in <xref linkend="functions-string-sql">.
   These functions are also implemented using the regular syntax for
   function invocation.  (See <xref linkend="functions-string-other">.)
  </para>

  <table id="functions-string-sql">
   <title><acronym>SQL</acronym> String Functions and Operators</title>
   <tgroup cols="5">
    <thead>
     <row>
      <entry>Function</entry>
      <entry>Return Type</entry>
      <entry>Description</entry>
      <entry>Example</entry>
      <entry>Result</entry>  
     </row>
    </thead>

    <tbody>
     <row>
      <entry> <parameter>string</parameter> <literal>||</literal> <parameter>string</parameter> </entry>
      <entry> <type>text</type> </entry>
      <entry>string concatenation</entry>
      <entry>'Postgre' || 'SQL'</entry>
      <entry>PostgreSQL</entry>
     </row>

     <row>
      <entry>char_length(<parameter>string</parameter>) or character_length(<parameter>string</parameter>)</entry>
      <entry><type>integer</type></entry>
      <entry>length of string</entry>
      <entry>char_length('jose')</entry>
      <entry>4</entry>
     </row>

     <row>
      <entry>lower(<parameter>string</parameter>)</entry>
      <entry><type>text</type></entry>
      <entry>Convert string to lower case.</entry>
      <entry>lower('TOM')</entry>
      <entry>tom</entry>
     </row>

     <row>
      <entry>octet_length(<parameter>string</parameter>)</entry>
      <entry><type>integer</type></entry>
      <entry>number of bytes in string</entry>
      <entry>octet_length('jose')</entry>
      <entry>4</entry>
     </row>

     <row>
      <entry>position(<parameter>substring</parameter> in <parameter>string</parameter>)</entry>
      <entry><type>integer</type></entry>
      <entry>location of specified substring</entry>
      <entry>position('om' in 'Thomas')</entry>
      <entry>3</entry>
     </row>

     <row>
      <entry>substring(<parameter>string</parameter> <optional>from <type>integer</type></optional> <optional>for <type>integer</type></optional>)</entry>
      <entry><type>text</type></entry>
      <entry>extract substring</entry>
      <entry>substring('Thomas' from 2 for 3)</entry>
      <entry>oma</entry>
     </row>

     <row>
      <entry>
       trim(<optional>leading | trailing | both</optional>
       <optional><parameter>characters</parameter></optional> from
       <parameter>string</parameter>)
      </entry>
      <entry><type>text</type></entry>
      <entry>
       Removes the longest string containing only the
       <parameter>characters</parameter> (a space by default) from the
       beginning/end/both ends of the <parameter>string</parameter>.
      </entry>
      <entry>trim(both 'x' from 'xTomx')</entry>
      <entry>Tom</entry>
     </row>

     <row>
      <entry>upper(<parameter>string</parameter>)</entry>
      <entry><type>text</type></entry>
      <entry>Convert string to upper case.</entry>
      <entry>upper('tom')</entry>
      <entry>TOM</entry>
     </row>
    </tbody>
   </tgroup>
  </table>
783

784
  <para>
785 786 787
   Additional string manipulation functions are available and are
   listed below.  Some of them are used internally to implement the
   SQL string functions listed above.
788
  </para>
789

790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969
  <table id="functions-string-other">
   <title>Other String Functions</title>
   <tgroup cols="5">
    <thead>
     <row>
      <entry>Function</entry>
      <entry>Return type</entry>
      <entry>Description</entry>
      <entry>Example</entry>
      <entry>Result</entry>
     </row>
    </thead>

    <tbody>
     <row>
      <entry>ascii(<type>text</type>)</entry>
      <entry>integer</entry>
      <entry>Returns the <acronym>ASCII</acronym> code of the first character of the argument.</entry>
      <entry>ascii('x')</entry>
      <entry>120</entry>
     </row>

     <row>
      <entry>btrim(<parameter>string</parameter> <type>text</type>, <parameter>trim</parameter> <type>text</type>)</entry>
      <entry><type>text</type></entry>
      <entry>
       Remove (trim) the longest string consisting only of characters
       in <parameter>trim</parameter> from the start and end of
       <parameter>string</parameter>.
      </entry>
      <entry>btrim('xyxtrimyyx','xy')</entry>
      <entry>trim</entry>
     </row>

     <row>
      <entry>chr(<type>integer</type>)</entry>
      <entry><type>text</type></entry>
      <entry>Returns the character with the given <acronym>ASCII</acronym> code.</entry>
      <entry>chr(65)</entry>
      <entry>A</entry>
     </row>

     <row>
      <entry>initcap(<type>text</type>)</entry>
      <entry><type>text</type></entry>
      <entry>Converts first letter of each word (whitespace separated) to upper case.</entry>
      <entry>initcap('hello thomas')</entry>
      <entry>Hello Thomas</entry>
     </row>

     <row>
      <entry>
       lpad(<parameter>string</parameter> <type>text</type>,
       <parameter>length</parameter> <type>integer</type>
       <optional>, <parameter>fill</parameter> <type>text</type></optional>)
      </entry>
      <entry>text</entry>
      <entry>
       Fills up the <parameter>string</parameter> to length
       <parameter>length</parameter> by prepending the characters
       <parameter>fill</parameter> (a space by default).  If the
       <parameter>string</parameter> is already longer than
       <parameter>length</parameter> then it is truncated (on the
       right).
      </entry>
      <entry>lpad('hi', 5, 'xy')</entry>
      <entry>xyxhi</entry>
     </row>

     <row>
      <entry>ltrim(<parameter>string</parameter> <type>text</type>, <parameter>trim</parameter> <type>text</type>)</entry>
      <entry><type>text</type></entry>
      <entry>
       Removes the longest string containing only characters from
       <parameter>trim</parameter> from the start of the string.
      </entry>
      <entry>ltrim('zzzytrim','xyz')</entry>
      <entry>trim</entry>
     </row>

     <row>
      <entry>repeat(<type>text</type>, <type>integer</type>)</entry>
      <entry><type>text</type></entry>
      <entry>Repeat text a number of times.</entry>
      <entry>repeat('Pg', 4)</entry>
      <entry>PgPgPgPg</entry>
     </row>

     <row>
      <entry>
       rpad(<parameter>string</parameter> <type>text</type>,
       <parameter>length</parameter> <type>integer</type>
       <optional>, <parameter>fill</parameter> <type>text</type></optional>)
      </entry>
      <entry><type>text</type></entry>
      <entry>
       Fills up the <parameter>string</parameter> to length
       <parameter>length</parameter> by appending the characters
       <parameter>fill</parameter> (a space by default).  If the
       <parameter>string</parameter> is already longer than
       <parameter>length</parameter> then it is truncated.
      </entry>
      <entry>rpad('hi', 5, 'xy')</entry>
      <entry>hixyx</entry>
     </row>

     <row>
      <entry>rtrim(<parameter>string</parameter> text, <parameter>trim</parameter> text)</entry>
      <entry><type>text</type></entry>
      <entry>
       Removes the longest string containing only characters from
       <parameter>trim</parameter> from the end of the string.
      </entry>
      <entry>rtrim('trimxxxx','x')</entry>
      <entry>trim</entry>
     </row>

     <row>
      <entry>strpos(<parameter>string</parameter>, <parameter>substring</parameter>)</entry>
      <entry><type>text</type></entry>
      <entry>
       Locates specified substring. (same as
       <literal>position(<parameter>substring</parameter> in
       <parameter>string</parameter>)</literal>, but note the reversed
       argument order)
      </entry>
      <entry>strpos('high','ig')</entry>
     </row>

     <row>
      <entry>substr(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</entry>
      <entry><type>text</type></entry>
      <entry>
       Extracts specified substring. (same as <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
      </entry>
      <entry>substr('alphabet', 3, 2)</entry>
      <entry>ph</entry>
     </row>

     <row>
      <entry>to_ascii(<type>text</type> <optional>, <parameter>encoding</parameter></optional>)</entry>
      <entry><type>text</type></entry>
      <entry>Converts text from multibyte encoding to <acronym>ASCII</acronym>.</entry>
      <entry>to_ascii('Karel')</entry>
      <entry></entry>
     </row>

     <row>
      <entry>
       translate(<parameter>string</parameter> <type>text</type>,
       <parameter>from</parameter> <type>text</type>,
       <parameter>to</parameter> <type>text</type>)
      </entry>
      <entry><type>text</type></entry>
      <entry>
       Any character in <parameter>string</parameter> that matches a
       character in the <parameter>from</parameter> set is replaced by
       the corresponding character in the <parameter>to</parameter>
       set.
      </entry>
      <entry>translate('12345', '14', 'ax')</entry>
      <entry>a23x5</entry>
     </row>       

    </tbody>
   </tgroup>
  </table>

  <para>
   The <function>to_ascii</function> function supports conversion from
   LATIN1, LATIN2, WIN1250 (CP1250) only.
  </para>
 </sect1>


 <sect1 id="functions-matching">
  <title>Pattern Matching</title>

  <para>
   There are two separate approaches to pattern matching provided by
970
   <productname>Postgres</productname>:  the <acronym>SQL</acronym>
971 972 973
   <function>LIKE</function> operator and
   <acronym>POSIX</acronym>-style regular expressions.
  </para>
974

975
  <tip>
976
   <para>
977 978 979
    If you have pattern matching needs that go beyond this, or want to
    make pattern-driven substitutions or translations, consider
    writing a user-defined function in Perl or Tcl.
980
   </para>
981 982 983 984 985 986 987 988 989
  </tip>

  <sect2 id="functions-like">
   <title>Pattern Matching with <function>LIKE</function></title>

<synopsis>
<replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional> ESCAPE <replaceable>escape-character</replaceable> </optional>
<replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional> ESCAPE <replaceable>escape-character</replaceable> </optional>
</synopsis>
990 991

   <para>
992 993 994 995 996 997 998 999 1000
    Every <replaceable>pattern</replaceable> defines a set of strings.
    The <function>LIKE</function> expression returns true if the
    <replaceable>string</replaceable> is contained in the set of
    strings represented by <replaceable>pattern</replaceable>.  (As
    expected, the <function>NOT LIKE</function> expression returns
    false if <function>LIKE</function> returns true, and vice versa.
    An equivalent expression is <literal>NOT
    (<replaceable>string</replaceable> LIKE
    <replaceable>pattern</replaceable>)</literal>.)
1001 1002
   </para>

1003 1004
   <para>
    If <replaceable>pattern</replaceable> does not contain percent
1005
    signs or underscore, then the pattern only represents the string
1006 1007 1008
    itself; in that case <function>LIKE</function> acts like the
    equals operator.  An underscore (<literal>_</literal>) in
    <replaceable>pattern</replaceable> stands for (matches) any single
1009 1010
    character; a percent sign (<literal>%</literal>) matches any string
    of zero or more characters.
1011 1012 1013 1014 1015 1016 1017 1018 1019 1020 1021 1022 1023
   </para>

   <informalexample>
    <para>
     Some examples:
<programlisting>
'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
'abc' LIKE 'c'      <lineannotation>false</lineannotation>
</programlisting>
    </para>
   </informalexample>
1024

1025
   <para>
1026
    <function>LIKE</function> pattern matches always cover the entire
1027
    string.  To match a pattern anywhere within a string, the
1028
    pattern must therefore start and end with a percent sign.
1029
   </para>
1030 1031

   <para>
1032 1033 1034 1035
    To match a literal underscore or percent sign without matching
    other characters, the respective character in
    <replaceable>pattern</replaceable> must be 
    preceded by the escape character.  The default escape
1036
    character is the backslash but a different one may be selected by
1037 1038 1039 1040 1041 1042 1043 1044 1045
    using the <literal>ESCAPE</literal> clause.  To match the escape
    character itself, write two escape characters.
   </para>

   <para>
    Note that the backslash already has a special meaning in string
    literals, so to write a pattern constant that contains a backslash
    you must write two backslashes in the query.  You can avoid this by
    selecting a different escape character with <literal>ESCAPE</literal>.
1046
   </para>
1047 1048

   <para>
1049 1050
    The keyword <token>ILIKE</token> can be used instead of
    <token>LIKE</token> to make the match case insensitive according
1051
    to the active locale.  This is not in the SQL standard but is a
1052
    <productname>Postgres</productname> extension.
1053
   </para>
1054

1055 1056
   <para>
    The operator <literal>~~</literal> is equivalent to
1057 1058 1059
    <function>LIKE</function>, and <literal>~~*</literal> corresponds to
    <function>ILIKE</function>.  There are also
    <literal>!~~</literal> and <literal>!~~*</literal> operators that
1060 1061 1062 1063 1064
    represent <function>NOT LIKE</function> and <function>NOT
    ILIKE</function>.  All of these are also
    <productname>Postgres</productname>-specific.
   </para>
  </sect2>
1065

1066 1067 1068

  <sect2 id="functions-regexp">
   <title>POSIX Regular Expressions</title>
1069

1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090 1091 1092 1093 1094 1095 1096 1097 1098 1099 1100 1101 1102 1103 1104 1105 1106
   <table>
    <title>Regular Expression Match Operators</title>

    <tgroup cols="3">
     <thead>
      <row>
       <entry>Operator</entry>
       <entry>Description</entry>
       <entry>Example</entry>
      </row>
     </thead>

     <tbody>
       <ROW>
	<ENTRY> <literal>~</literal> </ENTRY>
	<ENTRY>Matches regular expression, case sensitive</ENTRY>
	<ENTRY>'thomas' ~ '.*thomas.*'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> <literal>~*</literal> </ENTRY>
	<ENTRY>Matches regular expression, case insensitive</ENTRY>
	<ENTRY>'thomas' ~* '.*Thomas.*'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> <literal>!~</literal> </ENTRY>
	<ENTRY>Does not match regular expression, case sensitive</ENTRY>
	<ENTRY>'thomas' !~ '.*Thomas.*'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> <literal>!~*</literal> </ENTRY>
	<ENTRY>Does not match regular expression, case insensitive</ENTRY>
	<ENTRY>'thomas' !~* '.*vadim.*'</ENTRY>
       </ROW>
     </tbody>
    </tgroup>
   </table>

1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 1118 1119 1120 1121 1122 1123 1124 1125 1126 1127 1128 1129
   <para>
    POSIX regular expressions provide a more powerful means for
    pattern matching than the <function>LIKE</function> function.
    Many Unix tools such as <command>egrep</command>,
    <command>sed</command>, or <command>awk</command> use a pattern
    matching language that is similar to the one described here.
   </para>

   <para>
    A regular expression is a character sequence that is an
    abbreviated definition of a set of strings (a <firstterm>regular
    set</firstterm>).  A string is said to match a regular expression
    if it is a member of the regular set described by the regular
    expression.  As with <function>LIKE</function>, pattern characters
    match string characters exactly unless they are special characters
    in the regular expression language --- but regular expressions use
    different special characters than <function>LIKE</function> does.
    Unlike <function>LIKE</function> patterns, a
    regular expression is allowed to match anywhere within a string, unless
    the regular expression is explicitly anchored to the beginning or
    end of the string.
   </para>

1130 1131

<!-- derived from the re_format.7 man page -->
1132
   <para>
1133 1134 1135 1136
    Regular expressions (<quote>RE</quote>s), as defined in POSIX
    1003.2, come in two forms: modern REs (roughly those of
    <command>egrep</command>; 1003.2 calls these
    <quote>extended</quote> REs) and obsolete REs (roughly those of
1137 1138
    <command>ed</command>; 1003.2 <quote>basic</quote> REs).
    <productname>Postgres</productname> implements the modern form.
1139
   </para>
1140

1141
   <para>
1142 1143 1144 1145
    A (modern) RE is one or more non-empty
    <firstterm>branches</firstterm>, separated by
    <literal>|</literal>.  It matches anything that matches one of the
    branches.
1146
   </para>
1147

1148
   <para>
1149 1150 1151
    A branch is one or more <firstterm>pieces</firstterm>,
    concatenated.  It matches a match for the first, followed by a
    match for the second, etc.
1152
   </para>
1153

Bruce Momjian's avatar
Bruce Momjian committed
1154
   <para>
1155 1156 1157 1158 1159 1160 1161 1162
    A piece is an <firstterm>atom</firstterm> possibly followed by a
    single <literal>*</literal>, <literal>+</literal>,
    <literal>?</literal>, or <firstterm>bound</firstterm>.  An atom
    followed by <literal>*</literal> matches a sequence of 0 or more
    matches of the atom.  An atom followed by <literal>+</literal>
    matches a sequence of 1 or more matches of the atom.  An atom
    followed by <literal>?</literal> matches a sequence of 0 or 1
    matches of the atom.
Bruce Momjian's avatar
Bruce Momjian committed
1163
   </para>
1164

1165 1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192
   <para>
    A <firstterm>bound</firstterm> is <literal>{</literal> followed by
    an unsigned decimal integer, possibly followed by
    <literal>,</literal> possibly followed by another unsigned decimal
    integer, always followed by <literal>}</literal>.  The integers
    must lie between 0 and <symbol>RE_DUP_MAX</symbol> (255)
    inclusive, and if there are two of them, the first may not exceed
    the second.  An atom followed by a bound containing one integer
    <replaceable>i</replaceable> and no comma matches a sequence of
    exactly <replaceable>i</replaceable> matches of the atom.  An atom
    followed by a bound containing one integer
    <replaceable>i</replaceable> and a comma matches a sequence of
    <replaceable>i</replaceable> or more matches of the atom.  An atom
    followed by a bound containing two integers
    <replaceable>i</replaceable> and <replaceable>j</replaceable>
    matches a sequence of <replaceable>i</replaceable> through
    <replaceable>j</replaceable> (inclusive) matches of the atom.
   </para>

   <note>
    <para>
     A repetition operator (<literal>?</literal>,
     <literal>*</literal>, <literal>+</literal>, or bounds) cannot
     follow another repetition operator.  A repetition operator cannot
     begin an expression or subexpression or follow
     <literal>^</literal> or <literal>|</literal>.
    </para>
   </note>
1193

1194
   <para>
1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211
    An <firstterm>atom</firstterm> is a regular expression enclosed in
    <literal>()</literal> (matching a match for the regular
    expression), an empty set of <literal>()</literal> (matching the
    null string), a <firstterm>bracket expression</firstterm> (see
    below), <literal>.</literal> (matching any single character),
    <literal>^</literal> (matching the null string at the beginning of
    a line), <literal>$</literal> (matching the null string at the end
    of a line), a <literal>\</literal> followed by one of the
    characters <literal>^.[$()|*+?{\</literal> (matching that
    character taken as an ordinary character), a <literal>\</literal>
    followed by any other character (matching that character taken as
    an ordinary character, as if the <literal>\</literal> had not been
    present), or a single character with no other significance
    (matching that character).  A <literal>{</literal> followed by a
    character other than a digit is an ordinary character, not the
    beginning of a bound.  It is illegal to end an RE with
    <literal>\</literal>.
1212
   </para>
1213

1214 1215 1216 1217 1218 1219 1220
   <para>
    Note that the backslash (<literal>\</literal>) already has a special
    meaning in string
    literals, so to write a pattern constant that contains a backslash
    you must write two backslashes in the query.
   </para>

1221
   <para>
1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234
    A <firstterm>bracket expression</firstterm> is a list of
    characters enclosed in <literal>[]</literal>.  It normally matches
    any single character from the list (but see below).  If the list
    begins with <literal>^</literal>, it matches any single character
    (but see below) not from the rest of the list.  If two characters
    in the list are separated by <literal>-</literal>, this is
    shorthand for the full range of characters between those two
    (inclusive) in the collating sequence,
    e.g. <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
    any decimal digit.  It is illegal for two ranges to share an
    endpoint, e.g.  <literal>a-c-e</literal>.  Ranges are very
    collating-sequence-dependent, and portable programs should avoid
    relying on them.
1235
   </para>
1236

1237
   <para>
1238 1239 1240 1241 1242 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252 1253 1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266 1267 1268 1269 1270 1271 1272 1273 1274 1275 1276 1277 1278 1279 1280 1281 1282 1283 1284 1285 1286 1287 1288 1289 1290 1291 1292 1293 1294 1295 1296 1297 1298 1299 1300 1301 1302 1303 1304 1305 1306 1307 1308 1309 1310 1311 1312 1313 1314 1315 1316 1317 1318 1319 1320 1321 1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332 1333 1334 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 1348 1349 1350 1351 1352 1353 1354 1355 1356 1357 1358 1359
    To include a literal <literal>]</literal> in the list, make it the
    first character (following a possible <literal>^</literal>).  To
    include a literal <literal>-</literal>, make it the first or last
    character, or the second endpoint of a range.  To use a literal
    <literal>-</literal> as the first endpoint of a range, enclose it
    in <literal>[.</literal> and <literal>.]</literal> to make it a
    collating element (see below).  With the exception of these and
    some combinations using <literal>[</literal> (see next
    paragraphs), all other special characters, including
    <literal>\</literal>, lose their special significance within a
    bracket expression.
   </para>

   <para>
    Within a bracket expression, a collating element (a character, a
    multi-character sequence that collates as if it were a single
    character, or a collating-sequence name for either) enclosed in
    <literal>[.</literal> and <literal>.]</literal> stands for the
    sequence of characters of that collating element.  The sequence is
    a single element of the bracket expression's list.  A bracket
    expression containing a multi-character collating element can thus
    match more than one character, e.g. if the collating sequence
    includes a <literal>ch</literal> collating element, then the RE
    <literal>[[.ch.]]*c</literal> matches the first five characters of
    <literal>chchcc</literal>.
   </para>

   <para>
    Within a bracket expression, a collating element enclosed in
    <literal>[=</literal> and <literal>=]</literal> is an equivalence
    class, standing for the sequences of characters of all collating
    elements equivalent to that one, including itself.  (If there are
    no other equivalent collating elements, the treatment is as if the
    enclosing delimiters were <literal>[.</literal> and
    <literal>.]</literal>.)  For example, if <literal>o</literal> and
    <literal>^</literal> are the members of an equivalence class, then
    <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
    <literal>[o^]</literal> are all synonymous.  An equivalence class
    may not be an endpoint of a range.
   </para>

   <para>
    Within a bracket expression, the name of a character class
    enclosed in <literal>[:</literal> and <literal>:]</literal> stands
    for the list of all characters belonging to that class.  Standard
    character class names are: <literal>alnum</literal>,
    <literal>alpha</literal>, <literal>blank</literal>,
    <literal>cntrl</literal>, <literal>digit</literal>,
    <literal>graph</literal>, <literal>lower</literal>,
    <literal>print</literal>, <literal>punct</literal>,
    <literal>space</literal>, <literal>upper</literal>,
    <literal>xdigit</literal>.  These stand for the character classes
    defined in
    <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
    A locale may provide others.  A character class may not be used as
    an endpoint of a range.
   </para>

   <para>
    There are two special cases of bracket expressions:  the bracket
    expressions <literal>[[:<:]]</literal> and
    <literal>[[:>:]]</literal> match the null string at the beginning
    and end of a word respectively.  A word is defined as a sequence
    of word characters which is neither preceded nor followed by word
    characters.  A word character is an alnum character (as defined by
    <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
    or an underscore.  This is an extension, compatible with but not
    specified by POSIX 1003.2, and should be used with caution in
    software intended to be portable to other systems.
   </para>

   <para>
    In the event that an RE could match more than one substring of a
    given string, the RE matches the one starting earliest in the
    string.  If the RE could match more than one substring starting at
    that point, it matches the longest.  Subexpressions also match the
    longest possible substrings, subject to the constraint that the
    whole match be as long as possible, with subexpressions starting
    earlier in the RE taking priority over ones starting later.  Note
    that higher-level subexpressions thus take priority over their
    lower-level component subexpressions.
   </para>

   <para>
    Match lengths are measured in characters, not collating
    elements.  A null string is considered longer than no match at
    all.  For example, <literal>bb*</literal> matches the three middle
    characters of <literal>abbbc</literal>,
    <literal>(wee|week)(knights|nights)</literal> matches all ten
    characters of <literal>weeknights</literal>, when
    <literal>(.*).*</literal> is matched against
    <literal>abc</literal> the parenthesized subexpression matches all
    three characters, and when <literal>(a*)*</literal> is matched
    against <literal>bc</literal> both the whole RE and the
    parenthesized subexpression match the null string.
   </para>

   <para>
    If case-independent matching is specified, the effect is much as
    if all case distinctions had vanished from the alphabet.  When an
    alphabetic that exists in multiple cases appears as an ordinary
    character outside a bracket expression, it is effectively
    transformed into a bracket expression containing both cases,
    e.g. <literal>x</literal> becomes <literal>[xX]</literal>.  When
    it appears inside a bracket expression, all case counterparts of
    it are added to the bracket expression, so that (e.g.)
    <literal>[x]</literal> becomes <literal>[xX]</literal> and
    <literal>[^x]</literal> becomes <literal>[^xX]</literal>.
   </para>

   <para>
    There is no particular limit on the length of REs, except insofar
    as memory is limited.  Memory usage is approximately linear in RE
    size, and largely insensitive to RE complexity, except for bounded
    repetitions.  Bounded repetitions are implemented by macro
    expansion, which is costly in time and space if counts are large
    or bounded repetitions are nested.  An RE like, say,
    <literal>((((a{1,100}){1,100}){1,100}){1,100}){1,100}</literal>
    will (eventually) run almost any existing machine out of swap
    space.<footnote><para>This was written in 1994, mind you.  The
    numbers have probably changed, but the problem
    persists.</para></footnote>
1360
   </para>
1361 1362
<!-- end re_format.7 man page -->
  </sect2>
1363

1364 1365 1366 1367
 </sect1>


  <sect1 id="functions-formatting">
1368
   <title>Formatting Functions</title>
1369 1370 1371 1372

   <note>
    <title>Author</title>
    <para>
1373
     Written by Karel Zak (<email>zakkr@zf.jcu.cz</email>) on 2000-01-24
1374 1375
    </para>
   </note>
1376

1377
   <para>
1378 1379 1380 1381 1382 1383 1384
    The <productname>Postgres</productname> formatting functions
    provide a powerful set of tools for converting various data types
    (date/time, integer, floating point, numeric) to formatted strings
    and for converting from formatted strings to specific datetypes.
    These functions all follow a common calling convention:  The first
    argument is the value to be formatted and the second argument is a
    template that defines the output format.
1385 1386 1387 1388 1389 1390 1391 1392 1393 1394 1395 1396 1397 1398 1399 1400
   </para>

   <para>
    <table tocentry="1">
     <title>Formatting Functions</title>
     <tgroup cols="4">
      <thead>
       <row>
	<entry>Function</entry>
	<entry>Returns</entry>
	<entry>Description</entry>
	<entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
1401 1402 1403 1404
	<entry>to_char(timestamp, text)</entry>
	<entry>text</entry>
	<entry>convert timestamp to string</entry>
	<entry>to_char(timestamp 'now','HH12:MI:SS')</entry>
1405 1406
       </row>
       <row>
1407 1408 1409 1410
	<entry>to_char(int, text)</entry>
	<entry>text</entry>
	<entry>convert int4/int8 to string</entry>
	<entry>to_char(125, '999')</entry>
1411 1412
       </row>
       <row>
1413
	<entry>to_char(double precision, text)</entry>
1414
	<entry>text</entry>
1415
	<entry>convert real/double precision to string</entry>
1416
	<entry>to_char(125.8, '999D9')</entry>
1417 1418
       </row>
       <row>
1419 1420 1421 1422
	<entry>to_char(numeric, text)</entry>
	<entry>text</entry>
	<entry>convert numeric to string</entry>
	<entry>to_char(numeric '-125.8', '999D99S')</entry>
1423 1424
       </row>
       <row>
1425 1426 1427 1428
	<entry>to_date(text, text)</entry>
	<entry>date</entry>
	<entry>convert string to date</entry>
	<entry>to_date('05 Dec 2000', 'DD Mon YYYY')</entry>
1429 1430
       </row>
       <row>
1431 1432 1433 1434
	<entry>to_timestamp(text, text)</entry>
	<entry>date</entry>
	<entry>convert string to timestamp</entry>
	<entry>to_timestamp('05 Dec 2000', 'DD Mon YYYY')</entry>
1435 1436
       </row>
       <row>
1437 1438 1439 1440
	<entry>to_number(text, text)</entry>
	<entry>numeric</entry>
	<entry>convert string to numeric</entry>
	<entry>to_number('12,454.8-', '99G999D9S')</entry>
1441 1442 1443 1444 1445 1446 1447 1448
       </row>
      </tbody>
     </tgroup>
    </table>
   </para>

   <para>
    <table tocentry="1">
1449
     <title>Templates for date/time conversions</title>
1450 1451 1452
     <tgroup cols="2">
      <thead>
       <row>
1453
	<entry>Template</entry>
1454 1455 1456 1457 1458
	<entry>Description</entry>
       </row>
      </thead>
      <tbody>
       <row>
1459 1460
	<entry>HH</entry>
	<entry>hour of day (01-12)</entry>
1461 1462
       </row>
       <row>
1463 1464
	<entry>HH12</entry>
	<entry>hour of day (01-12)</entry>
1465
       </row>       
1466 1467 1468 1469
       <row>
	<entry>HH24</entry>
	<entry>hour of day (00-23)</entry>
       </row>       
1470
       <row>
1471 1472
	<entry>MI</entry>
	<entry>minute (00-59)</entry>
1473 1474
       </row>   
       <row>
1475 1476
	<entry>SS</entry>
	<entry>second (00-59)</entry>
1477 1478
       </row>
       <row>
1479 1480
	<entry>SSSS</entry>
	<entry>seconds past midnight (0-86399)</entry>
1481
       </row>
1482 1483 1484 1485 1486 1487 1488 1489
       <row>
	<entry>AM or A.M. or PM or P.M.</entry>
	<entry>meridian indicator (upper case)</entry>
       </row>
       <row>
	<entry>am or a.m. or pm or p.m.</entry>
	<entry>meridian indicator (lower case)</entry>
       </row>
1490
       <row>
1491 1492
	<entry>Y,YYY</entry>
	<entry>year (4 and more digits) with comma</entry>
1493 1494
       </row>
       <row>
1495 1496
	<entry>YYYY</entry>
	<entry>year (4 and more digits)</entry>
1497 1498
       </row>
       <row>
1499 1500
	<entry>YYY</entry>
	<entry>last 3 digits of year</entry>
1501 1502
       </row>
       <row>
1503 1504
	<entry>YY</entry>
	<entry>last 2 digits of year</entry>
1505 1506
       </row>
       <row>
1507 1508
	<entry>Y</entry>
	<entry>last digit of year</entry>
1509
       </row>
1510 1511 1512 1513 1514 1515 1516 1517
       <row>
	<entry>BC or B.C. or AD or A.D.</entry>
	<entry>year indicator (upper case)</entry>
       </row>
       <row>
	<entry>bc or b.c. or ad or a.d.</entry>
	<entry>year indicator (lower case)</entry>
       </row>
1518
       <row>
1519 1520
	<entry>MONTH</entry>
	<entry>full upper case month name (9 chars)</entry>
1521 1522
       </row>
       <row>
1523 1524
	<entry>Month</entry>
	<entry>full mixed case month name (9 chars)</entry>
1525 1526
       </row>
       <row>
1527 1528
	<entry>month</entry>
	<entry>full lower case month name (9 chars)</entry>
1529 1530
       </row>
       <row>
1531 1532
	<entry>MON</entry>
	<entry>upper case abbreviated month name (3 chars)</entry>
1533 1534
       </row>
       <row>
1535 1536
	<entry>Mon</entry>
	<entry>abbreviated mixed case month name (3 chars)</entry>
1537 1538
       </row>
       <row>
1539 1540
	<entry>mon</entry>
	<entry>abbreviated lower case month name (3 chars)</entry>
1541 1542
       </row>
       <row>
1543 1544
	<entry>MM</entry>
	<entry>month (01-12)</entry>
1545 1546
       </row>
       <row>
1547 1548
	<entry>DAY</entry>
	<entry>full upper case day name (9 chars)</entry>
1549 1550
       </row>
       <row>
1551 1552
	<entry>Day</entry>
	<entry>full mixed case day name (9 chars)</entry>
1553 1554
       </row>
       <row>
1555 1556
	<entry>day</entry>
	<entry>full lower case day name (9 chars)</entry>
1557 1558
       </row>
       <row>
1559 1560
	<entry>DY</entry>
	<entry>abbreviated upper case day name (3 chars)</entry>
1561 1562
       </row>
       <row>
1563 1564
	<entry>Dy</entry>
	<entry>abbreviated mixed case day name (3 chars)</entry>
1565 1566
       </row>
       <row>
1567 1568
	<entry>dy</entry>
	<entry>abbreviated lower case day name (3 chars)</entry>
1569 1570
       </row>
       <row>
1571 1572
	<entry>DDD</entry>
	<entry>day of year (001-366)</entry>
1573 1574
       </row>
       <row>
1575 1576
	<entry>DD</entry>
	<entry>day of month (01-31)</entry>
1577 1578
       </row>
       <row>
1579 1580
	<entry>D</entry>
	<entry>day of week (1-7; SUN=1)</entry>
1581 1582
       </row>
       <row>
1583
	<entry>W</entry>
1584
	<entry>week of month (1-5) where first week start on the first day of the month</entry>
1585 1586
       </row> 
       <row>
1587
	<entry>WW</entry>
1588
	<entry>week number of year (1-53) where first week start on the first day of the year</entry>
1589
       </row>
Bruce Momjian's avatar
Bruce Momjian committed
1590 1591
       <row>
	<entry>IW</entry>
1592
	<entry>ISO week number of year (The first Thursday of the new year is in week 1.)</entry>
Bruce Momjian's avatar
Bruce Momjian committed
1593
       </row>
1594
       <row>
1595 1596
	<entry>CC</entry>
	<entry>century (2 digits)</entry>
1597 1598
       </row>
       <row>
1599 1600
	<entry>J</entry>
	<entry>Julian Day (days since January 1, 4712 BC)</entry>
1601 1602
       </row>
       <row>
1603 1604
	<entry>Q</entry>
	<entry>quarter</entry>
1605 1606
       </row>
       <row>
1607
	<entry>RM</entry>
1608
	<entry>month in Roman Numerals (I-XII; I=January) - upper case</entry>
1609 1610
       </row>
       <row>
1611
	<entry>rm</entry>
1612
	<entry>month in Roman Numerals (I-XII; I=January) - lower case</entry>
1613
       </row>
1614 1615
       <row>
	<entry>TZ</entry>
1616
	<entry>timezone string - upper case</entry>
1617 1618 1619
       </row>
       <row>
	<entry>tz</entry>
1620
	<entry>timezone string - lower case</entry>
1621
       </row>
1622 1623 1624 1625 1626 1627
      </tbody>
     </tgroup>
    </table>
   </para>

   <para>
1628
    All templates allow the use of prefix and suffix modifiers. Modifiers are
1629
    always valid for use in templates. The prefix
1630
    <quote><literal>FX</literal></quote> is a global modifier only.      
1631 1632 1633 1634
   </para>

   <para>
    <table tocentry="1">
1635
     <title>Suffixes for templates for date/time to_char()</title>
1636 1637 1638 1639 1640 1641 1642 1643 1644 1645
     <tgroup cols="3">
      <thead>
       <row>
	<entry>Suffix</entry>
	<entry>Description</entry>
	<entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
1646 1647 1648
	<entry>FM</entry>
	<entry>fill mode prefix</entry>
	<entry>FMMonth</entry>
1649 1650
       </row>
       <row>
1651 1652 1653
	<entry>TH</entry>
	<entry>upper ordinal number suffix</entry>
	<entry>DDTH</entry>
1654 1655
       </row>	
       <row>
1656 1657 1658
	<entry>th</entry>
	<entry>lower ordinal number suffix</entry>
	<entry>DDTH</entry>
1659 1660
       </row>
       <row>
1661 1662 1663
	<entry>FX</entry>
	<entry>FiXed format global option (see below)</entry>
	<entry>FX Month DD Day</entry>
1664 1665
       </row>	
       <row>
1666 1667 1668
	<entry>SP</entry>
	<entry>spell mode (not yet implemented)</entry>
	<entry>DDSP</entry>
1669 1670 1671 1672 1673 1674 1675
       </row>       
      </tbody>
     </tgroup>
    </table>
   </para>

   <para>
1676 1677 1678 1679 1680 1681
    Usage notes:

    <itemizedlist>
     <listitem>
      <para>
       <function>to_timestamp</function> and <function>to_date</function>
1682 1683 1684 1685 1686 1687
       skip multiple blank space in converted string if the <literal>FX</literal> option 
       is not used. <literal>FX</literal> must be specified as the first item
       in the template; for example 
       <literal>to_timestamp('2000    JUN','YYYY MON')</literal> is right, but
       <literal>to_timestamp('2000    JUN','FXYYYY MON')</literal> returns error,
       because to_timestamp() expects one blank space only.
1688 1689 1690 1691 1692
      </para>
     </listitem>

     <listitem>
      <para>
1693 1694 1695 1696 1697
       If a backslash (<quote><literal>\</literal></quote>) is desired
       in a string constant, a double backslash
       (<quote><literal>\\</literal></quote>) must be entered; for
       example <literal>'\\HH\\MI\\SS'</literal>.  This is true for
       any string constant in <productname>Postgres</productname>.
1698 1699 1700 1701 1702
      </para>
     </listitem>

     <listitem>
      <para>
1703 1704 1705 1706 1707
       Ordinary text is allowed in <function>to_char</function>
       templates but any string between double quotes is guaranteed
       that it will not be interpreted as a template keyword and it is
       also processed faster.  (Example: <literal>'"Hello Year:
       "YYYY'</literal>).
1708 1709 1710 1711 1712
      </para>
     </listitem>

     <listitem>
      <para>
1713 1714 1715 1716 1717
       A double quote (<quote><literal>"</literal></quote>) between
       quotation marks is skipped and is not parsed.  If you want to
       have a double quote in the output you must preceed it with a
       double backslash, for example <literal>'\\"YYYY
       Month\\"'</literal>. <!-- " font-lock sanity :-) -->
1718 1719
      </para>
     </listitem>
1720 1721 1722 1723

     <listitem>
      <para>
       <literal>YYYY</literal> conversion from string to timestamp or
1724
       date is restricted if you use a year with more than 4 digits. You must
Peter Eisentraut's avatar
Peter Eisentraut committed
1725
       use some non-digit character or template after <literal>YYYY</literal>,
1726
       otherwise the year is always interpreted as 4 digits. For example
Peter Eisentraut's avatar
Peter Eisentraut committed
1727 1728
       (with year 20000):
       <literal>to_date('200001131', 'YYYYMMDD')</literal> will be 
1729
       interpreted as a 4-digit year; better is to use a non-digit 
Peter Eisentraut's avatar
Peter Eisentraut committed
1730 1731 1732
       separator after the year, like
       <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
       <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
1733 1734
      </para>
     </listitem>
1735
    </itemizedlist>
1736
   </para>
1737

1738 1739
   <para>
    <table tocentry="1">
1740
     <title>Templates for to_char(<replaceable>numeric</replaceable>)</title>
1741 1742 1743
     <tgroup cols="2">
      <thead>
       <row>
1744
	<entry>Template</entry>
1745 1746 1747 1748 1749
	<entry>Description</entry>
       </row>
      </thead>
      <tbody>
       <row>
1750 1751
	<entry>9</entry>
	<entry>value with the specified number of digits</entry>
1752 1753
       </row>
       <row>
1754 1755
	<entry>0</entry>
	<entry>value with leading zeros</entry>
1756 1757
       </row>
       <row>
1758 1759
	<entry>. (period)</entry>
	<entry>decimal point</entry>
1760 1761
       </row>       
       <row>
1762 1763
	<entry>, (comma)</entry>
	<entry>group (thousand) separator</entry>
1764 1765
       </row>
       <row>
1766 1767
	<entry>PR</entry>
	<entry>negative value in angle brackets</entry>
1768 1769
       </row>
       <row>
1770
	<entry>S</entry>
1771
	<entry>negative value with minus sign (uses locale)</entry>
1772 1773
       </row>
       <row>
1774
	<entry>L</entry>
1775
	<entry>currency symbol (uses locale)</entry>
1776 1777
       </row>
       <row>
1778
	<entry>D</entry>
1779
	<entry>decimal point (uses locale)</entry>
1780 1781
       </row>
       <row>
1782
	<entry>G</entry>
1783
	<entry>group separator (uses locale)</entry>
1784 1785
       </row>
       <row>
1786
	<entry>MI</entry>
1787
	<entry>minus sign in specified position (if number < 0)</entry>
1788 1789
       </row>
       <row>
1790
	<entry>PL</entry>
1791
	<entry>plus sign in specified position (if number > 0)</entry>
1792 1793
       </row>
       <row>
1794
	<entry>SG</entry>
1795
	<entry>plus/minus sign in specified position</entry>
1796 1797
       </row>
       <row>
1798 1799
	<entry>RN</entry>
	<entry>roman numeral (input between 1 and 3999)</entry>
1800 1801
       </row>
       <row>
1802 1803
	<entry>TH or th</entry>
	<entry>convert to ordinal number</entry>
1804 1805
       </row>
       <row>
1806
	<entry>V</entry>
1807
	<entry>shift <replaceable>n</replaceable> digits (see
1808
	 notes)</entry>
1809 1810
       </row>
       <row>
1811
	<entry>EEEE</entry>
1812
	<entry>scientific numbers (not supported yet)</entry>
1813 1814 1815 1816 1817 1818 1819
       </row>
      </tbody>
     </tgroup>
    </table>
   </para>

   <para>
1820 1821 1822 1823 1824 1825 1826 1827 1828 1829 1830
    Usage notes:

    <itemizedlist>
     <listitem>
      <para>
       A sign formatted using 'SG', 'PL' or 'MI' is not an anchor in
       the number; for example,
       to_char(-12, 'S9999') produces <literal>'  -12'</literal>,
       but to_char(-12, 'MI9999') produces <literal>'-  12'</literal>.
       The Oracle implementation does not allow the use of
       <literal>MI</literal> ahead of <literal>9</literal>, but rather
1831
       requires that <literal>9</literal> preceed
1832 1833 1834 1835 1836 1837 1838 1839 1840 1841 1842 1843 1844 1845
       <literal>MI</literal>.
      </para>
     </listitem>

     <listitem>
      <para>
       <literal>PL</literal>, <literal>SG</literal>, and
       <literal>TH</literal> are <productname>Postgres</productname>
       extensions. 
      </para>
     </listitem>

     <listitem>
      <para>
1846 1847 1848
       <literal>9</literal> specifies a value with the same number of 
       digits as there are <literal>9</literal>s. If a digit is
       not available use blank space.
1849 1850 1851 1852 1853 1854 1855 1856 1857 1858 1859 1860 1861 1862 1863 1864 1865 1866 1867
      </para>
     </listitem>

     <listitem>
      <para>
       <literal>TH</literal> does not convert values less than zero
       and does not convert decimal numbers. <literal>TH</literal> is
       a <productname>Postgres</productname> extension.
      </para>
     </listitem>

     <listitem>
      <para>
       <literal>V</literal> effectively
       multiplies the input values by
       <literal>10^<replaceable>n</replaceable></literal>, where
       <replaceable>n</replaceable> is the number of digits following
       <literal>V</literal>. 
       <function>to_char</function> does not support the use of
1868 1869
       <literal>V</literal> combined with a decimal point.
       (E.g., <literal>99.9V99</literal> is not allowed.)
1870 1871 1872
      </para>
     </listitem>
    </itemizedlist>
1873
   </para>   
1874 1875 1876

   <para>
    <table tocentry="1">
1877
     <title><function>to_char</function> Examples</title>
1878 1879 1880 1881 1882 1883 1884 1885 1886
     <tgroup cols="2">
      <thead>
       <row>
	<entry>Input</entry>
	<entry>Output</entry>
       </row>
      </thead>
      <tbody>
       <row>
1887 1888 1889
        <entry>to_char(now(),'Day, HH12:MI:SS')</entry>
        <entry><literal>'Tuesday  , 05:39:18'</literal></entry>
       </row>
1890
       <row>
1891 1892
        <entry>to_char(now(),'FMDay, HH12:MI:SS')</entry>
        <entry><literal>'Tuesday, 05:39:18'</literal></entry>
1893 1894
       </row>          
       <row>
1895 1896
        <entry>to_char(-0.1,'99.99')</entry>
        <entry><literal>' -.10'</literal></entry>
1897 1898
       </row>
       <row>
1899 1900
        <entry>to_char(-0.1,'FM9.99')</entry>
        <entry><literal>'-.1'</literal></entry>
1901 1902
       </row>
       <row>
1903 1904
        <entry>to_char(0.1,'0.9')</entry>
        <entry><literal>' 0.1'</literal></entry>
1905 1906
       </row>
       <row>
1907 1908
        <entry>to_char(12,'9990999.9')</entry>
        <entry><literal>'    0012.0'</literal></entry>
1909 1910
       </row>
       <row>
1911 1912
        <entry>to_char(12,'FM9990999.9')</entry>
        <entry><literal>'0012'</literal></entry>
1913 1914
       </row>
       <row>
1915 1916
        <entry>to_char(485,'999')</entry>
        <entry><literal>' 485'</literal></entry>
1917 1918
       </row>
       <row>
1919 1920
        <entry>to_char(-485,'999')</entry>
        <entry><literal>'-485'</literal></entry>
1921 1922
       </row>
       <row>
1923 1924
        <entry>to_char(485,'9 9 9')</entry>
        <entry><literal>' 4 8 5'</literal></entry>
1925 1926
       </row>
       <row>
1927 1928
        <entry>to_char(1485,'9,999')</entry>
        <entry><literal>' 1,485'</literal></entry>
1929 1930
       </row>
       <row>
1931 1932
        <entry>to_char(1485,'9G999')</entry>
        <entry><literal>' 1 485'</literal></entry>
1933 1934
       </row>
       <row>
1935 1936
        <entry>to_char(148.5,'999.999')</entry>
        <entry><literal>' 148.500'</literal></entry>
1937 1938
       </row>
       <row>
1939 1940
        <entry>to_char(148.5,'999D999')</entry>
        <entry><literal>' 148,500'</literal></entry>	 
1941 1942
       </row>
       <row>
1943 1944
        <entry>to_char(3148.5,'9G999D999')</entry>
        <entry><literal>' 3 148,500'</literal></entry>
1945 1946
       </row>
       <row>
1947 1948
        <entry>to_char(-485,'999S')</entry>
        <entry><literal>'485-'</literal></entry>
1949 1950
       </row>
       <row>		
1951 1952
        <entry>to_char(-485,'999MI')</entry>
        <entry><literal>'485-'</literal></entry>	
1953 1954
       </row>
       <row>
1955 1956
        <entry>to_char(485,'999MI')</entry>
        <entry><literal>'485'</literal></entry>		
1957 1958
       </row>
       <row>
1959 1960
        <entry>to_char(485,'PL999')</entry>
        <entry><literal>'+485'</literal></entry>	
1961 1962
       </row>
       <row>		
1963 1964
        <entry>to_char(485,'SG999')</entry>
        <entry><literal>'+485'</literal></entry>	
1965 1966
       </row>
       <row>
1967 1968
        <entry>to_char(-485,'SG999')</entry>
        <entry><literal>'-485'</literal></entry>	
1969 1970
       </row>
       <row>
1971 1972
        <entry>to_char(-485,'9SG99')</entry>
        <entry><literal>'4-85'</literal></entry>	
1973 1974
       </row>
       <row>
1975 1976
        <entry>to_char(-485,'999PR')</entry>
        <entry><literal>'&lt;485&gt;'</literal></entry>		
1977 1978
       </row>
       <row>
1979 1980
        <entry>to_char(485,'L999')</entry>
        <entry><literal>'DM 485</literal></entry>	 
1981 1982
       </row>
       <row>
1983 1984
        <entry>to_char(485,'RN')</entry>		
        <entry><literal>'        CDLXXXV'</literal></entry>
1985 1986
       </row>
       <row>
1987 1988
        <entry>to_char(485,'FMRN')</entry>	
        <entry><literal>'CDLXXXV'</literal></entry>
1989 1990
       </row>
       <row>
1991 1992
        <entry>to_char(5.2,'FMRN')</entry>
        <entry><literal>V</literal></entry>		
1993 1994
       </row>
       <row>
1995 1996
        <entry>to_char(482,'999th')</entry>
        <entry><literal>' 482nd'</literal></entry>				
1997 1998
       </row>
       <row>
1999 2000
        <entry>to_char(485, '"Good number:"999')</entry>
        <entry><literal>'Good number: 485'</literal></entry>
2001 2002
       </row>
       <row>
2003 2004
        <entry>to_char(485.8,'"Pre-decimal:"999" Post-decimal:" .999')</entry>
        <entry><literal>'Pre-decimal: 485 Post-decimal: .800'</literal></entry>
2005 2006
       </row>
       <row>
2007 2008
        <entry>to_char(12,'99V999')</entry>		
        <entry><literal>' 12000'</literal></entry>
2009 2010
       </row>
       <row>
2011 2012
        <entry>to_char(12.4,'99V999')</entry>
        <entry><literal>' 12400'</literal></entry>
2013 2014
       </row>
       <row>		
2015 2016
        <entry>to_char(12.45, '99V9')</entry>
        <entry><literal>' 125'</literal></entry>
2017 2018 2019 2020 2021 2022 2023 2024
       </row>
      </tbody>
     </tgroup>
    </table>
   </para>
  </sect1>


2025 2026
  <sect1 id="functions-datetime">
   <title>Date/Time Functions</title>
2027

2028
   <para>
2029 2030
    The date/time functions provide a powerful set of tools
    for manipulating various date/time types.
2031
   </para>
2032

2033 2034
   <para>
    <table tocentry="1">
2035 2036 2037 2038 2039 2040 2041 2042 2043 2044 2045 2046 2047 2048 2049 2050 2051 2052 2053 2054 2055 2056 2057 2058 2059 2060 2061 2062 2063 2064 2065
     <title>Date/Time Functions</title>
     <tgroup cols="4">
      <thead>
       <row>
	<entry>Function</entry>
	<entry>Returns</entry>
	<entry>Description</entry>
	<entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
	<entry>abstime(timestamp)</entry>
	<entry>abstime</entry>
	<entry>convert to abstime</entry>
	<entry>abstime(timestamp 'now')</entry>
       </row>
       <row>
	<entry>age(timestamp)</entry>
	<entry>interval</entry>
	<entry>preserve months and years</entry>
	<entry>age(timestamp '1957-06-13')</entry>
       </row>
       <row>
	<entry>age(timestamp,timestamp)</entry>
	<entry>interval</entry>
	<entry>preserve months and years</entry>
	<entry>age('now', timestamp '1957-06-13')</entry>
       </row>
       <row>
	<entry>date_part(text,timestamp)</entry>
2066
	<entry>double precision</entry>
2067 2068 2069 2070 2071
	<entry>portion of date</entry>
	<entry>date_part('dow',timestamp 'now')</entry>
       </row>
       <row>
	<entry>date_part(text,interval)</entry>
2072
	<entry>double precision</entry>
2073 2074 2075 2076 2077 2078 2079 2080 2081 2082 2083 2084 2085 2086 2087 2088 2089 2090 2091 2092 2093 2094 2095 2096 2097 2098 2099 2100 2101 2102 2103 2104 2105 2106 2107 2108 2109 2110 2111 2112 2113 2114 2115 2116 2117 2118 2119 2120 2121 2122 2123 2124 2125 2126 2127 2128 2129 2130 2131 2132 2133 2134 2135 2136 2137 2138 2139 2140 2141 2142 2143 2144 2145 2146 2147 2148 2149 2150 2151 2152 2153 2154 2155 2156 2157 2158 2159 2160 2161 2162 2163 2164 2165 2166 2167 2168 2169 2170 2171
	<entry>portion of time</entry>
	<entry>date_part('hour',interval '4 hrs 3 mins')</entry>
       </row>
       <row>
	<entry>date_trunc(text,timestamp)</entry>
	<entry>timestamp</entry>
	<entry>truncate date</entry>
	<entry>date_trunc('month',abstime 'now')</entry>
       </row>
       <row>
	<entry>interval(reltime)</entry>
	<entry>interval</entry>
	<entry>convert to interval</entry>
	<entry>interval(reltime '4 hours')</entry>
       </row>
       <row>
	<entry>isfinite(timestamp)</entry>
	<entry>bool</entry>
	<entry>a finite time?</entry>
	<entry>isfinite(timestamp 'now')</entry>
       </row>
       <row>
	<entry>isfinite(interval)</entry>
	<entry>bool</entry>
	<entry>a finite time?</entry>
	<entry>isfinite(interval '4 hrs')</entry>
       </row>
       <row>
	<entry>reltime(interval)</entry>
	<entry>reltime</entry>
	<entry>convert to reltime</entry>
	<entry>reltime(interval '4 hrs')</entry>
       </row>
       <row>
	<entry>timestamp(date)</entry>
	<entry>timestamp</entry>
	<entry>convert to timestamp</entry>
	<entry>timestamp(date 'today')</entry>
       </row>
       <row>
	<entry>timestamp(date,time)</entry>
	<entry>timestamp</entry>
	<entry>convert to timestamp</entry>
	<entry>timestamp(timestamp '1998-02-24',time '23:07');</entry>
       </row>
       <row>
	<entry>to_char(timestamp,text)</entry>
	<entry>text</entry>
	<entry>convert to string</entry>
	<entry>to_char(timestamp '1998-02-24','DD');</entry>
       </row>
      </tbody>
     </tgroup>
    </table>
   </para>

   <para>
    For the
    <function>date_part</function> and <function>date_trunc</function>
    functions, arguments can be
    `<literal>year</literal>', `<literal>month</literal>',
    `<literal>day</literal>', `<literal>hour</literal>',
    `<literal>minute</literal>', and `<literal>second</literal>',
    as well as the more specialized quantities
    `<literal>decade</literal>', `<literal>century</literal>',
    `<literal>millennium</literal>', `<literal>millisecond</literal>',
    and `<literal>microsecond</literal>'. 
    <function>date_part</function> allows `<literal>dow</literal>'
    to return day of week, '<literal>week</literal>' to return the
    ISO-defined week of year, and `<literal>epoch</literal>' to return
    seconds since 1970 (for <type>timestamp</type>)
    or '<literal>epoch</literal>' to return total elapsed seconds
    (for <type>interval</type>).
   </para>
  </sect1>

  
 <sect1 id="functions-geometry">
   <title>Geometric Functions and Operators</title>

   <para>
    The geometric types point, box, lseg, line, path, polygon, and
    circle have a large set of native support functions and operators.
   </para>

   <table>
     <TITLE>Geometric Operators</TITLE>
     <TGROUP COLS="3">
      <THEAD>
       <ROW>
	<ENTRY>Operator</ENTRY>
	<ENTRY>Description</ENTRY>
	<ENTRY>Usage</ENTRY>
       </ROW>
      </THEAD>
      <TBODY>
       <ROW>
	<ENTRY> + </ENTRY>
	<ENTRY>Translation</ENTRY>
2172
	<ENTRY>box '((0,0),(1,1))' + point '(2.0,0)'</ENTRY>
2173 2174 2175 2176
       </ROW>
       <ROW>
	<ENTRY> - </ENTRY>
	<ENTRY>Translation</ENTRY>
2177
	<ENTRY>box '((0,0),(1,1))' - point '(2.0,0)'</ENTRY>
2178 2179 2180 2181
       </ROW>
       <ROW>
	<ENTRY> * </ENTRY>
	<ENTRY>Scaling/rotation</ENTRY>
2182
	<ENTRY>box '((0,0),(1,1))' * point '(2.0,0)'</ENTRY>
2183 2184 2185 2186
       </ROW>
       <ROW>
	<ENTRY> / </ENTRY>
	<ENTRY>Scaling/rotation</ENTRY>
2187
	<ENTRY>box '((0,0),(2,2))' / point '(2.0,0)'</ENTRY>
2188 2189 2190 2191 2192 2193 2194 2195 2196 2197 2198 2199 2200 2201
       </ROW>
       <ROW>
	<ENTRY> # </ENTRY>
	<ENTRY>Intersection</ENTRY>
	<ENTRY>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> # </ENTRY>
	<ENTRY>Number of points in polygon</ENTRY>
	<ENTRY># '((1,0),(0,1),(-1,0))'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> ## </ENTRY>
	<ENTRY>Point of closest proximity</ENTRY>
2202
	<ENTRY>point '(0,0)' ## lseg '((2,0),(0,2))'</ENTRY>
2203 2204 2205 2206
       </ROW>
       <ROW>
	<ENTRY> &amp;&amp; </ENTRY>
	<ENTRY>Overlaps?</ENTRY>
2207
	<ENTRY>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</ENTRY>
2208 2209 2210 2211
       </ROW>
       <ROW>
	<ENTRY> &amp;&lt; </ENTRY>
	<ENTRY>Overlaps to left?</ENTRY>
2212
	<ENTRY>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</ENTRY>
2213 2214 2215 2216
       </ROW>
       <ROW>
	<ENTRY> &amp;&gt; </ENTRY>
	<ENTRY>Overlaps to right?</ENTRY>
2217
	<ENTRY>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</ENTRY>
2218 2219 2220 2221
       </ROW>
       <ROW>
	<ENTRY> &lt;-&gt; </ENTRY>
	<ENTRY>Distance between</ENTRY>
2222
	<ENTRY>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</ENTRY>
2223 2224 2225 2226
       </ROW>
       <ROW>
	<ENTRY> &lt;&lt; </ENTRY>
	<ENTRY>Left of?</ENTRY>
2227
	<ENTRY>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</ENTRY>
2228 2229 2230 2231
       </ROW>
       <ROW>
	<ENTRY> &lt;^ </ENTRY>
	<ENTRY>Is below?</ENTRY>
2232
	<ENTRY>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</ENTRY>
2233 2234 2235 2236
       </ROW>
       <ROW>
	<ENTRY> &gt;&gt; </ENTRY>
	<ENTRY>Is right of?</ENTRY>
2237
	<ENTRY>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</ENTRY>
2238 2239 2240 2241
       </ROW>
       <ROW>
	<ENTRY> &gt;^ </ENTRY>
	<ENTRY>Is above?</ENTRY>
2242
	<ENTRY>circle '((0,5),1)' >^ circle '((0,0),1)'</ENTRY>
2243 2244 2245 2246
       </ROW>
       <ROW>
	<ENTRY> ?# </ENTRY>
	<ENTRY>Intersects or overlaps</ENTRY>
2247
	<ENTRY>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))';</ENTRY>
2248 2249 2250 2251
       </ROW>
       <ROW>
	<ENTRY> ?- </ENTRY>
	<ENTRY>Is horizontal?</ENTRY>
2252
	<ENTRY>point '(1,0)' ?- point '(0,0)'</ENTRY>
2253 2254 2255 2256
       </ROW>
       <ROW>
	<ENTRY> ?-| </ENTRY>
	<ENTRY>Is perpendicular?</ENTRY>
2257
	<ENTRY>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</ENTRY>
2258 2259 2260 2261
       </ROW>
       <ROW>
	<ENTRY> @-@  </ENTRY>
	<ENTRY>Length or circumference</ENTRY>
2262
	<ENTRY>@-@ path '((0,0),(1,0))'</ENTRY>
2263 2264 2265 2266
       </ROW>
       <ROW>
	<ENTRY> ?| </ENTRY>
	<ENTRY>Is vertical?</ENTRY>
2267
	<ENTRY>point '(0,1)' ?| point '(0,0)'</ENTRY>
2268 2269 2270 2271
       </ROW>
       <ROW>
	<ENTRY> ?|| </ENTRY>
	<ENTRY>Is parallel?</ENTRY>
2272
	<ENTRY>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</ENTRY>
2273 2274 2275 2276
       </ROW>
       <ROW>
	<ENTRY> @ </ENTRY>
	<ENTRY>Contained or on</ENTRY>
2277
	<ENTRY>point '(1,1)' @ circle '((0,0),2)'</ENTRY>
2278 2279 2280 2281
       </ROW>
       <ROW>
	<ENTRY> @@ </ENTRY>
	<ENTRY>Center of</ENTRY>
2282
	<ENTRY>@@ circle '((0,0),10)'</ENTRY>
2283 2284 2285 2286
       </ROW>
       <ROW>
	<ENTRY> ~= </ENTRY>
	<ENTRY>Same as</ENTRY>
2287
	<ENTRY>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</ENTRY>
2288 2289 2290 2291 2292 2293
       </ROW>
      </TBODY>
     </TGROUP>
   </TABLE>

   <table>
2294 2295 2296 2297 2298 2299 2300 2301 2302 2303 2304 2305
     <title>Geometric Functions</title>
     <tgroup cols="4">
      <thead>
       <row>
	<entry>Function</entry>
	<entry>Returns</entry>
	<entry>Description</entry>
	<entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
2306
	<entry>area(object)</entry>
2307
	<entry>double precision</entry>
2308
	<entry>area of item</entry>
2309
	<entry>area(box '((0,0),(1,1))')</entry>
2310 2311
       </row>
       <row>
2312
	<entry>box(box, box)</entry>
2313
	<entry>box</entry>
2314
	<entry>intersection box</entry>
2315
	<entry>box(box '((0,0),(1,1))',box '((0.5,0.5),(2,2))')</entry>
2316 2317
       </row>
       <row>
2318 2319
	<entry>center(object)</entry>
	<entry>point</entry>
2320
	<entry>center of item</entry>
2321
	<entry>center(box '((0,0),(1,2))')</entry>
2322 2323
       </row>
       <row>
2324
	<entry>diameter(circle)</entry>
2325
	<entry>double precision</entry>
2326 2327
	<entry>diameter of circle</entry>
	<entry>diameter(circle '((0,0),2.0)')</entry>
2328 2329
       </row>
       <row>
2330
	<entry>height(box)</entry>
2331
	<entry>double precision</entry>
2332 2333
	<entry>vertical size of box</entry>
	<entry>height(box '((0,0),(1,1))')</entry>
2334 2335
       </row>
       <row>
2336 2337 2338 2339
	<entry>isclosed(path)</entry>
	<entry>bool</entry>
	<entry>a closed path?</entry>
	<entry>isclosed(path '((0,0),(1,1),(2,0))')</entry>
2340 2341
       </row>
       <row>
2342 2343 2344 2345
	<entry>isopen(path)</entry>
	<entry>bool</entry>
	<entry>an open path?</entry>
	<entry>isopen(path '[(0,0),(1,1),(2,0)]')</entry>
2346 2347
       </row>
       <row>
2348
	<entry>length(object)</entry>
2349
	<entry>double precision</entry>
2350
	<entry>length of item</entry>
2351
	<entry>length(path '((-1,0),(1,0))')</entry>
2352 2353
       </row>
       <row>
2354 2355 2356 2357
	<entry>pclose(path)</entry>
	<entry>path</entry>
	<entry>convert path to closed</entry>
	<entry>popen(path '[(0,0),(1,1),(2,0)]')</entry>
2358
       </row>
2359 2360
<!--
Not defined by this name. Implements the intersection operator '#'
2361
       <row>
2362 2363 2364 2365
	<entry>point(lseg,lseg)</entry>
	<entry>point</entry>
	<entry>intersection</entry>
	<entry>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</entry>
2366
       </row>
2367
-->
2368
       <row>
2369 2370 2371 2372
	<entry>npoint(path)</entry>
	<entry>int4</entry>
	<entry>number of points</entry>
	<entry>npoints(path '[(0,0),(1,1),(2,0)]')</entry>
2373 2374
       </row>
       <row>
2375 2376 2377 2378
	<entry>popen(path)</entry>
	<entry>path</entry>
	<entry>convert path to open path</entry>
	<entry>popen(path '((0,0),(1,1),(2,0))')</entry>
2379 2380
       </row>
       <row>
2381
	<entry>radius(circle)</entry>
2382
	<entry>double precision</entry>
2383 2384
	<entry>radius of circle</entry>
	<entry>radius(circle '((0,0),2.0)')</entry>
2385 2386
       </row>
       <row>
2387
	<entry>width(box)</entry>
2388
	<entry>double precision</entry>
2389 2390
	<entry>horizontal size</entry>
	<entry>width(box '((0,0),(1,1))')</entry>
2391 2392 2393
       </row>
      </tbody>
     </tgroup>
2394
   </table>
2395

2396 2397

   <table>
2398 2399 2400 2401 2402 2403 2404 2405 2406 2407 2408 2409
     <title>Geometric Type Conversion Functions</title>
     <tgroup cols="4">
      <thead>
       <row>
	<entry>Function</entry>
	<entry>Returns</entry>
	<entry>Description</entry>
	<entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
2410 2411
	<entry>box(circle)</entry>
	<entry>box</entry>
2412
	<entry>circle to box</entry>
2413
	<entry>box(circle '((0,0),2.0)')</entry>
2414 2415
       </row>
       <row>
2416
	<entry>box(point, point)</entry>
2417
	<entry>box</entry>
2418
	<entry>points to box</entry>
2419
	<entry>box(point '(0,0)', point '(1,1)')</entry>
2420 2421
       </row>
       <row>
2422 2423
	<entry>box(polygon)</entry>
	<entry>box</entry>
2424
	<entry>polygon to box</entry>
2425
	<entry>box(polygon '((0,0),(1,1),(2,0))')</entry>
2426 2427
       </row>
       <row>
2428 2429
	<entry>circle(box)</entry>
	<entry>circle</entry>
2430
	<entry>to circle</entry>
2431
	<entry>circle(box '((0,0),(1,1))')</entry>
2432 2433
       </row>
       <row>
2434
	<entry>circle(point, double precision)</entry>
2435
	<entry>circle</entry>
2436
	<entry>point to circle</entry>
2437
	<entry>circle(point '(0,0)', 2.0)</entry>
2438 2439
       </row>
       <row>
2440 2441
	<entry>lseg(box)</entry>
	<entry>lseg</entry>
2442
	<entry>box diagonal to lseg</entry>
2443
	<entry>lseg(box '((-1,0),(1,0))')</entry>
2444 2445
       </row>
       <row>
2446
	<entry>lseg(point, point)</entry>
2447
	<entry>lseg</entry>
2448
	<entry>points to lseg</entry>
2449
	<entry>lseg(point '(-1,0)', point '(1,0)')</entry>
2450 2451
       </row>
       <row>
2452 2453
	<entry>path(polygon)</entry>
	<entry>point</entry>
2454
	<entry>polygon to path</entry>
2455
	<entry>path(polygon '((0,0),(1,1),(2,0))')</entry>
2456 2457
       </row>
       <row>
2458 2459
	<entry>point(circle)</entry>
	<entry>point</entry>
2460
	<entry>center</entry>
2461
	<entry>point(circle '((0,0),2.0)')</entry>
2462 2463
       </row>
       <row>
2464
	<entry>point(lseg, lseg)</entry>
2465
	<entry>point</entry>
2466
	<entry>intersection</entry>
2467
	<entry>point(lseg '((-1,0),(1,0))', lseg '((-2,-2),(2,2))')</entry>
2468 2469
       </row>
       <row>
2470 2471
	<entry>point(polygon)</entry>
	<entry>point</entry>
2472
	<entry>center</entry>
2473
	<entry>point(polygon '((0,0),(1,1),(2,0))')</entry>
2474 2475
       </row>
       <row>
2476 2477
	<entry>polygon(box)</entry>
	<entry>polygon</entry>
2478
	<entry>12 point polygon</entry>
2479
	<entry>polygon(box '((0,0),(1,1))')</entry>
2480 2481
       </row>
       <row>
2482 2483
	<entry>polygon(circle)</entry>
	<entry>polygon</entry>
2484
	<entry>12-point polygon</entry>
2485
	<entry>polygon(circle '((0,0),2.0)')</entry>
2486 2487
       </row>
       <row>
2488
	<entry>polygon(<replaceable class="parameter">npts</replaceable>, circle)</entry>
2489
	<entry>polygon</entry>
2490
	<entry><replaceable class="parameter">npts</replaceable> polygon</entry>
2491
	<entry>polygon(12, circle '((0,0),2.0)')</entry>
2492 2493
       </row>
       <row>
2494 2495
	<entry>polygon(path)</entry>
	<entry>polygon</entry>
2496
	<entry>path to polygon</entry>
2497
	<entry>polygon(path '((0,0),(1,1),(2,0))')</entry>
2498 2499 2500
       </row>
      </tbody>
     </tgroup>
2501 2502
   </table>

2503
  </sect1>
2504

2505 2506

  <sect1 id="functions-net">
2507
   <title>Network Address Type Functions</title>
2508

2509 2510 2511 2512 2513 2514 2515 2516 2517 2518 2519 2520 2521 2522 2523 2524 2525 2526 2527 2528 2529 2530 2531 2532 2533 2534 2535 2536 2537 2538 2539 2540 2541 2542 2543 2544 2545 2546 2547 2548 2549 2550 2551 2552 2553 2554 2555 2556 2557 2558 2559 2560 2561 2562 2563 2564 2565 2566 2567 2568 2569 2570 2571 2572 2573 2574 2575 2576 2577 2578 2579 2580 2581 2582 2583 2584 2585

    <table tocentry="1" id="cidr-inet-operators-table">
     <title><type>cidr</> and <type>inet</> Operators</title>
     <TGROUP COLS="3">
      <THEAD>
       <ROW>
	<ENTRY>Operator</ENTRY>
	<ENTRY>Description</ENTRY>
	<ENTRY>Usage</ENTRY>
       </ROW>
      </THEAD>
      <TBODY>
       <ROW>
	<ENTRY> &lt; </ENTRY>
	<ENTRY>Less than</ENTRY>
	<ENTRY>inet '192.168.1.5' &lt; inet '192.168.1.6'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> &lt;= </ENTRY>
	<ENTRY>Less than or equal</ENTRY>
	<ENTRY>inet '192.168.1.5' &lt;= inet '192.168.1.5'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> = </ENTRY>
	<ENTRY>Equals</ENTRY>
	<ENTRY>inet '192.168.1.5' = inet '192.168.1.5'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> &gt;= </ENTRY>
	<ENTRY>Greater or equal</ENTRY>
	<ENTRY>inet '192.168.1.5' &gt;= inet '192.168.1.5'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> &gt; </ENTRY>
	<ENTRY>Greater</ENTRY>
	<ENTRY>inet '192.168.1.5' &gt; inet '192.168.1.4'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> &lt;&gt; </ENTRY>
	<ENTRY>Not equal</ENTRY>
	<ENTRY>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> &lt;&lt; </ENTRY>
	<ENTRY>is contained within</ENTRY>
	<ENTRY>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> &lt;&lt;= </ENTRY>
	<ENTRY>is contained within or equals</ENTRY>
	<ENTRY>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> &gt;&gt; </ENTRY>
	<ENTRY>contains</ENTRY>
	<ENTRY>inet'192.168.1/24' &gt;&gt; inet '192.168.1.5'</ENTRY>
       </ROW>
       <ROW>
	<ENTRY> &gt;&gt;= </ENTRY>
	<ENTRY>contains or equals</ENTRY>
	<ENTRY>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</ENTRY>
       </ROW>
      </TBODY>
     </TGROUP>
    </TABLE>

    <para>
     All of the operators for <type>inet</type> can be applied to
     <type>cidr</type> values as well.  The operators
     <literal>&lt;&lt;</>, <literal>&lt;&lt;=</>,
     <literal>&gt;&gt;</>, <literal>&gt;&gt;=</>
     test for subnet inclusion: they consider only the network parts
     of the two addresses, ignoring any host part, and determine whether
     one network part is identical to or a subnet of the other.
    </para>


2586 2587
    <table tocentry="1" id="cidr-inet-functions">
     <title><type>cidr</> and <type>inet</> Functions</title>
2588
     <tgroup cols="5">
2589 2590 2591 2592 2593 2594
      <thead>
       <row>
	<entry>Function</entry>
	<entry>Returns</entry>
	<entry>Description</entry>
	<entry>Example</entry>
2595
	<entry>Result</entry>
2596 2597 2598 2599
       </row>
      </thead>
      <tbody>
       <row>
2600
	<entry>broadcast(inet)</entry>
2601 2602
	<entry>inet</entry>
	<entry>broadcast address for network</entry>
2603
	<entry>broadcast('192.168.1.5/24')</entry>
2604
	<entry>192.168.1.255/24</entry>
2605 2606
       </row>
       <row>
2607 2608
	<entry>host(inet)</entry>
	<entry>text</entry>
2609
	<entry>extract IP address as text</entry>
2610
	<entry>host('192.168.1.5/24')</entry>
2611
	<entry>192.168.1.5</entry>
2612 2613
       </row>
       <row>
2614
	<entry>masklen(inet)</entry>
2615
	<entry>integer</entry>
2616
	<entry>extract netmask length</entry>
2617
	<entry>masklen('192.168.1.5/24')</entry>
2618
	<entry>24</entry>
2619 2620
       </row>
       <row>
2621
	<entry>netmask(inet)</entry>
2622 2623
	<entry>inet</entry>
	<entry>construct netmask for network</entry>
2624
	<entry>netmask('192.168.1.5/24')</entry>
2625 2626 2627 2628 2629 2630 2631
	<entry>255.255.255.0</entry>
       </row>
       <row>
	<entry>network(inet)</entry>
	<entry>cidr</entry>
	<entry>extract network part of address</entry>
	<entry>network('192.168.1.5/24')</entry>
2632
	<entry>192.168.1.0/24</entry>
2633 2634 2635 2636 2637 2638 2639 2640
       </row>
       <row>
	<entry>text(inet)</entry>
	<entry>text</entry>
	<entry>extract IP address and masklen as text</entry>
	<entry>text(inet '192.168.1.5')</entry>
	<entry>192.168.1.5/32</entry>
       </row>
2641 2642 2643 2644 2645 2646 2647
       <row>
	<entry>abbrev(inet)</entry>
	<entry>text</entry>
	<entry>extract abbreviated display as text</entry>
	<entry>abbrev(cidr '10.1.0.0/16')</entry>
	<entry>10.1/16</entry>
       </row>
2648 2649 2650 2651 2652 2653
      </tbody>
     </tgroup>
    </table>

   <para>
    All of the functions for <type>inet</type> can be applied to
2654 2655 2656
    <type>cidr</type> values as well.  The <function>host</>(),
    <function>text</>(), and <function>abbrev</>() functions are primarily
    intended to offer alternative display formats.
2657 2658 2659 2660 2661 2662 2663 2664 2665 2666 2667 2668 2669
   </para>

   <para>
    <table tocentry="1" id="macaddr-functions">
     <title><type>macaddr</> Functions</title>
     <tgroup cols="5">
      <thead>
       <row>
	<entry>Function</entry>
	<entry>Returns</entry>
	<entry>Description</entry>
	<entry>Example</entry>
	<entry>Result</entry>
2670
       </row>
2671 2672
      </thead>
      <tbody>
2673 2674 2675 2676 2677
       <row>
	<entry>trunc(macaddr)</entry>
	<entry>macaddr</entry>
	<entry>set last 3 bytes to zero</entry>
	<entry>trunc(macaddr '12:34:56:78:90:ab')</entry>
2678
	<entry>12:34:56:00:00:00</entry>
2679
       </row>
2680 2681 2682
      </tbody>
     </tgroup>
    </table>
2683
   </para>
2684

2685
   <para>
2686 2687 2688 2689 2690
    The function <function>trunc</>(<type>macaddr</>) returns a MAC
    address with the last 3 bytes set to 0.  This can be used to
    associate the remaining prefix with a manufacturer.  The directory
    <filename>contrib/mac</> in the source distribution contains some
    utilities to create and maintain such an association table.
2691
   </para>
2692

2693 2694 2695 2696 2697 2698
   <para>
    The <type>macaddr</> type also supports the standard relational
    operators (<literal>&gt;</>, <literal>&lt;=</>, etc.) for
    lexicographical ordering.
   </para>

2699
  </sect1>
2700

2701 2702 2703 2704 2705 2706 2707 2708 2709 2710 2711 2712 2713 2714 2715 2716 2717 2718 2719 2720 2721 2722 2723 2724 2725 2726 2727 2728 2729 2730 2731 2732 2733 2734 2735 2736 2737 2738 2739 2740 2741 2742 2743 2744 2745 2746 2747 2748 2749 2750 2751 2752 2753 2754 2755 2756 2757 2758 2759 2760 2761 2762 2763 2764 2765 2766 2767 2768

 <sect1 id="functions-conditional">
  <title>Conditional Expressions</title>

  <para>
   This section descibes the SQL-compliant conditional expressions
   available in <productname>Postgres</productname>.
  </para>

  <tip>
   <para>
    If your needs go beyond the capabilities of these conditional
    expressions you might want to consider writing a stored procedure
    in a more expressive programming language.
   </para>
  </tip>

  <bridgehead renderas="sect2">CASE</bridgehead>

<synopsis>
CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
     <optional>WHEN ...</optional>
     <optional>ELSE <replaceable>result</replaceable></optional>
END
</synopsis>

  <para>
   The <acronym>SQL</acronym> <token>CASE</token> expression is a
   generic conditional expression, similar to if/else statements in
   other languages.  <token>CASE</token> clauses can be used whereever
   an expression is valid.  <replaceable>condition</replaceable> is an
   expression that returns a boolean result.  If the result is true
   then the value of the <token>CASE</token> expression is
   <replaceable>result</replaceable>.  If the result is false any
   subsequent <token>WHEN</token> clauses are searched in the same
   manner.  If no <token>WHEN</token>
   <replaceable>condition</replaceable> is true then the value of the
   case expression is the <replaceable>result</replaceable> in the
   <token>ELSE</token> clause.  If the <token>ELSE</token> clause is
   omitted and no condition matches, the result is NULL.
  </para>

  <informalexample>
   <para>
    An example:
<screen>
<prompt>=&gt;</prompt> <userinput>SELECT * FROM test;</userinput>
<computeroutput>
 a
---
 1
 2
 3
</computeroutput>

<prompt>=&gt;</prompt> <userinput>SELECT a, CASE WHEN a=1 THEN 'one' WHEN a=2 THEN 'two' ELSE 'other' END FROM test;</userinput>
<computeroutput>
 a | case
---+-------
 1 | one
 2 | two
 3 | other
</computeroutput>
</screen>
   </para>
  </informalexample>

  <para>
2769 2770 2771
   The data types of all the <replaceable>result</replaceable>
   expressions must be coercible to a single output type.
   See <xref linkend="typeconv-union-case"> for more detail.
2772 2773 2774 2775 2776 2777 2778 2779 2780 2781 2782 2783 2784 2785 2786 2787 2788 2789 2790 2791 2792 2793 2794 2795 2796 2797 2798 2799 2800 2801 2802 2803 2804 2805 2806 2807 2808 2809 2810 2811 2812 2813 2814 2815 2816 2817 2818 2819 2820 2821 2822 2823 2824 2825 2826 2827 2828 2829 2830 2831 2832 2833 2834 2835 2836 2837 2838 2839 2840 2841 2842
  </para>

<synopsis>
CASE <replaceable>expression</replaceable>
    WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
    <optional>WHEN ...</optional>
    <optional>ELSE <replaceable>result</replaceable></optional>
END
</synopsis>

  <para>
   This <quote>simple</quote> <token>CASE</token> expression is a
   specialized variant of the general form above.  The
   <replaceable>expression</replaceable> is computed and compared to
   all the <replaceable>value</replaceable>s in the
   <token>WHEN</token> clauses until one is found that is equal.  If
   no match is found, the <replaceable>result</replaceable> in the
   <token>ELSE</token> clause (or NULL) is returned.  This is similar
   to the <function>switch</function> statement in C.
  </para>

  <informalexample>
   <para>
    The example above can be written using the simple
    <token>CASE</token> syntax:
<screen>
<prompt>=&gt;</prompt> <userinput>SELECT a, CASE a WHEN 1 THEN 'one' WHEN 2 THEN 'two' ELSE 'other' END FROM test;</userinput>
<computeroutput>
 a | case
---+-------
 1 | one
 2 | two
 3 | other
</computeroutput>
</screen>
    </para>
   </informalexample>

   <bridgehead renderas="sect2">COALESCE</bridgehead>

<synopsis>
<function>COALESCE</function>(<replaceable>value</replaceable><optional>, ...</optional>)
</synopsis>

  <para>
   The <function>COALESCE</function> function returns the first of its
   arguments that is not NULL.  This is often useful to substitute a
   default value for NULL values when data is retrieved for display,
   for example:
<programlisting>
SELECT COALESCE(description, short_description, '(none)') ...
</programlisting>
  </para>

 <bridgehead renderas="sect2">NULLIF</bridgehead>

<synopsis>
<function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
</synopsis>

  <para>
   The <function>NULLIF</function> function returns NULL if and only
   if <replaceable>value1</replaceable> and
   <replaceable>value2</replaceable> are equal.  Otherwise it returns
   <replaceable>value1</replaceable>.  This can be used to perform the
   inverse operation of the <function>COALESCE</function> example
   given above:
<programlisting>
SELECT NULLIF(value, '(none)') ...
</programlisting>
  </para>
2843 2844 2845 2846 2847 2848 2849 2850 2851 2852 2853 2854 2855

  <tip>
   <para>
    <function>COALESCE</function> and <function>NULLIF</function> are
    just shorthand for <token>CASE</token> expressions.  They are actually
    converted into <token>CASE</token> expressions at a very early stage
    of processing, and subsequent processing thinks it is dealing with
    <token>CASE</token>.  Thus an incorrect <function>COALESCE</function> or
    <function>NULLIF</function> usage may draw an error message that
    refers to <token>CASE</token>.
   </para>
  </tip>

2856 2857 2858 2859
 </sect1>


  <sect1 id="functions-misc">
2860
   <title>Miscellaneous Functions</>
2861 2862 2863 2864 2865 2866 2867 2868 2869 2870 2871 2872 2873 2874 2875

   <table>
    <title>Miscellaneous Functions</>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</> <entry>Return type</> <entry>Description</></row>
     </thead>

     <tbody>
      <row>
       <entry>current_user</>
       <entry>name</>
       <entry>user name of current execution context</>
      </row>
      <row>
2876
       <entry>session_user</>
2877
       <entry>name</>
2878
       <entry>session user name</>
2879 2880
      </row>
      <row>
2881
       <entry>user</>
2882
       <entry>name</>
2883
       <entry>equivalent to <function>current_user</></>
2884 2885 2886 2887 2888 2889 2890 2891 2892 2893 2894 2895 2896 2897 2898 2899 2900 2901 2902 2903 2904 2905 2906 2907 2908 2909 2910 2911 2912 2913
      </row>
     </tbody>
    </tgroup>
   </table>

   <para>
    The <function>session_user</> is the user that initiated a database
    connection and is fixed for the duration of that connection. The
    <function>current_user</> is the user identifier that is applicable
    for permission checking. Currently it is always equal to the session
    user, but in the future there might be <quote>setuid</> functions and
    other facilities to allow the current user to change temporarily.
    In Unix parlance, the session user is the <quote>real user</>
    and the current user is the <quote>effective user</>.
   </para>

   <para>
    Note that these functions have special syntactic status in <acronym>SQL</>;
    they must be called without trailing parentheses.
   </para>

   <note>
    <title>Deprecated</>
    <para>
     The function <function>getpgusername()</> is an obsolete equivalent
     of <function>current_user</>.
    </para>
   </note>
  </sect1>

2914

2915 2916
 <sect1 id="functions-aggregate">
  <title>Aggregate Functions</title>
2917

2918 2919
  <note>
   <title>Author</title>
2920
   <para>
2921
    Written by Isaac Wilcox <email>isaac@azartmedia.com</email> on 2000-06-16
2922
   </para>
2923
  </note>
2924

2925 2926 2927 2928 2929 2930 2931
  <para>
   <firstterm>Aggregate functions</firstterm> compute a single result
   value from a set of input values.  The special syntax
   considerations for aggregate functions are explained in <xref
   linkend="syntax-aggregates">.  Consult the <citetitle>PostgreSQL
   Tutorial</citetitle> for additional introductory information.
  </para>
2932

2933 2934
  <table tocentry="1">
   <title>Aggregate Functions</title>
2935

2936 2937 2938 2939 2940 2941 2942 2943 2944 2945 2946 2947 2948 2949 2950 2951 2952 2953 2954 2955 2956 2957 2958 2959 2960 2961 2962 2963 2964 2965 2966 2967 2968 2969 2970 2971 2972 2973 2974 2975 2976 2977 2978 2979 2980 2981 2982 2983 2984 2985 2986 2987 2988 2989 2990 2991 2992 2993 2994 2995 2996 2997 2998 2999 3000 3001 3002 3003 3004 3005 3006 3007 3008 3009 3010 3011 3012 3013 3014 3015 3016 3017 3018 3019 3020 3021 3022 3023 3024 3025 3026 3027 3028 3029 3030 3031
   <tgroup cols="3">
    <thead>
     <row>
      <entry>Function</entry>
      <entry>Description</entry>
      <entry>Notes</entry>
     </row>
    </thead>

    <tbody>
     <row>
      <entry>AVG(<replaceable class="parameter">expression</replaceable>)</entry>
      <entry>the average (arithmetic mean) of all input values</entry>
      <entry>
       Finding the average value is available on the following data
       types: <type>smallint</type>, <type>integer</type>,
       <type>bigint</type>, <type>real</type>, <type>double
       precision</type>, <type>numeric</type>, <type>interval</type>.
       The result is of type <type>numeric</type> for any integer type
       input, <type>double precision</type> for floating point input,
       otherwise the same as the input data type.
      </entry>
     </row>

     <row>
      <entry>COUNT(*)</entry>
      <entry>number of input values</entry>
      <entry>The return value is of type <type>integer</type>.</entry>
     </row>

     <row>
      <entry>COUNT(<replaceable class="parameter">expression</replaceable>)</entry>
      <entry>
       Counts the input values for which the value of <replaceable
       class="parameter">expression</replaceable> is not NULL.
      </entry>
      <entry></entry>
     </row>

     <row>
      <entry>MAX(<replaceable class="parameter">expression</replaceable>)</entry>
      <entry>the maximum value of <replaceable class="parameter">expression</replaceable> across all input values</entry>
      <entry>
       Available for all numeric, string, and date/time types.  The
       result has the same type as the input expression.
      </entry>
     </row>

     <row>
      <entry>MIN(<replaceable class="parameter">expression</replaceable>)</entry>
      <entry>the minimum value of <replaceable class="parameter">expression</replaceable> across all input values</entry>
      <entry>
       Available for all numeric, string, and date/time types.  The
       result has the same type as the input expression.
      </entry>
     </row>

     <row>
      <entry>STDDEV(<replaceable class="parameter">expression</replaceable>)</entry>
      <entry>the sample standard deviation of the input values</entry>
      <entry>
       Finding the standard deviation is available on the following
       data types: <type>smallint</type>, <type>integer</type>,
       <type>bigint</type>, <type>real</type>, <type>double
       precision</type>, <type>numeric</type>.  The result is of type
       <type>double precision</type> for floating point input,
       otherwise <type>numeric</type>.
      </entry>
     </row>

     <row>
      <entry>SUM(<replaceable class="parameter">expression</replaceable>)</entry>
      <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
      <entry>
       Summation is available on the following data types:
       <type>smallint</type>, <type>integer</type>,
       <type>bigint</type>, <type>real</type>, <type>double
       precision</type>, <type>numeric</type>, <type>interval</type>.
       The result is of type <type>numeric</type> for any integer type
       input, <type>double precision</type> for floating point input,
       otherwise the same as the input data type.
      </entry>
     </row>

     <row>
      <entry>VARIANCE(<replaceable class="parameter">expression</replaceable>)</entry>
      <entry>the sample variance of the input values</entry>
      <entry>
       The variance is the square of the standard deviation.  The
       supported data types are the same.
      </entry>
     </row>

    </tbody>
   </tgroup>
  </table>
3032

3033 3034 3035 3036 3037 3038
  <para>
   It should be noted that except for <function>COUNT</function>,
   these functions return NULL when no rows are selected.  In
   particular, <function>SUM</function> of no rows returns NULL, not
   zero as one might expect.
  </para>
3039

3040
 </sect1>
3041

3042
</chapter>
3043

3044 3045
<!-- Keep this comment at the end of the file
Local variables:
Thomas G. Lockhart's avatar
Thomas G. Lockhart committed
3046
mode:sgml
3047
sgml-omittag:nil
3048 3049 3050 3051 3052 3053 3054 3055
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
Thomas G. Lockhart's avatar
Thomas G. Lockhart committed
3056
sgml-local-catalogs:("/usr/lib/sgml/catalog")
3057 3058 3059
sgml-local-ecat-files:nil
End:
-->