func.sgml 164 KB
Newer Older
1
<!--
2
$Header: /cvsroot/pgsql/doc/src/sgml/func.sgml,v 1.88 2001/12/23 20:22:49 tgl Exp $
3
PostgreSQL documentation
4
-->
5 6 7 8

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

9 10 11 12 13 14 15 16
 <indexterm zone="functions">
  <primary>functions</primary>
 </indexterm>

 <indexterm zone="functions">
  <primary>operators</primary>
 </indexterm>

17
 <para>
18
  <productname>PostgreSQL</productname> provides a large number of
19 20 21 22 23
  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
24
  available functions and operators, respectively.
25 26 27 28 29 30
 </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
31
  and some explicitly marked functions, are not specified by the <acronym>SQL</acronym>
32 33
  standard. Some of this extended functionality is present in other
  <acronym>RDBMS</acronym> products, and in many cases this
Tom Lane's avatar
Tom Lane committed
34
  functionality is compatible and consistent between various products.
35 36
 </para>

37 38 39 40

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

41 42 43 44 45 46 47 48 49 50 51
  <indexterm zone="functions-logical">
   <primary>operators</primary>
   <secondary>logical</secondary>
  </indexterm>

  <indexterm>
   <primary>Boolean</primary>
   <secondary>operators</secondary>
   <see>operators, logical</see>
  </indexterm>

52 53 54
  <para>
   The usual logical operators are available:

55 56 57 58 59 60 61 62 63 64 65 66 67 68 69
   <indexterm>
    <primary>and</primary>
    <secondary>operator</secondary>
   </indexterm>

   <indexterm>
    <primary>or</primary>
    <secondary>operator</secondary>
   </indexterm>

   <indexterm>
    <primary>not</primary>
    <secondary>operator</secondary>
   </indexterm>

70 71 72 73 74 75
   <simplelist>
    <member>AND</member>
    <member>OR</member>
    <member>NOT</member>
   </simplelist>

76
   <acronym>SQL</acronym> uses a three-valued Boolean logic where NULL represents
77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124
   <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>
125 126 127 128 129 130 131

      <row>
       <entry>NULL</entry>
       <entry>NULL</entry>
       <entry>NULL</entry>
       <entry>NULL</entry>
      </row>
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
     </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>

166 167 168
 <sect1 id="functions-comparison">
  <title>Comparison Operators</title>

169 170 171 172 173
  <indexterm zone="functions-comparison">
   <primary>comparison</primary>
   <secondary>operators</secondary>
  </indexterm>

174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218
  <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>
219
   <para>
220 221 222 223
    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.
224
   </para>
225 226 227 228 229
  </note>

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

Peter Eisentraut's avatar
Peter Eisentraut committed
236
  <para>
237 238 239
   <indexterm>
    <primary>between</primary>
   </indexterm>
Peter Eisentraut's avatar
Peter Eisentraut committed
240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261
   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>

262 263 264 265 266 267
  <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>
268 269 270 271 272 273 274 275 276
   or the equivalent, but less standard, constructs
<synopsis>
<replaceable>expression</replaceable> ISNULL
<replaceable>expression</replaceable> NOTNULL
</synopsis>
  </para>

  <para>
   Do <emphasis>not</emphasis> write
277 278
   <literal><replaceable>expression</replaceable> = NULL</literal>
   because NULL is not <quote>equal to</quote> NULL.  (NULL represents
279 280
   an unknown value, and it is not known whether two unknown values are
   equal.)
281
  </para>
282 283

  <para>
284 285 286 287 288 289
   Some applications may (incorrectly) require that
   <literal><replaceable>expression</replaceable> = NULL</literal>
   returns true if <replaceable>expression</replaceable> evaluates to
   the NULL value.  To support these applications, the run-time option
   <varname>transform_null_equals</varname> can be turned on (e.g.,
   <literal>SET transform_null_equals TO ON;</literal>).
290
   <productname>PostgreSQL</productname> will then convert <literal>x
291 292 293 294 295 296
   = NULL</literal> clauses to <literal>x IS NULL</literal>.  This was
   the default behavior in releases 6.5 through 7.1.
  </para>

  <para>
   Boolean values can also be tested using the constructs
297 298 299 300 301 302 303 304 305 306 307 308
<synopsis>
<replaceable>expression</replaceable> IS TRUE
<replaceable>expression</replaceable> IS NOT TRUE
<replaceable>expression</replaceable> IS FALSE
<replaceable>expression</replaceable> IS NOT FALSE
<replaceable>expression</replaceable> IS UNKNOWN
<replaceable>expression</replaceable> IS NOT UNKNOWN
</synopsis>
   These are similar to <literal>IS NULL</literal> in that they will
   always return TRUE or FALSE, never NULL, even when the operand is NULL.
   A NULL input is treated as the logical value UNKNOWN.
  </para>
309 310 311 312 313 314
 </sect1>


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

315 316 317 318 319 320 321 322
  <para>
   Mathematical operators are provided for many
   <productname>PostgreSQL</productname> types. For types without
   common mathematical conventions for all possible permutations 
   (e.g. date/time types) we
   describe the actual behavior in subsequent sections.
  </para>

323
  <table>
324
   <title>Mathematical Operators</title>
325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375

   <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>
376
      <entry>8</entry>
377 378 379 380 381 382
     </row>

     <row>
      <entry> <literal>|/</literal> </entry>
      <entry>Square root</entry>
      <entry>|/ 25.0</entry>
383
      <entry>5</entry>
384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401
     </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>
402
      <entry>Factorial (prefix operator)</entry>
403 404 405 406 407 408 409 410
      <entry>!! 5</entry>
      <entry>120</entry>
     </row>

     <row>
      <entry> <literal>@</literal> </entry>
      <entry>Absolute value</entry>
      <entry>@ -5.0</entry>
411
      <entry>5</entry>
412
     </row>
413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455

     <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>

456 457 458 459
    </tbody>
   </tgroup>
  </table>

460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508
  <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>
509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524

  <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>
525
      <entry><function>abs</function>(<replaceable>x</replaceable>)</entry>
526
      <entry>(same as x)</entry>
527
      <entry>absolute value</entry>
528
      <entry><literal>abs(-17.4)</literal></entry>
529 530 531 532
      <entry>17.4</entry>
     </row>

     <row>
533
      <entry><function>cbrt</function>(<type>dp</type>)</entry>
534
      <entry><type>dp</type></entry>
535
      <entry>cube root</entry>
536
      <entry><literal>cbrt(27.0)</literal></entry>
537
      <entry>3</entry>
538 539 540
     </row>

     <row>
541
      <entry><function>ceil</function>(<type>numeric</type>)</entry>
542 543
      <entry><type>numeric</type></entry>
      <entry>smallest integer not less than argument</entry>
544
      <entry><literal>ceil(-42.8)</literal></entry>
545 546 547 548
      <entry>-42</entry>
     </row>

     <row>
549
      <entry><function>degrees</function>(<type>dp</type>)</entry>
550 551
      <entry><type>dp</type></entry>
      <entry>radians to degrees</entry>
552
      <entry><literal>degrees(0.5)</literal></entry>
553 554 555 556
      <entry>28.6478897565412</entry>
     </row>

     <row>
557
      <entry><function>exp</function>(<type>dp</type>)</entry>
558 559
      <entry><type>dp</type></entry>
      <entry>exponential</entry>
560
      <entry><literal>exp(1.0)</literal></entry>
561 562 563 564
      <entry>2.71828182845905</entry>
     </row>

     <row>
565
      <entry><function>floor</function>(<type>numeric</type>)</entry>
566 567
      <entry><type>numeric</type></entry>
      <entry>largest integer not greater than argument</entry>
568
      <entry><literal>floor(-42.8)</literal></entry>
569
      <entry>-43</entry>
570 571 572
     </row>

     <row>
573
      <entry><function>ln</function>(<type>dp</type>)</entry>
574
      <entry><type>dp</type></entry>
575
      <entry>natural logarithm</entry>
576
      <entry><literal>ln(2.0)</literal></entry>
577 578 579 580
      <entry>0.693147180559945</entry>
     </row>

     <row>
581
      <entry><function>log</function>(<type>dp</type>)</entry>
582
      <entry><type>dp</type></entry>
583
      <entry>base 10 logarithm</entry>
584
      <entry><literal>log(100.0)</literal></entry>
585
      <entry>2</entry>
586 587 588
     </row>

     <row>
589
      <entry><function>log</function>(<parameter>b</parameter> <type>numeric</type>,
590
       <parameter>x</parameter> <type>numeric</type>)</entry>
591
      <entry><type>numeric</type></entry>
592
      <entry>logarithm to base <parameter>b</parameter></entry>
593
      <entry><literal>log(2.0, 64.0)</literal></entry>
594
      <entry>6.0000000000</entry>
595 596 597
     </row>

     <row>
598
      <entry><function>mod</function>(<parameter>y</parameter>, <parameter>x</parameter>)</entry>
599
      <entry>(same as argument types)</entry>
600
      <entry>remainder of <parameter>y</parameter>/<parameter>x</parameter></entry>
601
      <entry><literal>mod(9,4)</literal></entry>
602 603 604 605
      <entry>1</entry>
     </row>

     <row>
606
      <entry><function>pi</function>()</entry>
607
      <entry><type>dp</type></entry>
608
      <entry><quote>Pi</quote> constant</entry>
609
      <entry><literal>pi()</literal></entry>
610 611 612 613
      <entry>3.14159265358979</entry>
     </row>

     <row>
614
      <entry><function>pow</function>(<parameter>e</parameter> <type>dp</type>,
615 616 617
       <parameter>n</parameter> <type>dp</type>)</entry>
      <entry><type>dp</type></entry>
      <entry>raise a number to exponent <parameter>e</parameter></entry>
618
      <entry><literal>pow(9.0, 3.0)</literal></entry>
619
      <entry>729</entry>
620 621 622
     </row>

     <row>
623
      <entry><function>radians</function>(<type>dp</type>)</entry>
624 625
      <entry><type>dp</type></entry>
      <entry>degrees to radians</entry>
626
      <entry><literal>radians(45.0)</literal></entry>
627 628 629 630
      <entry>0.785398163397448</entry>
     </row>

     <row>
631
      <entry><function>random</function>()</entry>
632 633
      <entry><type>dp</type></entry>
      <entry>value between 0.0 to 1.0</entry>
634
      <entry><literal>random()</literal></entry>
635 636 637 638
      <entry></entry>
     </row>

     <row>
639
      <entry><function>round</function>(<type>dp</type>)</entry>
640
      <entry><type>dp</type></entry>
641
      <entry>round to nearest integer</entry>
642
      <entry><literal>round(42.4)</literal></entry>
643 644 645 646
      <entry>42</entry>
     </row>

     <row>
647
      <entry><function>round</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type>)</entry>
648
      <entry><type>numeric</type></entry>
649
      <entry>round to <parameter>s</parameter> decimal places</entry>
650
      <entry><literal>round(42.4382, 2)</literal></entry>
651 652 653 654
      <entry>42.44</entry>
     </row>
<!--
     <row>
655
      <entry><function>setseed</function>(<replaceable>new-seed</replaceable>)</entry>
656
      <entry>set seed for subsequent random() calls</entry>
657
      <entry><literal>setseed(0.54823)</literal></entry>
658 659 660
      <entry></entry>
     </row>
-->
661 662 663 664 665 666 667 668
     <row>
      <entry><function>sign</function>(<type>numeric</type>)</entry>
      <entry><type>numeric</type></entry>
      <entry>sign of the argument (-1, 0, +1)</entry>
      <entry><literal>sign(-8.4)</literal></entry>
      <entry>-1</entry>
     </row>

669
     <row>
670
      <entry><function>sqrt</function>(<type>dp</type>)</entry>
671
      <entry><type>dp</type></entry>
672
      <entry>square root</entry>
673
      <entry><literal>sqrt(2.0)</literal></entry>
674 675 676 677
      <entry>1.4142135623731</entry>
     </row>

     <row>
678
      <entry><function>trunc</function>(<type>dp</type>)</entry>
679 680
      <entry><type>dp</type></entry>
      <entry>truncate toward zero</entry>
681
      <entry><literal>trunc(42.8)</literal></entry>
682 683 684 685
      <entry>42</entry>
     </row>

     <row>
686
      <entry><function>trunc</function>(<type>numeric</type>, <parameter>s</parameter> <type>integer</type>)</entry>
687
      <entry><type>numeric</type></entry>
688
      <entry>truncate to <parameter>s</parameter> decimal places</entry>
689
      <entry><literal>trunc(42.4382, 2)</literal></entry>
690 691 692 693 694 695 696 697
      <entry>42.43</entry>
     </row>

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

  <para>
698
   In the table above, <literal>dp</literal> indicates <type>double precision</type>.
699 700 701 702 703
   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
704 705 706 707
   precision</type>.
   Functions returning a <type>numeric</type> result take
   <type>numeric</type> input arguments, unless otherwise specified.
   Many of these functions are implemented on top
Tom Lane's avatar
Tom Lane committed
708 709
   of the host system's C library; accuracy and behavior in boundary cases
   could therefore vary depending on the host system.
710 711 712 713 714 715 716 717 718 719 720 721 722 723 724
  </para>

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

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

    <tbody>
     <row>
725
      <entry><function>acos</function>(<replaceable>x</replaceable>)</entry>
726 727 728 729
      <entry>inverse cosine</entry>
     </row>

     <row>
730
      <entry><function>asin</function>(<replaceable>x</replaceable>)</entry>
731 732 733 734
      <entry>inverse sine</entry>
     </row>

     <row>
735
      <entry><function>atan</function>(<replaceable>x</replaceable>)</entry>
736 737 738 739
      <entry>inverse tangent</entry>
     </row>

     <row>
740
      <entry><function>atan2</function>(<replaceable>x</replaceable>, <replaceable>y</replaceable>)</entry>
741 742 743 744
      <entry>inverse tangent of <replaceable>y</replaceable>/<replaceable>x</replaceable></entry>
     </row>

     <row>
745
      <entry><function>cos</function>(<replaceable>x</replaceable>)</entry>
746 747 748 749
      <entry>cosine</entry>
     </row>

     <row>
750
      <entry><function>cot</function>(<replaceable>x</replaceable>)</entry>
751 752 753 754
      <entry>cotangent</entry>
     </row>

     <row>
755
      <entry><function>sin</function>(<replaceable>x</replaceable>)</entry>
756 757 758 759
      <entry>sine</entry>
     </row>

     <row>
760
      <entry><function>tan</function>(<replaceable>x</replaceable>)</entry>
761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784
      <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
Peter Eisentraut's avatar
Peter Eisentraut committed
785
   <type>CHARACTER</type> type.  Generally, the functions described
786
   here also work on data of non-string types by converting that data
787
   to a string representation first.  Some functions also exist
Peter Eisentraut's avatar
Peter Eisentraut committed
788
   natively for bit-string types.
789 790 791
  </para>

  <para>
792
   <acronym>SQL</acronym> defines some string functions with a special syntax where
793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815
   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>
816 817 818 819 820 821 822
      <entry>
       string concatenation
       <indexterm>
        <primary>character strings</primary>
	<secondary>concatenation</secondary>
       </indexterm>
      </entry>
823 824
      <entry><literal>'Postgre' || 'SQL'</></entry>
      <entry><literal>PostgreSQL</></entry>
825 826
     </row>

Peter Eisentraut's avatar
Peter Eisentraut committed
827
     <row>
828
      <entry><function>bit_length</function>(<parameter>string</parameter>)</entry>
Peter Eisentraut's avatar
Peter Eisentraut committed
829 830
      <entry><type>integer</type></entry>
      <entry>number of bits in string</entry>
831 832
      <entry><literal>bit_length('jose')</literal></entry>
      <entry><literal>32</literal></entry>
Peter Eisentraut's avatar
Peter Eisentraut committed
833 834
     </row>

835
     <row>
836
      <entry><function>char_length</function>(<parameter>string</parameter>) or <function>character_length</function>(<parameter>string</parameter>)</entry>
837
      <entry><type>integer</type></entry>
838
      <entry>
Tom Lane's avatar
Tom Lane committed
839
       number of characters in string
840 841 842 843 844 845 846 847 848 849
       <indexterm>
        <primary>character strings</primary>
	<secondary>length</secondary>
       </indexterm>
       <indexterm>
        <primary>length</primary>
	<secondary>character strings</secondary>
	<see>character strings, length</see>
       </indexterm>
      </entry>
850 851
      <entry><literal>char_length('jose')</></entry>
      <entry><literal>4</></entry>
852 853 854
     </row>

     <row>
855
      <entry><function>lower</function>(<parameter>string</parameter>)</entry>
856 857
      <entry><type>text</type></entry>
      <entry>Convert string to lower case.</entry>
858 859
      <entry><literal>lower('TOM')</literal></entry>
      <entry><literal>tom</literal></entry>
860 861 862
     </row>

     <row>
863
      <entry><function>octet_length</function>(<parameter>string</parameter>)</entry>
864 865
      <entry><type>integer</type></entry>
      <entry>number of bytes in string</entry>
866 867
      <entry><literal>octet_length('jose')</literal></entry>
      <entry><literal>4</literal></entry>
868 869 870
     </row>

     <row>
871
      <entry><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</entry>
872 873
      <entry><type>integer</type></entry>
      <entry>location of specified substring</entry>
874 875
      <entry><literal>position('om' in 'Thomas')</literal></entry>
      <entry><literal>3</literal></entry>
876 877 878
     </row>

     <row>
879
      <entry><function>substring</function>(<parameter>string</parameter> <optional>from <type>integer</type></optional> <optional>for <type>integer</type></optional>)</entry>
880
      <entry><type>text</type></entry>
881 882 883 884 885 886
      <entry>
       extract substring
       <indexterm>
        <primary>substring</primary>
       </indexterm>
      </entry>
887 888
      <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
      <entry><literal>hom</literal></entry>
889 890 891 892
     </row>

     <row>
      <entry>
893
       <function>trim</function>(<optional>leading | trailing | both</optional>
894 895 896 897 898 899 900 901 902
       <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>
Tom Lane's avatar
Tom Lane committed
903
      <entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
904
      <entry><literal>Tom</literal></entry>
905 906 907
     </row>

     <row>
908
      <entry><function>upper</function>(<parameter>string</parameter>)</entry>
909 910
      <entry><type>text</type></entry>
      <entry>Convert string to upper case.</entry>
911 912
      <entry><literal>upper('tom')</literal></entry>
      <entry><literal>TOM</literal></entry>
913 914 915 916
     </row>
    </tbody>
   </tgroup>
  </table>
917

918
  <para>
919 920
   Additional string manipulation functions are available and are
   listed below.  Some of them are used internally to implement the
Tom Lane's avatar
Tom Lane committed
921
   <acronym>SQL</acronym>-standard string functions listed above.
922
  </para>
923

924 925 926 927 928 929
  <table id="functions-string-other">
   <title>Other String Functions</title>
   <tgroup cols="5">
    <thead>
     <row>
      <entry>Function</entry>
930
      <entry>Return Type</entry>
931 932 933 934 935 936 937 938
      <entry>Description</entry>
      <entry>Example</entry>
      <entry>Result</entry>
     </row>
    </thead>

    <tbody>
     <row>
939
      <entry><function>ascii</function>(<type>text</type>)</entry>
940 941
      <entry>integer</entry>
      <entry>Returns the <acronym>ASCII</acronym> code of the first character of the argument.</entry>
942 943
      <entry><literal>ascii('x')</literal></entry>
      <entry><literal>120</literal></entry>
944 945 946
     </row>

     <row>
947
      <entry><function>btrim</function>(<parameter>string</parameter> <type>text</type>, <parameter>trim</parameter> <type>text</type>)</entry>
948 949 950 951 952 953
      <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>
954 955
      <entry><literal>btrim('xyxtrimyyx','xy')</literal></entry>
      <entry><literal>trim</literal></entry>
956 957 958
     </row>

     <row>
959
      <entry><function>chr</function>(<type>integer</type>)</entry>
960 961
      <entry><type>text</type></entry>
      <entry>Returns the character with the given <acronym>ASCII</acronym> code.</entry>
962 963
      <entry><literal>chr(65)</literal></entry>
      <entry><literal>A</literal></entry>
964 965
     </row>

Tatsuo Ishii's avatar
Tatsuo Ishii committed
966
     <row>
967 968 969 970 971
      <entry>
       <function>convert</function>(<parameter>string</parameter> <type>text</type>,
       <optional><parameter>src_encoding</parameter> <type>name</type>,</optional>
       <parameter>dest_encoding</parameter> <type>name</type>)
      </entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
972
      <entry><type>text</type></entry>
973 974 975 976 977 978
      <entry>
       Converts string using <parameter>dest_encoding</parameter>.
       The original encoding is specified by
       <parameter>src_encoding</parameter>.  If
       <parameter>src_encoding</parameter> is omitted, database
       encoding is assumed.
Tatsuo Ishii's avatar
Tatsuo Ishii committed
979
      </entry>
980 981
      <entry><literal>convert('text_in_unicode', 'UNICODE', 'LATIN1')</literal></entry>
      <entry><literal>text_in_unicode</literal> represented in ISO 8859-1</entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
982 983
     </row>

984
     <row>
985
      <entry><function>initcap</function>(<type>text</type>)</entry>
986 987
      <entry><type>text</type></entry>
      <entry>Converts first letter of each word (whitespace separated) to upper case.</entry>
988 989
      <entry><literal>initcap('hi thomas')</literal></entry>
      <entry><literal>Hi Thomas</literal></entry>
990 991
     </row>

992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010
     <row>
      <entry><function>length</function>(<parameter>string</parameter>)</entry>
      <entry><type>integer</type></entry>
      <entry>
       length of string
       <indexterm>
        <primary>character strings</primary>
	<secondary>length</secondary>
       </indexterm>
       <indexterm>
        <primary>length</primary>
	<secondary>character strings</secondary>
	<see>character strings, length</see>
       </indexterm>
      </entry>
      <entry><literal>length('jose')</></entry>
      <entry><literal>4</></entry>
     </row>

1011 1012
     <row>
      <entry>
1013
       <function>lpad</function>(<parameter>string</parameter> <type>text</type>,
1014 1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025
       <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>
1026 1027
      <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
      <entry><literal>xyxhi</literal></entry>
1028 1029 1030
     </row>

     <row>
1031
      <entry><function>ltrim</function>(<parameter>string</parameter> <type>text</type>, <parameter>trim</parameter> <type>text</type>)</entry>
1032 1033 1034 1035 1036
      <entry><type>text</type></entry>
      <entry>
       Removes the longest string containing only characters from
       <parameter>trim</parameter> from the start of the string.
      </entry>
1037 1038
      <entry><literal>ltrim('zzzytrim','xyz')</literal></entry>
      <entry><literal>trim</literal></entry>
1039 1040
     </row>

1041 1042 1043 1044 1045 1046 1047 1048 1049 1050
     <row>
      <entry><function>pg_client_encoding</function>()</entry>
      <entry><type>name</type></entry>
      <entry>
       Returns current client encoding name.
      </entry>
      <entry><literal>pg_client_encoding()</literal></entry>
      <entry><literal>SQL_ASCII</literal></entry>
     </row>

1051
     <row>
1052
      <entry><function>repeat</function>(<type>text</type>, <type>integer</type>)</entry>
1053 1054
      <entry><type>text</type></entry>
      <entry>Repeat text a number of times.</entry>
1055 1056
      <entry><literal>repeat('Pg', 4)</literal></entry>
      <entry><literal>PgPgPgPg</literal></entry>
1057 1058 1059 1060
     </row>

     <row>
      <entry>
1061
       <function>rpad</function>(<parameter>string</parameter> <type>text</type>,
1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072
       <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>
1073 1074
      <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
      <entry><literal>hixyx</literal></entry>
1075 1076 1077
     </row>

     <row>
1078
      <entry><function>rtrim</function>(<parameter>string</parameter> text, <parameter>trim</parameter> text)</entry>
1079 1080 1081 1082 1083
      <entry><type>text</type></entry>
      <entry>
       Removes the longest string containing only characters from
       <parameter>trim</parameter> from the end of the string.
      </entry>
1084 1085
      <entry><literal>rtrim('trimxxxx','x')</literal></entry>
      <entry><literal>trim</literal></entry>
1086 1087 1088
     </row>

     <row>
1089
      <entry><function>strpos</function>(<parameter>string</parameter>, <parameter>substring</parameter>)</entry>
1090 1091 1092 1093 1094 1095 1096
      <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>
1097 1098
      <entry><literal>strpos('high','ig')</literal></entry>
      <entry><literal>2</literal></entry>
1099 1100 1101
     </row>

     <row>
1102
      <entry><function>substr</function>(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</entry>
1103 1104 1105 1106
      <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>
1107 1108
      <entry><literal>substr('alphabet', 3, 2)</literal></entry>
      <entry><literal>ph</literal></entry>
1109 1110 1111
     </row>

     <row>
1112
      <entry><function>to_ascii</function>(<type>text</type> <optional>, <parameter>encoding</parameter></optional>)</entry>
1113 1114
      <entry><type>text</type></entry>
      <entry>Converts text from multibyte encoding to <acronym>ASCII</acronym>.</entry>
1115 1116
      <entry><literal>to_ascii('Karel')</literal></entry>
      <entry><literal>Karel</literal></entry>
1117 1118 1119 1120
     </row>

     <row>
      <entry>
1121
       <function>translate</function>(<parameter>string</parameter> <type>text</type>,
1122 1123 1124 1125 1126 1127 1128 1129 1130 1131
       <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>
1132 1133
      <entry><literal>translate('12345', '14', 'ax')</literal></entry>
      <entry><literal>a23x5</literal></entry>
1134
     </row>       
1135 1136 1137
     
     <row>
      <entry>
1138
       <function>encode</function>(<parameter>data</parameter> <type>bytea</type>,
1139 1140 1141 1142
              <parameter>type</parameter> <type>text</type>)
      </entry>
      <entry><type>text</type></entry>
      <entry>
1143
       Encodes binary data to <acronym>ASCII</acronym>-only representation.  Supported
1144
       types are: 'base64', 'hex', 'escape'.
1145
      </entry>
1146 1147
      <entry><literal>encode('123\\000\\001', 'base64')</literal></entry>
      <entry><literal>MTIzAAE=</literal></entry>
1148 1149 1150 1151
     </row>       

     <row>
      <entry>
1152
       <function>decode</function>(<parameter>string</parameter> <type>text</type>,
1153 1154 1155 1156 1157 1158 1159
              <parameter>type</parameter> <type>text</type>)
      </entry>
      <entry><type>bytea</type></entry>
      <entry>
       Decodes binary data from <parameter>string</parameter> previously 
       encoded with encode().  Parameter type is same as in encode().
      </entry>
1160 1161
      <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
      <entry><literal>123\000\001</literal></entry>
1162
     </row>       
1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 1174

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

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


1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 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
 <sect1 id="functions-binarystring">
  <title>Binary String Functions and Operators</title>

  <para>
   This section describes functions and operators for examining and
   manipulating binary string values.  Strings in this context include
   values of the type <type>BYTEA</type>.
  </para>

  <para>
   <acronym>SQL</acronym> 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-binarystring-sql">.
   Some functions are also implemented using the regular syntax for
   function invocation.  (See <xref linkend="functions-binarystring-other">.)
  </para>

  <table id="functions-binarystring-sql">
   <title><acronym>SQL</acronym> Binary 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>bytea</type> </entry>
      <entry>
       string concatenation
       <indexterm>
        <primary>binary strings</primary>
	<secondary>concatenation</secondary>
       </indexterm>
      </entry>
      <entry><literal>'\\\\Postgre'::bytea || '\\047SQL\\000'::bytea</></entry>
      <entry><literal>\\Postgre'SQL\000</></entry>
     </row>

     <row>
      <entry><function>octet_length</function>(<parameter>string</parameter>)</entry>
      <entry><type>integer</type></entry>
      <entry>number of bytes in binary string</entry>
      <entry><literal>octet_length('jo\\000se'::bytea)</literal></entry>
      <entry><literal>5</literal></entry>
     </row>

     <row>
      <entry><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</entry>
      <entry><type>integer</type></entry>
      <entry>location of specified substring</entry>
      <entry><literal>position('\\000om'::bytea in 'Th\\000omas'::bytea)</literal></entry>
      <entry><literal>3</literal></entry>
     </row>

     <row>
      <entry><function>substring</function>(<parameter>string</parameter> <optional>from <type>integer</type></optional> <optional>for <type>integer</type></optional>)</entry>
      <entry><type>bytea</type></entry>
      <entry>
       extract substring
       <indexterm>
        <primary>substring</primary>
       </indexterm>
      </entry>
      <entry><literal>substring('Th\\000omas'::bytea from 2 for 3)</literal></entry>
      <entry><literal>h\000o</literal></entry>
     </row>

     <row>
      <entry>
       <function>trim</function>(<optional>both</optional>
       <parameter>characters</parameter> from
       <parameter>string</parameter>)
      </entry>
      <entry><type>bytea</type></entry>
      <entry>
       Removes the longest string containing only the
       <parameter>characters</parameter> from the
       beginning/end/both ends of the <parameter>string</parameter>.
      </entry>
      <entry><literal>trim('\\000'::bytea from '\\000Tom\\000'::bytea)</literal></entry>
      <entry><literal>Tom</literal></entry>
     </row>

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

  <para>
   Additional binary string manipulation functions are available and are
   listed below.  Some of them are used internally to implement the
   <acronym>SQL</acronym>-standard string functions listed above.
  </para>

  <table id="functions-binarystring-other">
   <title>Other Binary 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><function>btrim</function>(<parameter>string</parameter> <type>bytea</type>, <parameter>trim</parameter> <type>bytea</type>)</entry>
      <entry><type>bytea</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><literal>btrim('\\000trim\\000'::bytea,'\\000'::bytea)</literal></entry>
      <entry><literal>trim</literal></entry>
     </row>

     <row>
      <entry><function>length</function>(<parameter>string</parameter>)</entry>
      <entry><type>integer</type></entry>
      <entry>
       length of binary string
       <indexterm>
        <primary>binary strings</primary>
	<secondary>length</secondary>
       </indexterm>
       <indexterm>
        <primary>length</primary>
	<secondary>binary strings</secondary>
	<see>binary strings, length</see>
       </indexterm>
      </entry>
      <entry><literal>length('jo\\000se'::bytea)</></entry>
      <entry><literal>5</></entry>
     </row>

     <row>
      <entry>
       <function>encode</function>(<parameter>string</parameter> <type>bytea</type>,
              <parameter>type</parameter> <type>text</type>)
      </entry>
      <entry><type>text</type></entry>
      <entry>
       Encodes binary string to <acronym>ASCII</acronym>-only representation.  Supported
       types are: 'base64', 'hex', 'escape'.
      </entry>
      <entry><literal>encode('123\\000456'::bytea, 'escape')</literal></entry>
      <entry><literal>123\000456</literal></entry>
     </row>       

     <row>
      <entry>
       <function>decode</function>(<parameter>string</parameter> <type>text</type>,
              <parameter>type</parameter> <type>text</type>)
      </entry>
      <entry><type>bytea</type></entry>
      <entry>
       Decodes binary string from <parameter>string</parameter> previously 
       encoded with encode().  Parameter type is same as in encode().
      </entry>
      <entry><literal>decode('123\\000456', 'escape')</literal></entry>
      <entry><literal>123\000456</literal></entry>
     </row>       

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

 </sect1>


1355 1356 1357 1358 1359
 <sect1 id="functions-matching">
  <title>Pattern Matching</title>

  <para>
   There are two separate approaches to pattern matching provided by
1360
   <productname>PostgreSQL</productname>:  the <acronym>SQL</acronym>
1361 1362 1363
   <function>LIKE</function> operator and
   <acronym>POSIX</acronym>-style regular expressions.
  </para>
1364

1365
  <tip>
1366
   <para>
1367 1368 1369
    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.
1370
   </para>
1371 1372 1373 1374 1375
  </tip>

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

1376 1377 1378 1379
   <indexterm>
    <primary>like</primary>
   </indexterm>

1380 1381 1382 1383
<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>
1384 1385

   <para>
1386 1387 1388 1389 1390 1391 1392 1393 1394
    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>.)
1395 1396
   </para>

1397 1398
   <para>
    If <replaceable>pattern</replaceable> does not contain percent
1399
    signs or underscore, then the pattern only represents the string
1400 1401 1402
    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
1403 1404
    character; a percent sign (<literal>%</literal>) matches any string
    of zero or more characters.
1405 1406 1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417
   </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>
1418

1419
   <para>
1420
    <function>LIKE</function> pattern matches always cover the entire
1421
    string.  To match a pattern anywhere within a string, the
1422
    pattern must therefore start and end with a percent sign.
1423
   </para>
1424 1425

   <para>
1426 1427 1428 1429
    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
1430
    character is the backslash but a different one may be selected by
1431 1432 1433 1434 1435 1436 1437
    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
1438 1439 1440
    you must write two backslashes in the query.  Thus, writing a pattern
    that actually matches a literal backslash means writing four backslashes
    in the query.  You can avoid this by selecting a different escape
Peter Eisentraut's avatar
Peter Eisentraut committed
1441 1442
    character with <literal>ESCAPE</literal>; then backslash is not special
    to <function>LIKE</> anymore. (But it is still special to the string
1443 1444 1445 1446 1447 1448 1449 1450
    literal parser, so you still need two of them.)
   </para>

   <para>
    It's also possible to select no escape character by writing
    <literal>ESCAPE ''</literal>.  In this case there is no way to
    turn off the special meaning of underscore and percent signs in
    the pattern.
1451
   </para>
1452 1453

   <para>
1454 1455
    The keyword <token>ILIKE</token> can be used instead of
    <token>LIKE</token> to make the match case insensitive according
1456
    to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
1457
    <productname>PostgreSQL</productname> extension.
1458
   </para>
1459

1460 1461
   <para>
    The operator <literal>~~</literal> is equivalent to
1462 1463 1464
    <function>LIKE</function>, and <literal>~~*</literal> corresponds to
    <function>ILIKE</function>.  There are also
    <literal>!~~</literal> and <literal>!~~*</literal> operators that
1465
    represent <function>NOT LIKE</function> and <function>NOT
1466
    ILIKE</function>.  All of these operators are
1467
    <productname>PostgreSQL</productname>-specific.
1468 1469
   </para>
  </sect2>
1470

1471 1472

  <sect2 id="functions-regexp">
1473
   <title><acronym>POSIX</acronym> Regular Expressions</title>
1474

1475 1476 1477 1478 1479
   <indexterm zone="functions-regexp">
    <primary>regular expressions</primary>
    <seealso>pattern matching</seealso>
   </indexterm>

1480 1481 1482 1483 1484 1485 1486 1487 1488 1489 1490 1491 1492 1493 1494 1495
   <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>
1496
	<ENTRY><literal>'thomas' ~ '.*thomas.*'</literal></ENTRY>
1497 1498 1499 1500
       </ROW>
       <ROW>
	<ENTRY> <literal>~*</literal> </ENTRY>
	<ENTRY>Matches regular expression, case insensitive</ENTRY>
1501
	<ENTRY><literal>'thomas' ~* '.*Thomas.*'</literal></ENTRY>
1502 1503 1504 1505
       </ROW>
       <ROW>
	<ENTRY> <literal>!~</literal> </ENTRY>
	<ENTRY>Does not match regular expression, case sensitive</ENTRY>
1506
	<ENTRY><literal>'thomas' !~ '.*Thomas.*'</literal></ENTRY>
1507 1508 1509 1510
       </ROW>
       <ROW>
	<ENTRY> <literal>!~*</literal> </ENTRY>
	<ENTRY>Does not match regular expression, case insensitive</ENTRY>
1511
	<ENTRY><literal>'thomas' !~* '.*vadim.*'</literal></ENTRY>
1512 1513 1514 1515 1516
       </ROW>
     </tbody>
    </tgroup>
   </table>

1517
   <para>
1518
    <acronym>POSIX</acronym> regular expressions provide a more powerful means for
1519 1520 1521 1522 1523 1524 1525 1526 1527 1528 1529 1530 1531 1532 1533 1534 1535 1536 1537 1538 1539
    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>

1540 1541

<!-- derived from the re_format.7 man page -->
1542
   <para>
1543
    Regular expressions (<quote>RE</quote>s), as defined in <acronym>POSIX</acronym>
1544 1545 1546
    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
1547
    <command>ed</command>; 1003.2 <quote>basic</quote> REs).
1548
    <productname>PostgreSQL</productname> implements the modern form.
1549
   </para>
1550

1551
   <para>
1552 1553 1554 1555
    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.
1556
   </para>
1557

1558
   <para>
1559 1560 1561
    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.
1562
   </para>
1563

Bruce Momjian's avatar
Bruce Momjian committed
1564
   <para>
1565 1566 1567 1568 1569 1570 1571 1572
    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
1573
   </para>
1574

1575 1576 1577 1578 1579 1580 1581 1582 1583 1584 1585 1586 1587 1588 1589 1590 1591 1592 1593 1594 1595 1596 1597 1598 1599 1600 1601 1602
   <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>
1603

1604
   <para>
1605 1606 1607 1608 1609
    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),
1610 1611 1612
    <literal>^</literal> (matching the null string at the beginning of the
    input string), <literal>$</literal> (matching the null string at the end
    of the input string), a <literal>\</literal> followed by one of the
1613 1614 1615 1616 1617 1618 1619 1620 1621
    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>.
1622
   </para>
1623

1624 1625 1626 1627 1628 1629 1630
   <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>

1631
   <para>
1632 1633 1634 1635 1636 1637 1638 1639 1640 1641 1642 1643 1644
    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.
1645
   </para>
1646

1647
   <para>
1648 1649 1650 1651 1652 1653 1654 1655 1656 1657 1658 1659 1660 1661 1662
    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
1663
    multiple-character sequence that collates as if it were a single
1664 1665 1666 1667
    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
1668
    expression containing a multiple-character collating element can thus
1669 1670 1671 1672 1673 1674 1675 1676 1677 1678 1679 1680 1681 1682 1683 1684 1685 1686 1687 1688 1689 1690 1691 1692 1693 1694 1695 1696 1697 1698 1699 1700 1701 1702 1703 1704 1705 1706 1707 1708 1709 1710 1711 1712 1713 1714
    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
1715
    specified by <acronym>POSIX</acronym> 1003.2, and should be used with caution in
1716 1717 1718 1719 1720 1721 1722 1723 1724 1725 1726 1727 1728 1729 1730 1731 1732 1733 1734 1735 1736 1737 1738 1739 1740 1741 1742 1743 1744 1745 1746 1747 1748 1749 1750 1751 1752 1753 1754 1755 1756 1757 1758 1759 1760 1761 1762 1763 1764 1765 1766
    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
1767 1768 1769 1770 1771 1772 1773 1774
    space.
    <footnote>
     <para>
      This was written in 1994, mind you.  The
      numbers have probably changed, but the problem
      persists.
     </para>
    </footnote>
1775
   </para>
1776 1777
<!-- end re_format.7 man page -->
  </sect2>
1778

1779 1780 1781 1782
 </sect1>


  <sect1 id="functions-formatting">
1783
   <title>Data Type Formatting Functions</title>
1784

1785 1786 1787 1788
   <indexterm zone="functions-formatting">
    <primary>formatting</primary>
   </indexterm>

1789 1790 1791
   <note>
    <title>Author</title>
    <para>
1792
     Written by Karel Zak (<email>zakkr@zf.jcu.cz</email>) on 2000-01-24
1793 1794
    </para>
   </note>
1795

1796
   <para>
1797
    The <productname>PostgreSQL</productname> formatting functions
1798 1799
    provide a powerful set of tools for converting various data types
    (date/time, integer, floating point, numeric) to formatted strings
1800
    and for converting from formatted strings to specific data types.
1801
    These functions all follow a common calling convention: the first
1802
    argument is the value to be formatted and the second argument is a
1803
    template that defines the output or input format.
1804 1805 1806 1807 1808 1809 1810 1811 1812 1813 1814 1815 1816 1817 1818 1819
   </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>
1820 1821 1822 1823
	<entry><function>to_char</function>(<type>timestamp</type>, <type>text</type>)</entry>
	<entry><type>text</type></entry>
	<entry>convert time stamp to string</entry>
	<entry><literal>to_char(timestamp 'now','HH12:MI:SS')</literal></entry>
1824
       </row>
1825
       <row>
1826 1827
	<entry><function>to_char</function>(<type>interval</type>, <type>text</type>)</entry>
	<entry><type>text</type></entry>
1828
	<entry>convert interval to string</entry>
1829
	<entry><literal>to_char(interval '15h 2m 12s','HH24:MI:SS')</literal></entry>
1830
       </row>
1831
       <row>
1832 1833
	<entry><function>to_char</function>(<type>int</type>, <type>text</type>)</entry>
	<entry><type>text</type></entry>
1834
	<entry>convert int4/int8 to string</entry>
1835
	<entry><literal>to_char(125, '999')</literal></entry>
1836 1837
       </row>
       <row>
1838 1839
	<entry><function>to_char</function>(<type>double precision</type>, <type>text</type>)</entry>
	<entry><type>text</type></entry>
1840
	<entry>convert real/double precision to string</entry>
1841
	<entry><literal>to_char(125.8, '999D9')</literal></entry>
1842 1843
       </row>
       <row>
1844 1845
	<entry><function>to_char</function>(<type>numeric</type>, <type>text</type>)</entry>
	<entry><type>text</type></entry>
1846
	<entry>convert numeric to string</entry>
1847
	<entry><literal>to_char(numeric '-125.8', '999D99S')</literal></entry>
1848 1849
       </row>
       <row>
1850 1851
	<entry><function>to_date</function>(<type>text</type>, <type>text</type>)</entry>
	<entry><type>date</type></entry>
1852
	<entry>convert string to date</entry>
1853
	<entry><literal>to_date('05 Dec 2000', 'DD Mon YYYY')</literal></entry>
1854 1855
       </row>
       <row>
1856 1857 1858 1859
	<entry><function>to_timestamp</function>(<type>text</type>, <type>text</type>)</entry>
	<entry><type>timestamp</type></entry>
	<entry>convert string to time stamp</entry>
	<entry><literal>to_timestamp('05 Dec 2000', 'DD Mon YYYY')</literal></entry>
1860 1861
       </row>
       <row>
1862 1863
	<entry><function>to_number</function>(<type>text</type>, <type>text</type>)</entry>
	<entry><type>numeric</type></entry>
1864
	<entry>convert string to numeric</entry>
1865
	<entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
1866 1867 1868 1869 1870 1871
       </row>
      </tbody>
     </tgroup>
    </table>
   </para>

1872 1873 1874 1875
   <para>
    In an output template string, there are certain patterns that are
    recognized and replaced with appropriately-formatted data from the value
    to be formatted.  Any text that is not a template pattern is simply
Peter Eisentraut's avatar
Peter Eisentraut committed
1876
    copied verbatim.  Similarly, in an input template string, template patterns
1877 1878 1879 1880
    identify the parts of the input data string to be looked at and the
    values to be found there.
   </para>

1881 1882
   <para>
    <table tocentry="1">
1883
     <title>Template patterns for date/time conversions</title>
1884 1885 1886
     <tgroup cols="2">
      <thead>
       <row>
1887
	<entry>Pattern</entry>
1888 1889 1890 1891 1892
	<entry>Description</entry>
       </row>
      </thead>
      <tbody>
       <row>
1893
	<entry><literal>HH</literal></entry>
1894
	<entry>hour of day (01-12)</entry>
1895 1896
       </row>
       <row>
1897
	<entry><literal>HH12</literal></entry>
1898
	<entry>hour of day (01-12)</entry>
1899
       </row>       
1900
       <row>
1901
	<entry><literal>HH24</literal></entry>
1902 1903
	<entry>hour of day (00-23)</entry>
       </row>       
1904
       <row>
1905
	<entry><literal>MI</literal></entry>
1906
	<entry>minute (00-59)</entry>
1907 1908
       </row>   
       <row>
1909
	<entry><literal>SS</literal></entry>
1910
	<entry>second (00-59)</entry>
1911
       </row>
1912
       <row>
1913
	<entry><literal>MS</literal></entry>
1914 1915 1916
	<entry>millisecond (000-999)</entry>
       </row>
       <row>
1917
	<entry><literal>US</literal></entry>
1918 1919
	<entry>microsecond (000000-999999)</entry>
       </row>
1920
       <row>
1921
	<entry><literal>SSSS</literal></entry>
1922
	<entry>seconds past midnight (0-86399)</entry>
1923
       </row>
1924
       <row>
1925
	<entry><literal>AM</literal> or <literal>A.M.</literal> or <literal>PM</literal> or <literal>P.M.</literal></entry>
1926 1927 1928
	<entry>meridian indicator (upper case)</entry>
       </row>
       <row>
1929
	<entry><literal>am</literal> or <literal>a.m.</literal> or <literal>pm</literal> or <literal>p.m.</literal></entry>
1930 1931
	<entry>meridian indicator (lower case)</entry>
       </row>
1932
       <row>
1933
	<entry><literal>Y,YYY</literal></entry>
1934
	<entry>year (4 and more digits) with comma</entry>
1935 1936
       </row>
       <row>
1937
	<entry><literal>YYYY</literal></entry>
1938
	<entry>year (4 and more digits)</entry>
1939 1940
       </row>
       <row>
1941
	<entry><literal>YYY</literal></entry>
1942
	<entry>last 3 digits of year</entry>
1943 1944
       </row>
       <row>
1945
	<entry><literal>YY</literal></entry>
1946
	<entry>last 2 digits of year</entry>
1947 1948
       </row>
       <row>
1949
	<entry><literal>Y</literal></entry>
1950
	<entry>last digit of year</entry>
1951
       </row>
1952
       <row>
1953 1954
	<entry><literal>BC</literal> or <literal>B.C.</literal> or <literal>AD</literal> or <literal>A.D.</literal></entry>
	<entry>era indicator (upper case)</entry>
1955 1956
       </row>
       <row>
1957 1958
	<entry><literal>bc</literal> or <literal>b.c.</literal> or <literal>ad</literal> or <literal>a.d.</literal></entry>
	<entry>era indicator (lower case)</entry>
1959
       </row>
1960
       <row>
1961
	<entry><literal>MONTH</literal></entry>
1962
	<entry>full upper case month name (blank-padded to 9 chars)</entry>
1963 1964
       </row>
       <row>
1965
	<entry><literal>Month</literal></entry>
1966
	<entry>full mixed case month name (blank-padded to 9 chars)</entry>
1967 1968
       </row>
       <row>
1969
	<entry><literal>month</literal></entry>
1970
	<entry>full lower case month name (blank-padded to 9 chars)</entry>
1971 1972
       </row>
       <row>
1973
	<entry><literal>MON</literal></entry>
1974
	<entry>abbreviated upper case month name (3 chars)</entry>
1975 1976
       </row>
       <row>
1977
	<entry><literal>Mon</literal></entry>
1978
	<entry>abbreviated mixed case month name (3 chars)</entry>
1979 1980
       </row>
       <row>
1981
	<entry><literal>mon</literal></entry>
1982
	<entry>abbreviated lower case month name (3 chars)</entry>
1983 1984
       </row>
       <row>
1985
	<entry><literal>MM</literal></entry>
1986
	<entry>month number (01-12)</entry>
1987 1988
       </row>
       <row>
1989
	<entry><literal>DAY</literal></entry>
1990
	<entry>full upper case day name (blank-padded to 9 chars)</entry>
1991 1992
       </row>
       <row>
1993
	<entry><literal>Day</literal></entry>
1994
	<entry>full mixed case day name (blank-padded to 9 chars)</entry>
1995 1996
       </row>
       <row>
1997
	<entry><literal>day</literal></entry>
1998
	<entry>full lower case day name (blank-padded to 9 chars)</entry>
1999 2000
       </row>
       <row>
2001
	<entry><literal>DY</literal></entry>
2002
	<entry>abbreviated upper case day name (3 chars)</entry>
2003 2004
       </row>
       <row>
2005
	<entry><literal>Dy</literal></entry>
2006
	<entry>abbreviated mixed case day name (3 chars)</entry>
2007 2008
       </row>
       <row>
2009
	<entry><literal>dy</literal></entry>
2010
	<entry>abbreviated lower case day name (3 chars)</entry>
2011 2012
       </row>
       <row>
2013
	<entry><literal>DDD</literal></entry>
2014
	<entry>day of year (001-366)</entry>
2015 2016
       </row>
       <row>
2017
	<entry><literal>DD</literal></entry>
2018
	<entry>day of month (01-31)</entry>
2019 2020
       </row>
       <row>
2021
	<entry><literal>D</literal></entry>
2022
	<entry>day of week (1-7; SUN=1)</entry>
2023 2024
       </row>
       <row>
2025
	<entry><literal>W</literal></entry>
2026
	<entry>week of month (1-5) where first week start on the first day of the month</entry>
2027 2028
       </row> 
       <row>
2029
	<entry><literal>WW</literal></entry>
2030
	<entry>week number of year (1-53) where first week start on the first day of the year</entry>
2031
       </row>
Bruce Momjian's avatar
Bruce Momjian committed
2032
       <row>
2033
	<entry><literal>IW</literal></entry>
2034
	<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
2035
       </row>
2036
       <row>
2037
	<entry><literal>CC</literal></entry>
2038
	<entry>century (2 digits)</entry>
2039 2040
       </row>
       <row>
2041
	<entry><literal>J</literal></entry>
2042
	<entry>Julian Day (days since January 1, 4712 BC)</entry>
2043 2044
       </row>
       <row>
2045
	<entry><literal>Q</literal></entry>
2046
	<entry>quarter</entry>
2047 2048
       </row>
       <row>
2049
	<entry><literal>RM</literal></entry>
2050
	<entry>month in Roman Numerals (I-XII; I=January) - upper case</entry>
2051 2052
       </row>
       <row>
2053
	<entry><literal>rm</literal></entry>
2054
	<entry>month in Roman Numerals (I-XII; I=January) - lower case</entry>
2055
       </row>
2056
       <row>
2057
	<entry><literal>TZ</literal></entry>
2058
	<entry>timezone name - upper case</entry>
2059 2060
       </row>
       <row>
2061
	<entry><literal>tz</literal></entry>
2062
	<entry>timezone name - lower case</entry>
2063
       </row>
2064 2065 2066 2067 2068 2069
      </tbody>
     </tgroup>
    </table>
   </para>

   <para>
2070 2071 2072 2073
    Certain modifiers may be applied to any template pattern to alter its
    behavior.  For example, <quote><literal>FMMonth</literal></quote>
    is the <quote><literal>Month</literal></quote> pattern with the
    <quote><literal>FM</literal></quote> prefix.
2074 2075 2076 2077
   </para>

   <para>
    <table tocentry="1">
2078
     <title>Template pattern modifiers for date/time conversions</title>
2079 2080 2081
     <tgroup cols="3">
      <thead>
       <row>
2082
	<entry>Modifier</entry>
2083 2084 2085 2086 2087 2088
	<entry>Description</entry>
	<entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
2089 2090
	<entry><literal>FM</literal> prefix</entry>
	<entry>fill mode (suppress padding blanks and zeroes)</entry>
2091
	<entry><literal>FMMonth</literal></entry>
2092 2093
       </row>
       <row>
2094 2095
	<entry><literal>TH</literal> suffix</entry>
	<entry>add upper-case ordinal number suffix</entry>
2096
	<entry><literal>DDTH</literal></entry>
2097 2098
       </row>	
       <row>
2099 2100
	<entry><literal>th</literal> suffix</entry>
	<entry>add lower-case ordinal number suffix</entry>
2101
	<entry><literal>DDth</literal></entry>
2102 2103
       </row>
       <row>
2104
	<entry><literal>FX</literal> prefix</entry>
2105 2106
	<entry>Fixed format global option (see below)</entry>
	<entry><literal>FX Month DD Day</literal></entry>
2107 2108
       </row>	
       <row>
2109
	<entry><literal>SP</literal> suffix</entry>
2110
	<entry>spell mode (not yet implemented)</entry>
2111
	<entry><literal>DDSP</literal></entry>
2112 2113 2114 2115 2116 2117 2118
       </row>       
      </tbody>
     </tgroup>
    </table>
   </para>

   <para>
2119 2120 2121
    Usage notes:

    <itemizedlist>
2122 2123 2124 2125 2126 2127 2128 2129
     <listitem>
      <para>
       <literal>FM</literal> suppresses leading zeroes or trailing blanks
       that would otherwise be added to make the output of a pattern be
       fixed-width.
      </para>
     </listitem>

2130 2131 2132
     <listitem>
      <para>
       <function>to_timestamp</function> and <function>to_date</function>
2133
       skip multiple blank spaces in the input string if the <literal>FX</literal> option 
2134 2135 2136
       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
2137 2138
       <literal>to_timestamp('2000    JUN','FXYYYY MON')</literal> returns an error,
       because <function>to_timestamp</function> expects one blank space only.
2139 2140 2141 2142 2143
      </para>
     </listitem>

     <listitem>
      <para>
2144 2145 2146 2147
       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
2148
       any string constant in <productname>PostgreSQL</productname>.
2149 2150 2151 2152 2153
      </para>
     </listitem>

     <listitem>
      <para>
2154
       Ordinary text is allowed in <function>to_char</function>
2155 2156 2157 2158 2159 2160
       templates and will be output literally.  You can put a substring
       in double quotes to force it to be interpreted as literal text
       even if it contains pattern keywords.  For example, in
       <literal>'"Hello Year: "YYYY'</literal>, the <literal>YYYY</literal>
       will be replaced by year data, but the single <literal>Y</literal>
       will not be.
2161 2162 2163 2164 2165
      </para>
     </listitem>

     <listitem>
      <para>
2166 2167 2168
       If you want to have a double quote in the output you must
       precede it with a backslash, for example <literal>'\\"YYYY
       Month\\"'</literal>. <!-- "" font-lock sanity :-) -->
2169 2170
      </para>
     </listitem>
2171 2172 2173

     <listitem>
      <para>
2174 2175
       <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
       <type>date</type> is restricted if you use a year with more than 4 digits. You must
Peter Eisentraut's avatar
Peter Eisentraut committed
2176
       use some non-digit character or template after <literal>YYYY</literal>,
2177
       otherwise the year is always interpreted as 4 digits. For example
Peter Eisentraut's avatar
Peter Eisentraut committed
2178 2179
       (with year 20000):
       <literal>to_date('200001131', 'YYYYMMDD')</literal> will be 
2180
       interpreted as a 4-digit year; better is to use a non-digit 
Peter Eisentraut's avatar
Peter Eisentraut committed
2181 2182 2183
       separator after the year, like
       <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
       <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
2184 2185
      </para>
     </listitem>
2186 2187 2188

     <listitem>
      <para>
2189
       Millisecond <literal>MS</literal> and microsecond <literal>US</literal>
Peter Eisentraut's avatar
Peter Eisentraut committed
2190 2191
       values in a conversion from string to time stamp are used as part of the
       seconds after the decimal point. For example 
2192
       <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
Peter Eisentraut's avatar
Peter Eisentraut committed
2193 2194 2195 2196 2197 2198 2199 2200 2201 2202
       but 300, because the conversion counts it as 12 + 0.3.
       This means for the format <literal>SS:MS</>, the input values
       <literal>12:3</>, <literal>12:30</>, and <literal>12:300</> specify the
       same number of milliseconds. To get three milliseconds, one must use
       <literal>12:003</>, which the conversion counts as
       12 + 0.003 = 12.003 seconds.
      </para>

      <para>
       Here is a more 
2203 2204
       complex example: 
       <literal>to_timestamp('15:12:02.020.001230','HH:MI:SS.MS.US')</literal>
Peter Eisentraut's avatar
Peter Eisentraut committed
2205 2206
       is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
       1230 microseconds = 2.021230 seconds. 
2207 2208
      </para>
     </listitem>
2209
    </itemizedlist>
2210
   </para>
2211

2212 2213
   <para>
    <table tocentry="1">
2214
     <title>Template patterns for numeric conversions</title>
2215 2216 2217
     <tgroup cols="2">
      <thead>
       <row>
2218
	<entry>Pattern</entry>
2219 2220 2221 2222 2223
	<entry>Description</entry>
       </row>
      </thead>
      <tbody>
       <row>
2224
	<entry><literal>9</literal></entry>
2225
	<entry>value with the specified number of digits</entry>
2226 2227
       </row>
       <row>
2228
	<entry><literal>0</literal></entry>
2229
	<entry>value with leading zeros</entry>
2230 2231
       </row>
       <row>
2232
	<entry><literal>.</literal> (period)</entry>
2233
	<entry>decimal point</entry>
2234 2235
       </row>       
       <row>
2236
	<entry><literal>,</literal> (comma)</entry>
2237
	<entry>group (thousand) separator</entry>
2238 2239
       </row>
       <row>
2240
	<entry><literal>PR</literal></entry>
2241
	<entry>negative value in angle brackets</entry>
2242 2243
       </row>
       <row>
2244
	<entry><literal>S</literal></entry>
2245
	<entry>negative value with minus sign (uses locale)</entry>
2246 2247
       </row>
       <row>
2248
	<entry><literal>L</literal></entry>
2249
	<entry>currency symbol (uses locale)</entry>
2250 2251
       </row>
       <row>
2252
	<entry><literal>D</literal></entry>
2253
	<entry>decimal point (uses locale)</entry>
2254 2255
       </row>
       <row>
2256
	<entry><literal>G</literal></entry>
2257
	<entry>group separator (uses locale)</entry>
2258 2259
       </row>
       <row>
2260
	<entry><literal>MI</literal></entry>
2261
	<entry>minus sign in specified position (if number < 0)</entry>
2262 2263
       </row>
       <row>
2264
	<entry><literal>PL</literal></entry>
2265
	<entry>plus sign in specified position (if number > 0)</entry>
2266 2267
       </row>
       <row>
2268
	<entry><literal>SG</literal></entry>
2269
	<entry>plus/minus sign in specified position</entry>
2270 2271
       </row>
       <row>
2272
	<entry><literal>RN</literal></entry>
2273
	<entry>roman numeral (input between 1 and 3999)</entry>
2274 2275
       </row>
       <row>
2276
	<entry><literal>TH</literal> or <literal>th</literal></entry>
2277
	<entry>convert to ordinal number</entry>
2278 2279
       </row>
       <row>
2280
	<entry><literal>V</literal></entry>
2281
	<entry>shift <replaceable>n</replaceable> digits (see
2282
	 notes)</entry>
2283 2284
       </row>
       <row>
2285
	<entry><literal>EEEE</literal></entry>
Peter Eisentraut's avatar
Peter Eisentraut committed
2286
	<entry>scientific notation (not implemented yet)</entry>
2287 2288 2289 2290 2291 2292 2293
       </row>
      </tbody>
     </tgroup>
    </table>
   </para>

   <para>
2294 2295 2296 2297 2298
    Usage notes:

    <itemizedlist>
     <listitem>
      <para>
Peter Eisentraut's avatar
Peter Eisentraut committed
2299 2300
       A sign formatted using <literal>SG</>, <literal>PL</>, or
       <literal>MI</> is not an anchor in
2301
       the number; for example,
Peter Eisentraut's avatar
Peter Eisentraut committed
2302 2303
       <literal>to_char(-12, 'S9999')</> produces <literal>'  -12'</literal>,
       but <literal>to_char(-12, 'MI9999')</> produces <literal>'-  12'</literal>.
2304 2305
       The Oracle implementation does not allow the use of
       <literal>MI</literal> ahead of <literal>9</literal>, but rather
2306
       requires that <literal>9</literal> precede
2307 2308 2309 2310 2311 2312
       <literal>MI</literal>.
      </para>
     </listitem>

     <listitem>
      <para>
2313 2314 2315
       <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.
2316 2317 2318 2319 2320
      </para>
     </listitem>

     <listitem>
      <para>
2321 2322
       <literal>TH</literal> does not convert values less than zero
       and does not convert decimal numbers.
2323 2324 2325 2326 2327
      </para>
     </listitem>

     <listitem>
      <para>
2328
       <literal>PL</literal>, <literal>SG</literal>, and
2329
       <literal>TH</literal> are <productname>PostgreSQL</productname>
2330
       extensions. 
2331 2332 2333 2334 2335 2336 2337 2338 2339 2340 2341
      </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
2342 2343
       <literal>V</literal> combined with a decimal point.
       (E.g., <literal>99.9V99</literal> is not allowed.)
2344 2345 2346
      </para>
     </listitem>
    </itemizedlist>
2347
   </para>   
2348 2349 2350

   <para>
    <table tocentry="1">
2351
     <title><function>to_char</function> Examples</title>
2352 2353 2354 2355 2356 2357 2358 2359 2360
     <tgroup cols="2">
      <thead>
       <row>
	<entry>Input</entry>
	<entry>Output</entry>
       </row>
      </thead>
      <tbody>
       <row>
2361
        <entry><literal>to_char(now(),'Day, DD  HH12:MI:SS')</literal></entry>
2362
        <entry><literal>'Tuesday  , 06  05:39:18'</literal></entry>
2363
       </row>
2364
       <row>
2365
        <entry><literal>to_char(now(),'FMDay, FMDD  HH12:MI:SS')</literal></entry>
2366
        <entry><literal>'Tuesday, 6  05:39:18'</literal></entry>
2367 2368
       </row>          
       <row>
2369
        <entry><literal>to_char(-0.1,'99.99')</literal></entry>
2370
        <entry><literal>' -.10'</literal></entry>
2371 2372
       </row>
       <row>
2373
        <entry><literal>to_char(-0.1,'FM9.99')</literal></entry>
2374
        <entry><literal>'-.1'</literal></entry>
2375 2376
       </row>
       <row>
2377
        <entry><literal>to_char(0.1,'0.9')</literal></entry>
2378
        <entry><literal>' 0.1'</literal></entry>
2379 2380
       </row>
       <row>
2381
        <entry><literal>to_char(12,'9990999.9')</literal></entry>
2382
        <entry><literal>'    0012.0'</literal></entry>
2383 2384
       </row>
       <row>
2385
        <entry><literal>to_char(12,'FM9990999.9')</literal></entry>
2386
        <entry><literal>'0012'</literal></entry>
2387 2388
       </row>
       <row>
2389
        <entry><literal>to_char(485,'999')</literal></entry>
2390
        <entry><literal>' 485'</literal></entry>
2391 2392
       </row>
       <row>
2393
        <entry><literal>to_char(-485,'999')</literal></entry>
2394
        <entry><literal>'-485'</literal></entry>
2395 2396
       </row>
       <row>
2397
        <entry><literal>to_char(485,'9 9 9')</literal></entry>
2398
        <entry><literal>' 4 8 5'</literal></entry>
2399 2400
       </row>
       <row>
2401
        <entry><literal>to_char(1485,'9,999')</literal></entry>
2402
        <entry><literal>' 1,485'</literal></entry>
2403 2404
       </row>
       <row>
2405
        <entry><literal>to_char(1485,'9G999')</literal></entry>
2406
        <entry><literal>' 1 485'</literal></entry>
2407 2408
       </row>
       <row>
2409
        <entry><literal>to_char(148.5,'999.999')</literal></entry>
2410
        <entry><literal>' 148.500'</literal></entry>
2411 2412
       </row>
       <row>
2413
        <entry><literal>to_char(148.5,'999D999')</literal></entry>
2414
        <entry><literal>' 148,500'</literal></entry>	 
2415 2416
       </row>
       <row>
2417
        <entry><literal>to_char(3148.5,'9G999D999')</literal></entry>
2418
        <entry><literal>' 3 148,500'</literal></entry>
2419 2420
       </row>
       <row>
2421
        <entry><literal>to_char(-485,'999S')</literal></entry>
2422
        <entry><literal>'485-'</literal></entry>
2423 2424
       </row>
       <row>		
2425
        <entry><literal>to_char(-485,'999MI')</literal></entry>
2426
        <entry><literal>'485-'</literal></entry>	
2427 2428
       </row>
       <row>
2429
        <entry><literal>to_char(485,'999MI')</literal></entry>
2430
        <entry><literal>'485'</literal></entry>		
2431 2432
       </row>
       <row>
2433
        <entry><literal>to_char(485,'PL999')</literal></entry>
2434
        <entry><literal>'+485'</literal></entry>	
2435 2436
       </row>
       <row>		
2437
        <entry><literal>to_char(485,'SG999')</literal></entry>
2438
        <entry><literal>'+485'</literal></entry>	
2439 2440
       </row>
       <row>
2441
        <entry><literal>to_char(-485,'SG999')</literal></entry>
2442
        <entry><literal>'-485'</literal></entry>	
2443 2444
       </row>
       <row>
2445
        <entry><literal>to_char(-485,'9SG99')</literal></entry>
2446
        <entry><literal>'4-85'</literal></entry>	
2447 2448
       </row>
       <row>
2449
        <entry><literal>to_char(-485,'999PR')</literal></entry>
2450
        <entry><literal>'&lt;485&gt;'</literal></entry>		
2451 2452
       </row>
       <row>
2453
        <entry><literal>to_char(485,'L999')</literal></entry>
2454
        <entry><literal>'DM 485</literal></entry>	 
2455 2456
       </row>
       <row>
2457
        <entry><literal>to_char(485,'RN')</literal></entry>		
2458
        <entry><literal>'        CDLXXXV'</literal></entry>
2459 2460
       </row>
       <row>
2461
        <entry><literal>to_char(485,'FMRN')</literal></entry>	
2462
        <entry><literal>'CDLXXXV'</literal></entry>
2463 2464
       </row>
       <row>
2465
        <entry><literal>to_char(5.2,'FMRN')</literal></entry>
2466
        <entry><literal>V</literal></entry>		
2467 2468
       </row>
       <row>
2469
        <entry><literal>to_char(482,'999th')</literal></entry>
2470
        <entry><literal>' 482nd'</literal></entry>				
2471 2472
       </row>
       <row>
2473
        <entry><literal>to_char(485, '"Good number:"999')</literal></entry>
2474
        <entry><literal>'Good number: 485'</literal></entry>
2475 2476
       </row>
       <row>
2477
        <entry><literal>to_char(485.8,'"Pre:"999" Post:" .999')</literal></entry>
2478
        <entry><literal>'Pre: 485 Post: .800'</literal></entry>
2479 2480
       </row>
       <row>
2481
        <entry><literal>to_char(12,'99V999')</literal></entry>		
2482
        <entry><literal>' 12000'</literal></entry>
2483 2484
       </row>
       <row>
2485
        <entry><literal>to_char(12.4,'99V999')</literal></entry>
2486
        <entry><literal>' 12400'</literal></entry>
2487 2488
       </row>
       <row>		
2489
        <entry><literal>to_char(12.45, '99V9')</literal></entry>
2490
        <entry><literal>' 125'</literal></entry>
2491 2492 2493 2494 2495 2496 2497 2498
       </row>
      </tbody>
     </tgroup>
    </table>
   </para>
  </sect1>


2499
  <sect1 id="functions-datetime">
2500
   <title>Date/Time Functions and Operators</title>
2501

2502
   <para>
2503
    <xref linkend="functions-datetime-table"> shows the available
2504 2505 2506 2507 2508
    functions for date/time value processing.  
    <xref linkend="operators-datetime-table"> illustrates the
    behaviors of the basic arithmetic
    operators (<literal>+</literal>, <literal>*</literal>, etc.).
    For formatting functions, refer to <xref
2509 2510 2511
    linkend="functions-formatting">.  You should be familiar with the
    background information on date/time data types (see <xref
    linkend="datatype-datetime">).
2512
   </para>
2513

2514 2515 2516 2517 2518 2519 2520
   <para>
    The date/time operators described below behave similarly for types
    involving time zones as well as those without.

    <table id="operators-datetime-table">
     <title>Date/Time Operators</title>

2521
     <tgroup cols="3">
2522 2523 2524 2525 2526 2527 2528 2529 2530 2531
      <thead>
       <row>
        <entry>Name</entry>
        <entry>Example</entry>
        <entry>Result</entry>
       </row>
      </thead>

      <tbody>
       <row>
2532
        <entry> <literal>+</literal> </entry>
2533 2534 2535 2536 2537
        <entry><type>timestamp</type> '2001-09-28 01:00' + <type>interval</type> '23 hours'</entry>
        <entry><type>timestamp</type> '2001-09-29 00:00'</entry>
       </row>

       <row>
2538
        <entry> <literal>+</literal> </entry>
2539 2540 2541 2542 2543
        <entry><type>date</type> '2001-09-28' + <type>interval</type> '1 hour'</entry>
        <entry><type>timestamp</type> '2001-09-28 01:00'</entry>
       </row>

       <row>
2544
        <entry> <literal>+</literal> </entry>
2545 2546 2547 2548 2549
        <entry><type>time</type> '01:00' + <type>interval</type> '3 hours'</entry>
        <entry><type>time</type> '04:00'</entry>
       </row>

       <row>
2550
        <entry> <literal>-</literal> </entry>
2551 2552 2553 2554 2555
        <entry><type>timestamp</type> '2001-09-28 23:00' - <type>interval</type> '23 hours'</entry>
        <entry><type>timestamp</type> '2001-09-28'</entry>
       </row>

       <row>
2556
        <entry> <literal>-</literal> </entry>
2557 2558 2559 2560 2561
        <entry><type>date</type> '2001-09-28' + <type>interval</type> '1 hour'</entry>
        <entry><type>timestamp</type> '2001-09-27 23:00'</entry>
       </row>

       <row>
2562
        <entry> <literal>-</literal> </entry>
2563 2564 2565 2566 2567
        <entry><type>time</type> '05:00' + <type>interval</type> '2 hours'</entry>
        <entry><type>time</type> '03:00'</entry>
       </row>

       <row>
2568
        <entry> <literal>-</literal> </entry>
2569 2570 2571 2572 2573 2574 2575 2576 2577 2578 2579 2580 2581 2582 2583 2584 2585 2586 2587 2588 2589 2590 2591 2592
        <entry><type>interval</type> '2 hours' - <type>time</type> '05:00'</entry>
        <entry><type>time</type> '03:00:00'</entry>
       </row>

       <row>
        <entry> <literal>*</literal> </entry>
        <entry><type>interval</type> '1 hour' * <type>int</type> '3'</entry>
        <entry><type>interval</type> '03:00'</entry>
       </row>

       <row>
        <entry> <literal>/</literal> </entry>
        <entry><type>interval</type> '1 hour' / <type>int</type> '3'</entry>
        <entry><type>interval</type> '00:20'</entry>
       </row>
      </tbody>
     </tgroup>
    </table>
   </para>

   <para>
    The date/time functions are summarized below, with additional
    details in subsequent sections.

2593
    <table id="functions-datetime-table">
2594
     <title>Date/Time Functions</title>
2595
     <tgroup cols="5">
2596 2597
      <thead>
       <row>
2598 2599
	<entry>Name</entry>
	<entry>Return Type</entry>
2600 2601
	<entry>Description</entry>
	<entry>Example</entry>
2602
	<entry>Result</entry>
2603 2604
       </row>
      </thead>
2605

2606 2607
      <tbody>
       <row>
2608 2609
	<entry><function>age</function>(<type>timestamp</type>)</entry>
	<entry><type>interval</type></entry>
2610
	<entry>Subtract from today</entry>
2611 2612
	<entry><literal>age(timestamp '1957-06-13')</literal></entry>
	<entry><literal>43 years 8 mons 3 days</literal></entry>
2613
       </row>
2614

2615
       <row>
2616 2617
	<entry><function>age</function>(<type>timestamp</type>, <type>timestamp</type>)</entry>
	<entry><type>interval</type></entry>
2618
	<entry>Subtract arguments</entry>
2619 2620
	<entry><literal>age('2001-04-10', timestamp '1957-06-13')</literal></entry>
	<entry><literal>43 years 9 mons 27 days</literal></entry>
2621 2622 2623
       </row>

       <row>
2624 2625
	<entry><function>current_date</function></entry>
	<entry><type>date</type></entry>
2626
	<entry>Today's date; see <link
2627 2628 2629 2630
	 linkend="functions-datetime-current">below</link>
	</entry>
	<entry></entry>
	<entry></entry>
2631
       </row>
2632 2633

       <row>
2634 2635
	<entry><function>current_time</function></entry>
	<entry><type>time</type></entry>
2636
	<entry>Time of day; see <link
2637 2638 2639 2640 2641 2642
	 linkend="functions-datetime-current">below</link>
	</entry>
	<entry></entry>
	<entry></entry>
       </row>

2643
       <row>
2644 2645
	<entry><function>current_timestamp</function></entry>
	<entry><type>timestamp</type></entry>
2646
	<entry>date and time; see also <link
2647 2648 2649 2650 2651 2652 2653
	 linkend="functions-datetime-current">below</link>
	</entry>
	<entry></entry>
	<entry></entry>
       </row>

       <row>
2654 2655
	<entry><function>date_part</function>(<type>text</type>, <type>timestamp</type>)</entry>
	<entry><type>double precision</type></entry>
2656
	<entry>Get subfield (equivalent to
2657 2658 2659
	 <function>extract</function>); see also <link
	 linkend="functions-datetime-datepart">below</link>
        </entry>
2660 2661
	<entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
	<entry><literal>20</literal></entry>
2662
       </row>
2663

2664
       <row>
2665 2666
	<entry><function>date_part</function>(<type>text</type>, <type>interval</type>)</entry>
	<entry><type>double precision</type></entry>
2667
	<entry>Get subfield (equivalent to
2668 2669 2670
	 <function>extract</function>); see also <link
	 linkend="functions-datetime-datepart">below</link>
        </entry>
2671 2672
	<entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
	<entry><literal>3</literal></entry>
2673
       </row>
2674

2675
       <row>
2676 2677
	<entry><function>date_trunc</function>(<type>text</type>, <type>timestamp</type>)</entry>
	<entry><type>timestamp</type></entry>
2678
	<entry>Truncate to specified precision; see also <link
2679 2680
         linkend="functions-datetime-trunc">below</link>
        </entry>
2681 2682
	<entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
	<entry><literal>2001-02-16 20:00:00+00</literal></entry>
2683
       </row>
2684

2685
       <row>
2686 2687
	<entry><function>extract</function>(<parameter>field</parameter> from <type>timestamp</type>)</entry>
	<entry><type>double precision</type></entry>
2688
	<entry>Get subfield; see also <link
2689 2690
         linkend="functions-datetime-extract">below</link>
        </entry>
2691 2692
	<entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
	<entry><literal>20</literal></entry>
2693
       </row>
2694 2695

       <row>
2696 2697
	<entry><function>extract</function>(<parameter>field</parameter> from <type>interval</type>)</entry>
	<entry><type>double precision</type></entry>
2698
	<entry>Get subfield; see also <link
2699 2700
         linkend="functions-datetime-extract">below</link>
        </entry>
2701 2702
	<entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
	<entry><literal>3</literal></entry>
2703 2704
       </row>

2705
       <row>
2706 2707
	<entry><function>isfinite</function>(<type>timestamp</type>)</entry>
	<entry><type>boolean</type></entry>
2708
	<entry>Test for finite time stamp (neither invalid nor infinity)</entry>
2709 2710
	<entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
	<entry><literal>true</literal></entry>
2711
       </row>
2712

2713
       <row>
2714 2715
	<entry><function>isfinite</function>(<type>interval</type>)</entry>
	<entry><type>boolean</type></entry>
2716
	<entry>Test for finite interval</entry>
2717 2718
	<entry><literal>isfinite(interval '4 hours')</literal></entry>
	<entry><literal>true</literal></entry>
2719
       </row>
2720

2721
       <row>
2722 2723
	<entry><function>now</function>()</entry>
	<entry><type>timestamp</type></entry>
2724
	<entry>Current date and time (equivalent to
2725 2726 2727 2728 2729
	 <function>current_timestamp</function>); see also <link
	 linkend="functions-datetime-current">below</link>
	</entry>
	<entry></entry>
	<entry></entry>
2730
       </row>
2731

2732
       <row>
2733 2734
	<entry><function>timeofday()</function></entry>
	<entry><type>text</type></entry>
2735
	<entry>Current date and time; see <link
2736 2737
	 linkend="functions-datetime-current">below</link>
	</entry>
2738 2739
	<entry><literal>timeofday()</literal></entry>
	<entry><literal>Wed Feb 21 17:01:13.000126 2001 EST</literal></entry>
2740 2741
       </row>

2742
       <row>
2743 2744 2745 2746 2747
	<entry><function>timestamp</function>(<type>date</type>)</entry>
	<entry><type>timestamp</type></entry>
	<entry><type>date</type> to <type>timestamp</type></entry>
	<entry><literal>timestamp(date '2000-12-25')</literal></entry>
	<entry><literal>2000-12-25 00:00:00</literal></entry>
2748
       </row>
2749

2750
       <row>
2751 2752 2753 2754 2755
	<entry><function>timestamp</function>(<type>date</type>, <type>time</type>)</entry>
	<entry><type>timestamp</type></entry>
	<entry><type>date</type> and <type>time</type> to <type>timestamp</type></entry>
	<entry><literal>timestamp(date '1998-02-24',time '23:07')</literal></entry>
	<entry><literal>1998-02-24 23:07:00</literal></entry>
2756 2757 2758 2759
       </row>
      </tbody>
     </tgroup>
    </table>
2760
   </para>
2761 2762 2763 2764 2765 2766 2767 2768 2769 2770 2771 2772 2773 2774 2775

  <sect2 id="functions-datetime-extract">
   <title><function>EXTRACT</function>, <function>date_part</function></title>

<synopsis>
EXTRACT (<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
</synopsis>

   <para>
    The <function>extract</function> function retrieves sub-fields
    from date/time values, such as year or hour.
    <replaceable>source</replaceable> is a value expression that
    evaluates to type <type>timestamp</type> or <type>interval</type>.
    (Expressions of type <type>date</type> or <type>time</type> will
    be cast to <type>timestamp</type> and can therefore be used as
2776 2777
    well.)  <replaceable>field</replaceable> is an identifier or
    string that selects what field to extract from the source value.
2778 2779 2780 2781 2782 2783 2784
    The <function>extract</function> function returns values of type
    <type>double precision</type>.
    The following are valid values:

    <!-- alphabetical -->
    <variablelist>
     <varlistentry>
2785
      <term><literal>century</literal></term>
2786 2787 2788 2789 2790 2791 2792 2793 2794 2795 2796 2797 2798
      <listitem>
       <para>
        The year field divided by 100
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
</screen>
       </informalexample>

       <para>
2799 2800 2801
        Note that the result for the century field is simply the year field
        divided by 100, and not the conventional definition which puts most
        years in the 1900's in the twentieth century.
2802 2803 2804 2805 2806
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
2807
      <term><literal>day</literal></term>
2808 2809 2810 2811 2812 2813 2814 2815 2816 2817 2818 2819 2820 2821 2822
      <listitem>
       <para>
        The day (of the month) field (1 - 31)
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>

     <varlistentry>
2823
      <term><literal>decade</literal></term>
2824 2825 2826 2827 2828 2829 2830 2831 2832 2833 2834 2835 2836 2837 2838
      <listitem>
       <para>
        The year field divided by 10
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>

     <varlistentry>
2839
      <term><literal>dow</literal></term>
2840 2841 2842 2843 2844 2845 2846 2847 2848 2849 2850 2851 2852 2853 2854 2855
      <listitem>
       <para>
        The day of the week (0 - 6; Sunday is 0) (for
        <type>timestamp</type> values only)
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>

     <varlistentry>
2856
      <term><literal>doy</literal></term>
2857 2858 2859 2860 2861 2862 2863 2864 2865 2866 2867 2868 2869 2870
      <listitem>
       <para>
        The day of the year (1 - 365/366) (for <type>timestamp</type> values only)
       </para>
       <informalexample>
<screen>
SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>

     <varlistentry>
2871
      <term><literal>epoch</literal></term>
2872 2873 2874
      <listitem>
       <para>
        For <type>date</type> and <type>timestamp</type> values, the
2875
        number of seconds since 1970-01-01 00:00:00-00 (Result may be
2876 2877 2878 2879 2880 2881 2882 2883 2884 2885 2886 2887 2888 2889 2890 2891 2892
        negative.); for <type>interval</type> values, the total number
        of seconds in the interval
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(EPOCH FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>982352320</computeroutput>

SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
<lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>

     <varlistentry>
2893
      <term><literal>hour</literal></term>
2894 2895 2896 2897 2898 2899 2900 2901 2902 2903 2904 2905 2906 2907 2908
      <listitem>
       <para>
        The hour field (0 - 23)
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>

     <varlistentry>
2909
      <term><literal>microseconds</literal></term>
2910 2911 2912 2913 2914 2915 2916 2917 2918 2919 2920 2921 2922 2923 2924 2925
      <listitem>
       <para>
        The seconds field, including fractional parts, multiplied by 1
        000 000.  Note that this includes full seconds.
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
<lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>

     <varlistentry>
2926
      <term><literal>millennium</literal></term>
2927 2928 2929 2930 2931 2932 2933 2934 2935 2936 2937 2938 2939
      <listitem>
       <para>
        The year field divided by 1000
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
</screen>
       </informalexample>

       <para>
2940 2941 2942
        Note that the result for the millennium field is simply the year field
        divided by 1000, and not the conventional definition which puts
        years in the 1900's in the second millennium.
2943 2944 2945 2946 2947
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
2948
      <term><literal>milliseconds</literal></term>
2949 2950 2951 2952 2953 2954 2955 2956 2957 2958 2959 2960 2961 2962 2963 2964
      <listitem>
       <para>
        The seconds field, including fractional parts, multiplied by
        1000.  Note that this includes full seconds.
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
<lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>

     <varlistentry>
2965
      <term><literal>minute</literal></term>
2966 2967 2968 2969 2970 2971 2972 2973 2974 2975 2976 2977 2978 2979 2980
      <listitem>
       <para>
        The minutes field (0 - 59)
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>

     <varlistentry>
2981
      <term><literal>month</literal></term>
2982 2983 2984 2985 2986 2987 2988 2989 2990 2991 2992 2993 2994 2995 2996 2997 2998 2999 3000 3001 3002 3003 3004
      <listitem>
       <para>
        For <type>timestamp</type> values, the number of the month
        within the year (1 - 12) ; for <type>interval</type> values
        the number of months, modulo 12 (0 - 11)
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>

SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
<lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>

SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>

     <varlistentry>
3005
      <term><literal>quarter</literal></term>
3006 3007 3008 3009 3010 3011 3012 3013 3014 3015 3016 3017 3018 3019 3020 3021
      <listitem>
       <para>
        The quarter of the year (1 - 4) that the day is in (for
        <type>timestamp</type> values only)
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>

     <varlistentry>
3022
      <term><literal>second</literal></term>
3023 3024 3025 3026 3027 3028 3029 3030 3031 3032 3033 3034 3035 3036 3037 3038 3039 3040
      <listitem>
       <para>
        The seconds field, including fractional parts (0 -
        59<footnote><simpara>60 if leap seconds are
        implemented by the operating system</simpara></footnote>)
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>

SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
<lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>
3041 3042 3043 3044 3045 3046 3047 3048 3049 3050 3051 3052 3053 3054 3055 3056 3057 3058 3059 3060 3061 3062 3063 3064 3065 3066 3067 3068
<!--
     <varlistentry>
      <term><literal>timezone</literal></term>
      <listitem>
       <para>
        The time zone offset. XXX But in what units?
       </para>
      </listitem>
     </varlistentry>
-->

     <varlistentry>
      <term><literal>timezone_hour</literal></term>
      <listitem>
       <para>
        The hour component of the time zone offset.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>timezone_minute</literal></term>
      <listitem>
       <para>
        The minute component of the time zone offset.
       </para>
      </listitem>
     </varlistentry>
3069 3070

     <varlistentry>
3071
      <term><literal>week</literal></term>
3072 3073 3074 3075 3076 3077 3078 3079 3080 3081 3082 3083 3084 3085 3086 3087 3088 3089 3090 3091
      <listitem>
       <para>
        From a <type>timestamp</type> value, calculate the number of
        the week of the year that the day is in.  By definition
        (<acronym>ISO</acronym> 8601), the first week of a year
        contains January 4 of that year.  (The <acronym>ISO</acronym>
        week starts on Monday.)  In other words, the first Thursday of
        a year is in week 1 of that year.
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>

     <varlistentry>
3092
      <term><literal>year</literal></term>
3093 3094 3095 3096 3097 3098 3099 3100 3101 3102 3103 3104 3105 3106 3107 3108
      <listitem>
       <para>
        The year field
       </para>

       <informalexample>
<screen>
SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
</screen>
       </informalexample>
      </listitem>
     </varlistentry>

    </variablelist>

3109 3110 3111
   </para>

   <para>
3112 3113 3114
    The <function>extract</function> function is primarily intended
    for computational processing.  For formatting date/time values for
    display, see <xref linkend="functions-formatting">.
3115
   </para>
3116 3117 3118

   <anchor id="functions-datetime-datepart">
   <para>
3119 3120
    The <function>date_part</function> function is modeled on the traditional
    <productname>Ingres</productname> equivalent to the
3121 3122 3123 3124 3125 3126 3127 3128 3129 3130 3131 3132 3133 3134 3135
    <acronym>SQL</acronym>-function <function>extract</function>:
<synopsis>
date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
</synopsis>
    Note that here the <replaceable>field</replaceable> value needs to
    be a string.  The valid field values for
    <function>date_part</function> are the same as for
    <function>extract</function>.
   </para>

   <informalexample>
<screen>
SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>

Tatsuo Ishii's avatar
Tatsuo Ishii committed
3136
SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
3137 3138 3139 3140 3141 3142 3143 3144 3145 3146 3147 3148 3149 3150 3151 3152 3153 3154 3155 3156 3157 3158 3159 3160 3161 3162 3163 3164 3165 3166 3167 3168 3169 3170 3171 3172 3173 3174 3175 3176 3177 3178 3179 3180 3181 3182 3183 3184 3185 3186 3187 3188 3189 3190 3191 3192 3193 3194 3195 3196
<lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
</screen>
   </informalexample>

  </sect2>

  <sect2 id="functions-datetime-trunc">
   <title><function>date_trunc</function></title>

   <para>
    The function <function>date_trunc</function> is conceptually
    similar to the <function>trunc</function> function for numbers.
   </para>

   <para>
<synopsis>
date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
</synopsis>
    <replaceable>source</replaceable> is a value expression of type
    <type>timestamp</type> (values of type <type>date</type> and
    <type>time</type> are cast automatically).
    <replaceable>field</replaceable> selects to which precision to
    truncate the time stamp value.  The return value is of type
    <type>timestamp</type> with all fields that are less than the
    selected one set to zero (or one, for day and month).
   </para>

   <para>
    Valid values for <replaceable>field</replaceable> are:
    <simplelist>
     <member>microseconds</member>
     <member>milliseconds</member>
     <member>second</member>
     <member>minute</member>
     <member>hour</member>
     <member>day</member>
     <member>month</member>
     <member>year</member>
     <member>decade</member>
     <member>century</member>
     <member>millennium</member>
    </simplelist>
   </para>

   <informalexample>
    <para>
<screen>
SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00+00</computeroutput>

SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00+00</computeroutput>
</screen>
    </para>
   </informalexample>
  </sect2>

  <sect2 id="functions-datetime-current">
   <title>Current Date/Time</title>

3197 3198 3199 3200 3201 3202 3203 3204 3205 3206
   <indexterm>
    <primary>date</primary>
    <secondary>current</secondary>
   </indexterm>

   <indexterm>
    <primary>time</primary>
    <secondary>current</secondary>
   </indexterm>

3207
   <para>
3208 3209
    The following functions are available to obtain the current date and/or
    time:
3210 3211
<synopsis>
CURRENT_DATE
3212
CURRENT_TIME
3213
CURRENT_TIMESTAMP
3214 3215
CURRENT_TIME ( <replaceable>precision</> )
CURRENT_TIMESTAMP ( <replaceable>precision</> )
3216
</synopsis>
3217 3218 3219 3220 3221
    <function>CURRENT_TIME</function> and
    <function>CURRENT_TIMESTAMP</function> can optionally be given
    a precision parameter, which causes the result to be rounded
    to that many fractional digits.  Without a precision parameter,
    the result is given to full available precision.
3222 3223
   </para>

3224 3225 3226 3227 3228 3229 3230 3231 3232 3233 3234 3235 3236 3237 3238 3239 3240 3241
   <note>
    <para>
     Prior to <productname>PostgreSQL</> 7.2, the precision parameters
     were unimplemented, and the result was always given in integer
     seconds.
    </para>
   </note>

   <note>
    <para>
     The <acronym>SQL99</acronym> standard requires these functions to
     be written without any parentheses, unless a precision parameter
     is given.  As of <productname>PostgreSQL</> 7.2, an empty pair of
     parentheses can be written, but this is deprecated and may be
     removed in a future release.
    </para>
   </note>

3242 3243 3244
   <informalexample>
<screen>
SELECT CURRENT_TIME;
3245
<computeroutput>14:39:53.662522-05</computeroutput>
3246 3247

SELECT CURRENT_DATE;
3248
<computeroutput>2001-12-23</computeroutput>
3249 3250

SELECT CURRENT_TIMESTAMP;
3251 3252 3253 3254
<computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>

SELECT CURRENT_TIMESTAMP(2);
<computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
3255 3256 3257 3258 3259
</screen>
   </informalexample>

   <para>
    The function <function>now()</function> is the traditional
3260
    <productname>PostgreSQL</productname> equivalent to
3261
    <function>CURRENT_TIMESTAMP</function>.
3262 3263 3264
   </para>

   <para>
3265 3266
    There is also <function>timeofday()</function>, which for historical
    reasons returns a text string rather than a <type>timestamp</type> value:
3267 3268 3269 3270 3271 3272 3273 3274 3275 3276 3277 3278 3279 3280 3281 3282 3283 3284
   </para>

   <informalexample>
<screen>
SELECT timeofday();
 Sat Feb 17 19:07:32.000126 2001 EST
</screen>
   </informalexample>

   <para>
    It is quite important to realize that
    <function>CURRENT_TIMESTAMP</function> and related functions all return
    the time as of the start of the current transaction; their values do not
    increment while a transaction is running.  But
    <function>timeofday()</function> returns the actual current time.
   </para>

   <para>
3285
    All the date/time data types also accept the special literal value
3286 3287
    <literal>now</> to specify the current date and time.  Thus,
    the following three all return the same result:
3288 3289 3290 3291 3292 3293 3294 3295
<programlisting>
SELECT CURRENT_TIMESTAMP;
SELECT now();
SELECT TIMESTAMP 'now';
</programlisting>
    <note>
     <para>
      You do not want to use the third form when specifying a DEFAULT
3296
      value while creating a table.  The system will convert <literal>now</>
3297
      to a <type>timestamp</type> as soon as the constant is parsed, so that when
3298
      the default value is needed,
3299 3300
      the time of the table creation would be used!  The first two
      forms will not be evaluated until the default value is used,
3301 3302
      because they are function calls.  Thus they will give the desired
      behavior of defaulting to the time of row insertion.
3303 3304 3305 3306 3307
     </para>
    </note>
   </para>
  </sect2>
 </sect1>
3308 3309 3310 3311 3312 3313

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

   <para>
3314 3315 3316 3317
    The geometric types <type>point</type>, <type>box</type>,
    <type>lseg</type>, <type>line</type>, <type>path</type>,
    <type>polygon</type>, and <type>circle</type> have a large set of
    native support functions and operators.
3318 3319 3320 3321 3322 3323 3324 3325 3326 3327 3328 3329 3330 3331 3332 3333
   </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>
3334
	<ENTRY><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></ENTRY>
3335 3336 3337 3338
       </ROW>
       <ROW>
	<ENTRY> - </ENTRY>
	<ENTRY>Translation</ENTRY>
3339
	<ENTRY><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></ENTRY>
3340 3341 3342 3343
       </ROW>
       <ROW>
	<ENTRY> * </ENTRY>
	<ENTRY>Scaling/rotation</ENTRY>
3344
	<ENTRY><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></ENTRY>
3345 3346 3347 3348
       </ROW>
       <ROW>
	<ENTRY> / </ENTRY>
	<ENTRY>Scaling/rotation</ENTRY>
3349
	<ENTRY><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></ENTRY>
3350 3351 3352 3353
       </ROW>
       <ROW>
	<ENTRY> # </ENTRY>
	<ENTRY>Intersection</ENTRY>
3354
	<ENTRY><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></ENTRY>
3355 3356 3357 3358
       </ROW>
       <ROW>
	<ENTRY> # </ENTRY>
	<ENTRY>Number of points in polygon</ENTRY>
3359
	<ENTRY><literal># '((1,0),(0,1),(-1,0))'</literal></ENTRY>
3360 3361 3362 3363
       </ROW>
       <ROW>
	<ENTRY> ## </ENTRY>
	<ENTRY>Point of closest proximity</ENTRY>
3364
	<ENTRY><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></ENTRY>
3365 3366 3367 3368
       </ROW>
       <ROW>
	<ENTRY> &amp;&amp; </ENTRY>
	<ENTRY>Overlaps?</ENTRY>
3369
	<ENTRY><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></ENTRY>
3370 3371 3372 3373
       </ROW>
       <ROW>
	<ENTRY> &amp;&lt; </ENTRY>
	<ENTRY>Overlaps to left?</ENTRY>
3374
	<ENTRY><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></ENTRY>
3375 3376 3377 3378
       </ROW>
       <ROW>
	<ENTRY> &amp;&gt; </ENTRY>
	<ENTRY>Overlaps to right?</ENTRY>
3379
	<ENTRY><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></ENTRY>
3380 3381 3382 3383
       </ROW>
       <ROW>
	<ENTRY> &lt;-&gt; </ENTRY>
	<ENTRY>Distance between</ENTRY>
3384
	<ENTRY><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></ENTRY>
3385 3386 3387 3388
       </ROW>
       <ROW>
	<ENTRY> &lt;&lt; </ENTRY>
	<ENTRY>Left of?</ENTRY>
3389
	<ENTRY><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></ENTRY>
3390 3391 3392 3393
       </ROW>
       <ROW>
	<ENTRY> &lt;^ </ENTRY>
	<ENTRY>Is below?</ENTRY>
3394
	<ENTRY><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></ENTRY>
3395 3396 3397 3398
       </ROW>
       <ROW>
	<ENTRY> &gt;&gt; </ENTRY>
	<ENTRY>Is right of?</ENTRY>
3399
	<ENTRY><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></ENTRY>
3400 3401 3402 3403
       </ROW>
       <ROW>
	<ENTRY> &gt;^ </ENTRY>
	<ENTRY>Is above?</ENTRY>
3404
	<ENTRY><literal>circle '((0,5),1)' >^ circle '((0,0),1)'</literal></ENTRY>
3405 3406 3407 3408
       </ROW>
       <ROW>
	<ENTRY> ?# </ENTRY>
	<ENTRY>Intersects or overlaps</ENTRY>
3409
	<ENTRY><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></ENTRY>
3410 3411 3412 3413
       </ROW>
       <ROW>
	<ENTRY> ?- </ENTRY>
	<ENTRY>Is horizontal?</ENTRY>
3414
	<ENTRY><literal>point '(1,0)' ?- point '(0,0)'</literal></ENTRY>
3415 3416 3417 3418
       </ROW>
       <ROW>
	<ENTRY> ?-| </ENTRY>
	<ENTRY>Is perpendicular?</ENTRY>
3419
	<ENTRY><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></ENTRY>
3420 3421 3422 3423
       </ROW>
       <ROW>
	<ENTRY> @-@  </ENTRY>
	<ENTRY>Length or circumference</ENTRY>
3424
	<ENTRY><literal>@-@ path '((0,0),(1,0))'</literal></ENTRY>
3425 3426 3427 3428
       </ROW>
       <ROW>
	<ENTRY> ?| </ENTRY>
	<ENTRY>Is vertical?</ENTRY>
3429
	<ENTRY><literal>point '(0,1)' ?| point '(0,0)'</literal></ENTRY>
3430 3431 3432 3433
       </ROW>
       <ROW>
	<ENTRY> ?|| </ENTRY>
	<ENTRY>Is parallel?</ENTRY>
3434
	<ENTRY><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></ENTRY>
3435 3436 3437 3438
       </ROW>
       <ROW>
	<ENTRY> @ </ENTRY>
	<ENTRY>Contained or on</ENTRY>
3439
	<ENTRY><literal>point '(1,1)' @ circle '((0,0),2)'</literal></ENTRY>
3440 3441 3442 3443
       </ROW>
       <ROW>
	<ENTRY> @@ </ENTRY>
	<ENTRY>Center of</ENTRY>
3444
	<ENTRY><literal>@@ circle '((0,0),10)'</literal></ENTRY>
3445 3446 3447 3448
       </ROW>
       <ROW>
	<ENTRY> ~= </ENTRY>
	<ENTRY>Same as</ENTRY>
3449
	<ENTRY><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></ENTRY>
3450 3451 3452 3453 3454 3455
       </ROW>
      </TBODY>
     </TGROUP>
   </TABLE>

   <table>
3456 3457 3458 3459 3460 3461 3462 3463 3464 3465 3466 3467
     <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>
3468 3469
	<entry><function>area</function>(object)</entry>
	<entry><type>double precision</type></entry>
3470
	<entry>area of item</entry>
3471
	<entry><literal>area(box '((0,0),(1,1))')</literal></entry>
3472 3473
       </row>
       <row>
3474 3475
	<entry><function>box</function>(box, box)</entry>
	<entry><type>box</type></entry>
3476
	<entry>intersection box</entry>
3477
	<entry><literal>box(box '((0,0),(1,1))',box '((0.5,0.5),(2,2))')</literal></entry>
3478 3479
       </row>
       <row>
3480 3481
	<entry><function>center</function>(object)</entry>
	<entry><type>point</type></entry>
3482
	<entry>center of item</entry>
3483
	<entry><literal>center(box '((0,0),(1,2))')</literal></entry>
3484 3485
       </row>
       <row>
3486 3487
	<entry><function>diameter</function>(circle)</entry>
	<entry><type>double precision</type></entry>
3488
	<entry>diameter of circle</entry>
3489
	<entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
3490 3491
       </row>
       <row>
3492 3493
	<entry><function>height</function>(box)</entry>
	<entry><type>double precision</type></entry>
3494
	<entry>vertical size of box</entry>
3495
	<entry><literal>height(box '((0,0),(1,1))')</literal></entry>
3496 3497
       </row>
       <row>
3498 3499
	<entry><function>isclosed</function>(path)</entry>
	<entry><type>boolean</type></entry>
3500
	<entry>a closed path?</entry>
3501
	<entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
3502 3503
       </row>
       <row>
3504 3505
	<entry><function>isopen</function>(path)</entry>
	<entry><type>boolean</type></entry>
3506
	<entry>an open path?</entry>
3507
	<entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
3508 3509
       </row>
       <row>
3510 3511
	<entry><function>length</function>(object)</entry>
	<entry><type>double precision</type></entry>
3512
	<entry>length of item</entry>
3513
	<entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
3514 3515
       </row>
       <row>
3516 3517
	<entry><function>pclose</function>(path)</entry>
	<entry><type>path</type></entry>
3518
	<entry>convert path to closed</entry>
3519
	<entry><literal>popen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
3520
       </row>
3521 3522
<![IGNORE[
<!-- Not defined by this name. Implements the intersection operator '#' -->
3523
       <row>
3524 3525
	<entry><function>point</function>(lseg,lseg)</entry>
	<entry><type>point</type></entry>
3526
	<entry>intersection</entry>
3527
	<entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
3528
       </row>
3529
]]>
3530
       <row>
3531 3532
	<entry><function>npoint</function>(path)</entry>
	<entry><type>integer</type></entry>
3533
	<entry>number of points</entry>
3534
	<entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
3535 3536
       </row>
       <row>
3537 3538
	<entry><function>popen</function>(path)</entry>
	<entry><type>path</type></entry>
3539
	<entry>convert path to open path</entry>
3540
	<entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
3541 3542
       </row>
       <row>
3543 3544
	<entry><function>radius</function>(circle)</entry>
	<entry><type>double precision</type></entry>
3545
	<entry>radius of circle</entry>
3546
	<entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
3547 3548
       </row>
       <row>
3549 3550
	<entry><function>width</function>(box)</entry>
	<entry><type>double precision</type></entry>
3551
	<entry>horizontal size</entry>
3552
	<entry><literal>width(box '((0,0),(1,1))')</literal></entry>
3553 3554 3555
       </row>
      </tbody>
     </tgroup>
3556
   </table>
3557

3558 3559

   <table>
3560 3561 3562 3563 3564 3565 3566 3567 3568 3569 3570 3571
     <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>
3572 3573
	<entry><function>box</function>(<type>circle</type>)</entry>
	<entry><type>box</type></entry>
3574
	<entry>circle to box</entry>
3575
	<entry><literal>box(circle '((0,0),2.0)')</literal></entry>
3576 3577
       </row>
       <row>
3578 3579
	<entry><function>box</function>(<type>point</type>, <type>point</type>)</entry>
	<entry><type>box</type></entry>
3580
	<entry>points to box</entry>
3581
	<entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
3582 3583
       </row>
       <row>
3584 3585
	<entry><function>box</function>(<type>polygon</type>)</entry>
	<entry><type>box</type></entry>
3586
	<entry>polygon to box</entry>
3587
	<entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
3588 3589
       </row>
       <row>
3590 3591
	<entry><function>circle</function>(<type>box</type>)</entry>
	<entry><type>circle</type></entry>
3592
	<entry>to circle</entry>
3593
	<entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
3594 3595
       </row>
       <row>
3596 3597
	<entry><function>circle</function>(<type>point</type>, <type>double precision</type>)</entry>
	<entry><type>circle</type></entry>
3598
	<entry>point to circle</entry>
3599
	<entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
3600 3601
       </row>
       <row>
3602 3603
	<entry><function>lseg</function>(<type>box</type>)</entry>
	<entry><type>lseg</type></entry>
3604
	<entry>box diagonal to lseg</entry>
3605
	<entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
3606 3607
       </row>
       <row>
3608 3609
	<entry><function>lseg</function>(<type>point</type>, <type>point</type>)</entry>
	<entry><type>lseg</type></entry>
3610
	<entry>points to lseg</entry>
3611
	<entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
3612 3613
       </row>
       <row>
3614 3615
	<entry><function>path</function>(<type>polygon</type>)</entry>
	<entry><type>point</type></entry>
3616
	<entry>polygon to path</entry>
3617
	<entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
3618 3619
       </row>
       <row>
3620 3621
	<entry><function>point</function>(<type>circle</type>)</entry>
	<entry><type>point</type></entry>
3622
	<entry>center</entry>
3623
	<entry><literal>point(circle '((0,0),2.0)')</literal></entry>
3624 3625
       </row>
       <row>
3626 3627
	<entry><function>point</function>(<type>lseg</type>, <type>lseg</type>)</entry>
	<entry><type>point</type></entry>
3628
	<entry>intersection</entry>
3629
	<entry><literal>point(lseg '((-1,0),(1,0))', lseg '((-2,-2),(2,2))')</literal></entry>
3630 3631
       </row>
       <row>
3632 3633
	<entry><function>point</function>(<type>polygon</type>)</entry>
	<entry><type>point</type></entry>
3634
	<entry>center</entry>
3635
	<entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
3636 3637
       </row>
       <row>
3638 3639
	<entry><function>polygon</function>(<type>box</type>)</entry>
	<entry><type>polygon</type></entry>
3640
	<entry>12 point polygon</entry>
3641
	<entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
3642 3643
       </row>
       <row>
3644 3645
	<entry><function>polygon</function>(<type>circle</type>)</entry>
	<entry><type>polygon</type></entry>
3646
	<entry>12-point polygon</entry>
3647
	<entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
3648 3649
       </row>
       <row>
3650 3651
	<entry><function>polygon</function>(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</entry>
	<entry><type>polygon</type></entry>
3652
	<entry><replaceable class="parameter">npts</replaceable> polygon</entry>
3653
	<entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
3654 3655
       </row>
       <row>
3656 3657
	<entry><function>polygon</function>(<type>path</type>)</entry>
	<entry><type>polygon</type></entry>
3658
	<entry>path to polygon</entry>
3659
	<entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
3660 3661 3662
       </row>
      </tbody>
     </tgroup>
3663 3664
   </table>

3665
  </sect1>
3666

3667 3668

  <sect1 id="functions-net">
3669
   <title>Network Address Type Functions</title>
3670

3671 3672 3673 3674 3675 3676 3677 3678 3679 3680 3681 3682 3683 3684 3685

    <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>
3686
	<ENTRY><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></ENTRY>
3687 3688 3689 3690
       </ROW>
       <ROW>
	<ENTRY> &lt;= </ENTRY>
	<ENTRY>Less than or equal</ENTRY>
3691
	<ENTRY><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></ENTRY>
3692 3693 3694 3695
       </ROW>
       <ROW>
	<ENTRY> = </ENTRY>
	<ENTRY>Equals</ENTRY>
3696
	<ENTRY><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></ENTRY>
3697 3698 3699 3700
       </ROW>
       <ROW>
	<ENTRY> &gt;= </ENTRY>
	<ENTRY>Greater or equal</ENTRY>
3701
	<ENTRY><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></ENTRY>
3702 3703 3704 3705
       </ROW>
       <ROW>
	<ENTRY> &gt; </ENTRY>
	<ENTRY>Greater</ENTRY>
3706
	<ENTRY><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></ENTRY>
3707 3708 3709 3710
       </ROW>
       <ROW>
	<ENTRY> &lt;&gt; </ENTRY>
	<ENTRY>Not equal</ENTRY>
3711
	<ENTRY><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></ENTRY>
3712 3713 3714 3715
       </ROW>
       <ROW>
	<ENTRY> &lt;&lt; </ENTRY>
	<ENTRY>is contained within</ENTRY>
3716
	<ENTRY><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></ENTRY>
3717 3718 3719 3720
       </ROW>
       <ROW>
	<ENTRY> &lt;&lt;= </ENTRY>
	<ENTRY>is contained within or equals</ENTRY>
3721
	<ENTRY><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></ENTRY>
3722 3723 3724 3725
       </ROW>
       <ROW>
	<ENTRY> &gt;&gt; </ENTRY>
	<ENTRY>contains</ENTRY>
3726
	<ENTRY><literal>inet'192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></ENTRY>
3727 3728 3729 3730
       </ROW>
       <ROW>
	<ENTRY> &gt;&gt;= </ENTRY>
	<ENTRY>contains or equals</ENTRY>
3731
	<ENTRY><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></ENTRY>
3732 3733 3734 3735 3736 3737 3738 3739 3740 3741 3742 3743 3744 3745 3746 3747
       </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>


3748 3749
    <table tocentry="1" id="cidr-inet-functions">
     <title><type>cidr</> and <type>inet</> Functions</title>
3750
     <tgroup cols="5">
3751 3752 3753 3754 3755 3756
      <thead>
       <row>
	<entry>Function</entry>
	<entry>Returns</entry>
	<entry>Description</entry>
	<entry>Example</entry>
3757
	<entry>Result</entry>
3758 3759 3760 3761
       </row>
      </thead>
      <tbody>
       <row>
3762 3763
	<entry><function>broadcast</function>(<type>inet</type>)</entry>
	<entry><type>inet</type></entry>
3764
	<entry>broadcast address for network</entry>
3765 3766
	<entry><literal>broadcast('192.168.1.5/24')</literal></entry>
	<entry><literal>192.168.1.255/24</literal></entry>
3767 3768
       </row>
       <row>
3769 3770
	<entry><function>host</function>(<type>inet</type>)</entry>
	<entry><type>text</type></entry>
3771
	<entry>extract IP address as text</entry>
3772 3773
	<entry><literal>host('192.168.1.5/24')</literal></entry>
	<entry><literal>192.168.1.5</literal></entry>
3774 3775
       </row>
       <row>
3776 3777
	<entry><function>masklen</function>(<type>inet</type>)</entry>
	<entry><type>integer</type></entry>
3778
	<entry>extract netmask length</entry>
3779 3780
	<entry><literal>masklen('192.168.1.5/24')</literal></entry>
	<entry><literal>24</literal></entry>
3781
       </row>
Bruce Momjian's avatar
Bruce Momjian committed
3782
       <row>
3783 3784
	<entry><function>set_masklen</function>(<type>inet</type>,<type>integer</type>)</entry>
	<entry><type>inet</type></entry>
Bruce Momjian's avatar
Bruce Momjian committed
3785
	<entry>set netmask length for inet value</entry>
3786 3787
	<entry><literal>set_masklen('192.168.1.5/24',16)</literal></entry>
	<entry><literal>192.168.1.5/16</literal></entry>
Bruce Momjian's avatar
Bruce Momjian committed
3788
       </row>
3789
       <row>
3790 3791
	<entry><function>netmask</function>(<type>inet</type>)</entry>
	<entry><type>inet</type></entry>
3792
	<entry>construct netmask for network</entry>
3793 3794
	<entry><literal>netmask('192.168.1.5/24')</literal></entry>
	<entry><literal>255.255.255.0</literal></entry>
3795 3796
       </row>
       <row>
3797 3798
	<entry><function>network</function>(<type>inet</type>)</entry>
	<entry><type>cidr</type></entry>
3799
	<entry>extract network part of address</entry>
3800 3801
	<entry><literal>network('192.168.1.5/24')</literal></entry>
	<entry><literal>192.168.1.0/24</literal></entry>
3802 3803
       </row>
       <row>
3804 3805
	<entry><function>text</function>(<type>inet</type>)</entry>
	<entry><type>text</type></entry>
3806
	<entry>extract IP address and masklen as text</entry>
3807 3808
	<entry><literal>text(inet '192.168.1.5')</literal></entry>
	<entry><literal>192.168.1.5/32</literal></entry>
3809
       </row>
3810
       <row>
3811 3812
	<entry><function>abbrev</function>(<type>inet</type>)</entry>
	<entry><type>text</type></entry>
3813
	<entry>extract abbreviated display as text</entry>
3814 3815
	<entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
	<entry><literal>10.1/16</literal></entry>
3816
       </row>
3817 3818 3819 3820 3821 3822
      </tbody>
     </tgroup>
    </table>

   <para>
    All of the functions for <type>inet</type> can be applied to
3823 3824
    <type>cidr</type> values as well.  The <function>host</>(),
    <function>text</>(), and <function>abbrev</>() functions are primarily
Bruce Momjian's avatar
Bruce Momjian committed
3825
    intended to offer alternative display formats. You can cast a text
3826 3827
    field to inet using normal casting syntax: <literal>inet(expression)</literal> or 
    <literal>colname::inet</literal>.
3828 3829 3830 3831 3832 3833 3834 3835 3836 3837 3838 3839 3840
   </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>
3841
       </row>
3842 3843
      </thead>
      <tbody>
3844
       <row>
3845 3846
	<entry><function>trunc</function>(<type>macaddr</type>)</entry>
	<entry><type>macaddr</type></entry>
3847
	<entry>set last 3 bytes to zero</entry>
3848 3849
	<entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
	<entry><literal>12:34:56:00:00:00</literal></entry>
3850
       </row>
3851 3852 3853
      </tbody>
     </tgroup>
    </table>
3854
   </para>
3855

3856
   <para>
3857 3858 3859 3860 3861
    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.
3862
   </para>
3863

3864 3865 3866 3867 3868 3869
   <para>
    The <type>macaddr</> type also supports the standard relational
    operators (<literal>&gt;</>, <literal>&lt;=</>, etc.) for
    lexicographical ordering.
   </para>

3870
  </sect1>
3871

3872

3873 3874 3875 3876 3877 3878 3879 3880 3881 3882 3883 3884 3885 3886 3887 3888 3889 3890 3891 3892 3893 3894 3895 3896 3897 3898 3899 3900 3901 3902 3903 3904 3905 3906 3907 3908 3909 3910 3911 3912 3913 3914 3915 3916 3917 3918 3919 3920 3921
 <sect1 id="functions-sequence">
  <title>Sequence-Manipulation Functions</title>

  <indexterm>
   <primary>sequences</primary>
  </indexterm>
  <indexterm>
   <primary>nextval</primary>
  </indexterm>
  <indexterm>
   <primary>currval</primary>
  </indexterm>
  <indexterm>
   <primary>setval</primary>
  </indexterm>

   <table>
    <title>Sequence Functions</>
    <tgroup cols="3">
     <thead>
      <row><entry>Function</> <entry>Returns</> <entry>Description</></row>
     </thead>

     <tbody>
      <row>
	<entry><function>nextval</function>(<type>text</type>)</entry>
	<entry><type>bigint</type></entry>
	<entry>Advance sequence and return new value</>
      </row>
      <row>
	<entry><function>currval</function>(<type>text</type>)</entry>
	<entry><type>bigint</type></entry>
	<entry>Return value most recently obtained with <function>nextval</></entry>
      </row>
      <row>
	<entry><function>setval</function>(<type>text</type>,<type>bigint</type>)</entry>
	<entry><type>bigint</type></entry>
	<entry>Set sequence's current value</>
      </row>
      <row>
	<entry><function>setval</function>(<type>text</type>,<type>bigint</type>,<type>boolean</>)</entry>
	<entry><type>bigint</type></entry>
	<entry>Set sequence's current value and <literal>is_called</> flag</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

  <para>
3922
   This section describes <productname>PostgreSQL</productname>'s functions
3923 3924 3925 3926 3927 3928 3929 3930 3931 3932 3933 3934 3935 3936 3937 3938 3939 3940 3941 3942 3943 3944 3945 3946 3947 3948 3949 3950 3951 3952 3953 3954 3955 3956 3957 3958 3959 3960 3961 3962 3963 3964 3965 3966 3967 3968 3969 3970 3971 3972 3973 3974 3975 3976 3977 3978 3979 3980 3981 3982 3983 3984 3985 3986 3987 3988 3989 3990 3991 3992 3993 3994 3995 3996 3997 3998 3999 4000 4001 4002 4003 4004 4005 4006 4007 4008 4009 4010 4011 4012 4013 4014 4015 4016 4017 4018 4019 4020 4021 4022 4023 4024 4025 4026 4027 4028 4029 4030 4031 4032
   for operating on <firstterm>sequence objects</>.
   Sequence objects (also called sequence generators or
   just sequences) are special single-row tables created with
   <command>CREATE SEQUENCE</>.  A sequence object is usually used to
   generate unique identifiers for rows of a table.  The sequence functions
   provide simple, multi-user-safe methods for obtaining successive
   sequence values from sequence objects.
  </para>

  <para>
   For largely historical reasons, the sequence to be operated on by
   a sequence-function call is specified by a text-string argument.
   To achieve some compatibility with the handling of ordinary SQL
   names, the sequence functions convert their argument to lower case
   unless the string is double-quoted.  Thus
<programlisting>
nextval('foo')      <lineannotation>operates on sequence </><literal>foo</>
nextval('FOO')      <lineannotation>operates on sequence </><literal>foo</>
nextval('"Foo"')    <lineannotation>operates on sequence </><literal>Foo</>
</programlisting>
   Of course, the text argument can be the result of an expression,
   not only a simple literal, which is occasionally useful.
  </para>

  <para>
   The available sequence functions are:

    <variablelist>
     <varlistentry>
      <term><function>nextval</></term>
      <listitem>
       <para>
        Advance the sequence object to its next value and return that
	value.  This is done atomically: even if multiple server processes
	execute <function>nextval</> concurrently, each will safely receive
	a distinct sequence value.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><function>currval</></term>
      <listitem>
       <para>
        Return the value most recently obtained by <function>nextval</>
	for this sequence in the current server process.  (An error is
	reported if <function>nextval</> has never been called for this
	sequence in this process.)  Notice that because this is returning
	a process-local value, it gives a predictable answer even if other
	server processes are executing <function>nextval</> meanwhile.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><function>setval</></term>
      <listitem>
       <para>
        Reset the sequence object's counter value.  The two-parameter
	form sets the sequence's <literal>last_value</> field to the specified
	value and sets its <literal>is_called</> field to <literal>true</>,
	meaning that the next <function>nextval</> will advance the sequence
	before returning a value.  In the three-parameter form,
	<literal>is_called</> may be set either <literal>true</> or
	<literal>false</>.  If it's set to <literal>false</>,
	the next <function>nextval</> will return exactly the specified
	value, and sequence advancement commences with the following
	<function>nextval</>.  For example,
       </para>

       <informalexample>
<screen>
SELECT setval('foo', 42);           <lineannotation>Next nextval() will return 43</>
SELECT setval('foo', 42, true);     <lineannotation>Same as above</>
SELECT setval('foo', 42, false);    <lineannotation>Next nextval() will return 42</>
</screen>
       </informalexample>

       <para>
        The result returned by <function>setval</> is just the value of its
	second argument.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
  </para>

  <important>
   <para>
    To avoid blocking of concurrent transactions that obtain numbers from the
    same sequence, a <function>nextval</> operation is never rolled back;
    that is, once a value has been fetched it is considered used, even if the
    transaction that did the <function>nextval</> later aborts.  This means
    that aborted transactions may leave unused <quote>holes</quote> in the
    sequence of assigned values.  <function>setval</> operations are never
    rolled back, either.
   </para>
  </important>

  <para>
   If a sequence object has been created with default parameters,
   <function>nextval()</> calls on it will return successive values
   beginning with one.  Other behaviors can be obtained by using
   special parameters in the <command>CREATE SEQUENCE</> command;
   see its command reference page for more information.
  </para>

 </sect1>


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

4036 4037 4038 4039 4040 4041 4042 4043
  <indexterm>
   <primary>case</primary>
  </indexterm>

  <indexterm>
   <primary>conditionals</primary>
  </indexterm>

4044
  <para>
4045
   This section describes the <acronym>SQL</acronym>-compliant conditional expressions
4046
   available in <productname>PostgreSQL</productname>.
4047 4048 4049 4050 4051 4052 4053 4054 4055 4056 4057 4058 4059 4060 4061 4062 4063 4064 4065 4066 4067 4068
  </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
4069
   other languages.  <token>CASE</token> clauses can be used wherever
4070
   an expression is valid.  <replaceable>condition</replaceable> is an
4071
   expression that returns a <type>boolean</type> result.  If the result is true
4072 4073 4074 4075 4076 4077 4078 4079 4080 4081 4082 4083 4084 4085 4086 4087 4088 4089 4090 4091 4092 4093 4094
   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>

4095 4096 4097 4098 4099 4100
<prompt>=&gt;</prompt> <userinput>SELECT a,
          CASE WHEN a=1 THEN 'one'
               WHEN a=2 THEN 'two'
               ELSE 'other'
          END
    FROM test;</userinput>
4101 4102 4103 4104 4105 4106 4107 4108 4109 4110 4111 4112
<computeroutput>
 a | case
---+-------
 1 | one
 2 | two
 3 | other
</computeroutput>
</screen>
   </para>
  </informalexample>

  <para>
4113 4114 4115
   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.
4116 4117 4118 4119 4120 4121 4122 4123 4124 4125 4126 4127 4128 4129 4130 4131 4132 4133 4134 4135 4136 4137 4138 4139 4140 4141
  </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>
4142 4143 4144 4145 4146 4147
<prompt>=&gt;</prompt> <userinput>SELECT a,
          CASE a WHEN 1 THEN 'one'
                 WHEN 2 THEN 'two'
                 ELSE 'other'
          END
    FROM test;</userinput>
4148 4149 4150 4151 4152 4153 4154 4155 4156 4157 4158 4159 4160 4161 4162 4163 4164 4165 4166 4167 4168 4169 4170 4171 4172 4173 4174 4175 4176
<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>

4177 4178 4179 4180
  <indexterm>
   <primary>nullif</primary>
  </indexterm>

4181 4182 4183 4184 4185 4186 4187 4188 4189 4190 4191 4192 4193 4194 4195
<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>
4196 4197 4198 4199 4200 4201 4202 4203 4204 4205 4206 4207 4208

  <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>

4209 4210 4211 4212
 </sect1>


  <sect1 id="functions-misc">
4213
   <title>Miscellaneous Functions</>
4214 4215

   <table>
4216
    <title>Session Information Functions</>
4217 4218
    <tgroup cols="3">
     <thead>
4219
      <row><entry>Name</> <entry>Return Type</> <entry>Description</></row>
4220 4221 4222 4223
     </thead>

     <tbody>
      <row>
4224 4225
       <entry><function>current_user</></entry>
       <entry><type>name</></entry>
4226 4227 4228
       <entry>user name of current execution context</>
      </row>
      <row>
4229 4230
       <entry><function>session_user</></entry>
       <entry><type>name</></entry>
4231
       <entry>session user name</>
4232 4233
      </row>
      <row>
4234 4235
       <entry><function>user</></entry>
       <entry><type>name</></entry>
4236
       <entry>equivalent to <function>current_user</></>
4237 4238 4239 4240 4241
      </row>
     </tbody>
    </tgroup>
   </table>

4242 4243 4244 4245 4246
   <indexterm zone="functions-misc">
    <primary>user</primary>
    <secondary>current</secondary>
   </indexterm>

4247 4248
   <para>
    The <function>session_user</> is the user that initiated a database
4249
    connection; it is fixed for the duration of that connection. The
4250 4251 4252 4253 4254 4255 4256 4257 4258
    <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>
4259
    Note that these functions have special syntactic status in <acronym>SQL</>:
4260 4261 4262 4263 4264 4265 4266 4267 4268 4269
    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>
4270

4271 4272 4273 4274 4275 4276 4277 4278 4279 4280 4281 4282 4283 4284 4285 4286 4287 4288 4289 4290 4291 4292 4293 4294 4295 4296
   <table>
    <title>System Information Functions</>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</> <entry>Return Type</> <entry>Description</></row>
     </thead>

     <tbody>
      <row>
       <entry><function>version</></entry>
       <entry><type>text</></entry>
       <entry>PostgreSQL version information</>
      </row>
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-misc">
    <primary>version</primary>
   </indexterm>

   <para>
    <function>version()</> returns a string describing the PostgreSQL
    server's version.
   </para>

4297 4298 4299 4300 4301 4302 4303 4304 4305
   <table>
    <title>Access Privilege Inquiry Functions</>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</> <entry>Return Type</> <entry>Description</></row>
     </thead>

     <tbody>
      <row>
4306
       <entry><function>has_table_privilege</function>(<parameter>user</parameter>,
4307 4308 4309
                                  <parameter>table</parameter>,
                                  <parameter>access</parameter>)
       </entry>
4310
       <entry><type>boolean</type></>
4311 4312 4313
       <entry>does user have access to table</>
      </row>
      <row>
4314
       <entry><function>has_table_privilege</function>(<parameter>table</parameter>,
4315 4316
                                  <parameter>access</parameter>)
       </entry>
4317
       <entry><type>boolean</type></>
4318 4319 4320 4321 4322 4323 4324 4325 4326 4327 4328 4329 4330
       <entry>does current user have access to table</>
      </row>
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-misc">
    <primary>has_table_privilege</primary>
   </indexterm>

   <para>
    <function>has_table_privilege</> determines whether a user
    can access a table in a particular way.  The user can be
4331 4332 4333
    specified by name or by ID
    (<classname>pg_user</>.<structfield>usesysid</>), or if the argument is
    omitted
4334 4335 4336 4337 4338 4339 4340 4341 4342 4343
    <function>current_user</> is assumed.  The table can be specified
    by name or by OID.  (Thus, there are actually six variants of
    <function>has_table_privilege</>, which can be distinguished by
    the number and types of their arguments.)  The desired access type
    is specified by a text string, which must evaluate to one of the
    values <literal>SELECT</>, <literal>INSERT</>, <literal>UPDATE</>,
    <literal>DELETE</>, <literal>RULE</>, <literal>REFERENCES</>, or
    <literal>TRIGGER</>.  (Case of the string is not significant, however.)
   </para>

4344
   <table>
4345
    <title>Catalog Information Functions</>
4346 4347 4348 4349 4350 4351 4352
    <tgroup cols="3">
     <thead>
      <row><entry>Name</> <entry>Return Type</> <entry>Description</></row>
     </thead>

     <tbody>
      <row>
4353 4354 4355 4356 4357 4358 4359 4360 4361 4362 4363 4364 4365 4366 4367 4368 4369 4370
       <entry><function>pg_get_viewdef</>(<parameter>viewname</parameter>)</entry>
       <entry><type>text</></entry>
       <entry>Get CREATE VIEW command for view</>
      </row>
      <row>
       <entry><function>pg_get_ruledef</>(<parameter>rulename</parameter>)</entry>
       <entry><type>text</></entry>
       <entry>Get CREATE RULE command for rule</>
      </row>
      <row>
       <entry><function>pg_get_indexdef</>(<parameter>indexOID</parameter>)</entry>
       <entry><type>text</></entry>
       <entry>Get CREATE INDEX command for index</>
      </row>
      <row>
       <entry><function>pg_get_userbyid</>(<parameter>userid</parameter>)</entry>
       <entry><type>name</></entry>
       <entry>Get user name given sysid</>
4371 4372 4373 4374 4375 4376
      </row>
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-misc">
4377 4378 4379 4380 4381 4382 4383 4384 4385 4386 4387 4388 4389
    <primary>pg_get_viewdef</primary>
   </indexterm>

   <indexterm zone="functions-misc">
    <primary>pg_get_ruledef</primary>
   </indexterm>

   <indexterm zone="functions-misc">
    <primary>pg_get_indexdef</primary>
   </indexterm>

   <indexterm zone="functions-misc">
    <primary>pg_get_userbyid</primary>
4390 4391 4392
   </indexterm>

   <para>
4393 4394 4395 4396 4397 4398 4399
    These functions extract information from the system catalogs.
    <function>pg_get_viewdef()</>, <function>pg_get_ruledef()</>, and
    <function>pg_get_indexdef()</> respectively reconstruct the creating
    command for a view, rule, or index.  (Note that this is a decompiled
    reconstruction, not the verbatim text of the command.)
    <function>pg_get_userbyid()</> extracts a user's name given a
    <structfield>usesysid</> value.
4400 4401
   </para>

4402 4403
  </sect1>

4404

4405 4406
 <sect1 id="functions-aggregate">
  <title>Aggregate Functions</title>
4407

4408 4409
  <note>
   <title>Author</title>
4410
   <para>
4411
    Written by Isaac Wilcox <email>isaac@azartmedia.com</email> on 2000-06-16
4412
   </para>
4413
  </note>
4414

4415 4416 4417 4418 4419 4420 4421
  <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>
4422

4423 4424
  <table tocentry="1">
   <title>Aggregate Functions</title>
4425

4426 4427 4428 4429 4430 4431 4432 4433 4434 4435 4436 4437 4438 4439
   <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>
4440 4441 4442 4443
       <indexterm>
        <primary>average</primary>
        <secondary>function</secondary>
       </indexterm>
4444 4445 4446 4447 4448 4449 4450 4451 4452 4453 4454
       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>
4455
      <entry><function>count</function>(*)</entry>
4456
      <entry>number of input values</entry>
4457
      <entry>The return value is of type <type>bigint</type>.</entry>
4458 4459 4460
     </row>

     <row>
4461
      <entry><function>count</function>(<replaceable class="parameter">expression</replaceable>)</entry>
4462 4463 4464 4465
      <entry>
       Counts the input values for which the value of <replaceable
       class="parameter">expression</replaceable> is not NULL.
      </entry>
4466
      <entry>The return value is of type <type>bigint</type>.</entry>
4467 4468 4469
     </row>

     <row>
4470
      <entry><function>max</function>(<replaceable class="parameter">expression</replaceable>)</entry>
4471 4472 4473 4474 4475 4476 4477 4478
      <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>
4479
      <entry><function>min</function>(<replaceable class="parameter">expression</replaceable>)</entry>
4480 4481 4482 4483 4484 4485 4486 4487
      <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>
4488
      <entry><function>stddev</function>(<replaceable class="parameter">expression</replaceable>)</entry>
4489 4490
      <entry>the sample standard deviation of the input values</entry>
      <entry>
4491 4492 4493
       <indexterm>
        <primary>standard deviation</primary>
       </indexterm>
4494 4495 4496 4497 4498 4499 4500 4501 4502 4503
       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>
4504
      <entry><function>sum</function>(<replaceable class="parameter">expression</replaceable>)</entry>
4505 4506 4507 4508 4509 4510
      <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>.
4511 4512 4513
       The result is of type <type>bigint</type> for <type>smallint</type>
       or <type>integer</type> input, <type>numeric</type> for
       <type>bigint</type> 
4514 4515 4516 4517 4518 4519
       input, <type>double precision</type> for floating point input,
       otherwise the same as the input data type.
      </entry>
     </row>

     <row>
4520
      <entry><function>variance</function>(<replaceable class="parameter">expression</replaceable>)</entry>
4521 4522
      <entry>the sample variance of the input values</entry>
      <entry>
4523 4524 4525
       <indexterm>
        <primary>variance</primary>
       </indexterm>
4526
       The variance is the square of the standard deviation.  The
4527 4528
       supported data types and result types are the same as for
       standard deviation.
4529 4530 4531 4532 4533 4534
      </entry>
     </row>

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

4536 4537 4538 4539
  <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
4540 4541
   zero as one might expect.  <function>COALESCE</function> may be
   used to substitute zero for NULL when necessary.
4542
  </para>
4543

4544
 </sect1>
4545

4546 4547 4548 4549 4550 4551 4552 4553 4554 4555 4556 4557 4558 4559 4560 4561 4562 4563 4564 4565 4566 4567 4568 4569 4570 4571 4572 4573 4574 4575 4576 4577 4578 4579 4580 4581 4582 4583 4584 4585 4586 4587 4588 4589 4590 4591 4592 4593 4594 4595 4596 4597 4598 4599 4600 4601 4602 4603 4604 4605 4606 4607 4608 4609 4610 4611 4612 4613 4614 4615 4616 4617 4618 4619 4620 4621 4622 4623 4624 4625 4626 4627 4628 4629 4630 4631 4632 4633 4634 4635 4636 4637 4638 4639 4640 4641 4642 4643 4644 4645 4646 4647 4648 4649 4650 4651 4652 4653 4654 4655 4656 4657 4658 4659 4660 4661 4662 4663 4664 4665 4666 4667 4668 4669 4670 4671 4672 4673 4674 4675 4676 4677 4678 4679 4680 4681 4682 4683 4684 4685 4686 4687 4688 4689 4690 4691 4692 4693 4694 4695 4696 4697 4698 4699 4700 4701 4702 4703 4704 4705 4706 4707 4708 4709 4710 4711 4712 4713 4714 4715 4716 4717 4718 4719 4720 4721 4722 4723 4724 4725 4726 4727 4728 4729 4730 4731 4732 4733 4734 4735 4736 4737 4738 4739 4740 4741 4742 4743 4744 4745 4746 4747 4748 4749 4750 4751 4752 4753 4754 4755 4756 4757 4758 4759 4760 4761 4762 4763 4764 4765 4766 4767 4768 4769 4770 4771 4772 4773 4774 4775 4776 4777 4778 4779 4780 4781 4782 4783 4784 4785 4786 4787 4788 4789 4790 4791 4792 4793 4794 4795 4796 4797 4798 4799 4800 4801 4802 4803 4804 4805 4806 4807 4808 4809 4810 4811 4812 4813 4814 4815 4816 4817 4818 4819 4820 4821 4822 4823 4824 4825 4826 4827 4828 4829 4830 4831 4832 4833 4834 4835 4836 4837 4838 4839 4840 4841 4842 4843 4844 4845 4846 4847 4848 4849 4850 4851 4852 4853 4854 4855 4856 4857 4858 4859 4860 4861 4862 4863 4864 4865 4866 4867 4868 4869 4870 4871 4872 4873 4874 4875 4876 4877 4878 4879 4880 4881 4882 4883 4884 4885 4886 4887 4888 4889 4890 4891 4892 4893 4894 4895 4896 4897 4898 4899 4900 4901 4902 4903 4904 4905 4906 4907 4908 4909 4910 4911 4912 4913 4914 4915 4916 4917 4918 4919 4920 4921 4922 4923 4924 4925 4926 4927 4928 4929 4930 4931 4932 4933 4934 4935 4936 4937 4938 4939 4940 4941 4942 4943 4944 4945 4946 4947 4948 4949 4950 4951 4952 4953 4954 4955 4956 4957 4958 4959 4960 4961 4962 4963 4964

 <sect1 id="functions-subquery">
  <title>Subquery Expressions</title>

  <indexterm>
   <primary>exists</primary>
  </indexterm>

  <indexterm>
   <primary>in</primary>
  </indexterm>

  <indexterm>
   <primary>not in</primary>
  </indexterm>

  <indexterm>
   <primary>any</primary>
  </indexterm>

  <indexterm>
   <primary>all</primary>
  </indexterm>

  <indexterm>
   <primary>some</primary>
  </indexterm>

  <indexterm>
   <primary>subqueries</primary>
  </indexterm>

  <para>
   This section describes the <acronym>SQL</acronym>-compliant subquery
   expressions available in <productname>PostgreSQL</productname>.
   All of the expression forms documented in this section return
   Boolean (true/false) results.
  </para>

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

<synopsis>
EXISTS ( <replaceable>subquery</replaceable> )
</synopsis>

  <para>
   The argument of <token>EXISTS</> is an arbitrary SELECT statement,
   or <firstterm>subquery</>.  The
   subquery is evaluated to determine whether it returns any rows.
   If it returns at least one row, the result of <token>EXISTS</> is
   TRUE; if the subquery returns no rows, the result of <token>EXISTS</> 
   is FALSE.
  </para>

  <para>
   The subquery can refer to variables from the surrounding query,
   which will act as constants during any one evaluation of the subquery.
  </para>

  <para>
   The subquery will generally only be executed far enough to determine
   whether at least one row is returned, not all the way to completion.
   It is unwise to write a subquery that has any side-effects (such as
   calling sequence functions); whether the side-effects occur or not
   may be difficult to predict.
  </para>

  <para>
   Since the result depends only on whether any rows are returned,
   and not on the contents of those rows, the output list of the
   subquery is normally uninteresting.  A common coding convention is
   to write all EXISTS tests in the form
   <literal>EXISTS(SELECT 1 WHERE ...)</>.  There are exceptions to
   this rule however, such as subqueries that use <token>INTERSECT</>.
  </para>

  <para>
   This simple example is like an inner join on col2, but it produces at
   most one output row for each tab1 row, even if there are multiple matching
   tab2 rows:
<screen>
SELECT col1 FROM tab1
    WHERE EXISTS(SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
</screen>
  </para>

   <bridgehead renderas="sect2">IN (scalar form)</bridgehead>

<synopsis>
<replaceable>expression</replaceable> IN (<replaceable>value</replaceable><optional>, ...</optional>)
</synopsis>

  <para>
   The right-hand side of this form of <token>IN</> is a parenthesized list
   of scalar expressions.  The result is TRUE if the left-hand expression's
   result is equal to any of the right-hand expressions.  This is a shorthand
   notation for

<synopsis>
<replaceable>expression</replaceable> = <replaceable>value1</replaceable>
OR
<replaceable>expression</replaceable> = <replaceable>value2</replaceable>
OR
...
</synopsis>

   Note that if the left-hand expression yields NULL, or if there are
   no equal right-hand values and at least one right-hand expression yields
   NULL, the result of the <token>IN</> construct will be NULL, not FALSE.
   This is in accordance with SQL's normal rules for Boolean combinations
   of NULL values.
  </para>

  <note>
  <para>
   This form of <token>IN</> is not truly a subquery expression, but it
   seems best to document it in the same place as subquery <token>IN</>.
  </para>
  </note>

   <bridgehead renderas="sect2">IN (subquery form)</bridgehead>

<synopsis>
<replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The right-hand side of this form of <token>IN</> is a parenthesized
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result.
   The result of <token>IN</> is TRUE if any equal subquery row is found.
   The result is FALSE if no equal row is found (including the special
   case where the subquery returns no rows).
  </para>

  <para>
   Note that if the left-hand expression yields NULL, or if there are
   no equal right-hand values and at least one right-hand row yields
   NULL, the result of the <token>IN</> construct will be NULL, not FALSE.
   This is in accordance with SQL's normal rules for Boolean combinations
   of NULL values.
  </para>

  <para>
   As with <token>EXISTS</>, it's unwise to assume that the subquery will
   be evaluated completely.
  </para>

<synopsis>
(<replaceable>expression</replaceable>, <replaceable>expression</replaceable><optional>, ...</optional>) IN (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The right-hand side of this form of <token>IN</> is a parenthesized
   subquery, which must return exactly as many columns as there are
   expressions in the left-hand list.  The left-hand expressions are
   evaluated and compared row-wise to each row of the subquery result.
   The result of <token>IN</> is TRUE if any equal subquery row is found.
   The result is FALSE if no equal row is found (including the special
   case where the subquery returns no rows).
  </para>

  <para>
   As usual, NULLs in the expressions or subquery rows are combined per
   the normal rules of SQL boolean expressions.  Two rows are considered
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
   otherwise the result of that row comparison is unknown (NULL).
   If all the row results are either unequal or NULL, with at least one NULL,
   then the result of <token>IN</> is NULL.
  </para>

   <bridgehead renderas="sect2">NOT IN (scalar form)</bridgehead>

<synopsis>
<replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable><optional>, ...</optional>)
</synopsis>

  <para>
   The right-hand side of this form of <token>NOT IN</> is a parenthesized list
   of scalar expressions.  The result is TRUE if the left-hand expression's
   result is unequal to all of the right-hand expressions.  This is a shorthand
   notation for

<synopsis>
<replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
AND
<replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
AND
...
</synopsis>

   Note that if the left-hand expression yields NULL, or if there are
   no equal right-hand values and at least one right-hand expression yields
   NULL, the result of the <token>NOT IN</> construct will be NULL, not TRUE
   as one might naively expect.
   This is in accordance with SQL's normal rules for Boolean combinations
   of NULL values.
  </para>

  <tip>
  <para>
   <literal>x NOT IN y</> is equivalent to <literal>NOT (x IN y)</> in all
   cases.  However, NULLs are much more likely to trip up the novice when
   working with <token>NOT IN</> than when working with <token>IN</>.
   It's best to express your condition positively if possible.
  </para>
  </tip>

   <bridgehead renderas="sect2">NOT IN (subquery form)</bridgehead>

<synopsis>
<replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The right-hand side of this form of <token>NOT IN</> is a parenthesized
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result.
   The result of <token>NOT IN</> is TRUE if only unequal subquery rows
   are found (including the special case where the subquery returns no rows).
   The result is FALSE if any equal row is found.
  </para>

  <para>
   Note that if the left-hand expression yields NULL, or if there are
   no equal right-hand values and at least one right-hand row yields
   NULL, the result of the <token>NOT IN</> construct will be NULL, not TRUE.
   This is in accordance with SQL's normal rules for Boolean combinations
   of NULL values.
  </para>

  <para>
   As with <token>EXISTS</>, it's unwise to assume that the subquery will
   be evaluated completely.
  </para>

<synopsis>
(<replaceable>expression</replaceable>, <replaceable>expression</replaceable><optional>, ...</optional>) NOT IN (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The right-hand side of this form of <token>NOT IN</> is a parenthesized
   subquery, which must return exactly as many columns as there are
   expressions in the left-hand list.  The left-hand expressions are
   evaluated and compared row-wise to each row of the subquery result.
   The result of <token>NOT IN</> is TRUE if only unequal subquery rows
   are found (including the special case where the subquery returns no rows).
   The result is FALSE if any equal row is found.
  </para>

  <para>
   As usual, NULLs in the expressions or subquery rows are combined per
   the normal rules of SQL boolean expressions.  Two rows are considered
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
   otherwise the result of that row comparison is unknown (NULL).
   If all the row results are either unequal or NULL, with at least one NULL,
   then the result of <token>NOT IN</> is NULL.
  </para>

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

<synopsis>
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
<replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The right-hand side of this form of <token>ANY</> is a parenthesized
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result using the
   given <replaceable>operator</replaceable>, which must yield a boolean
   result.
   The result of <token>ANY</> is TRUE if any true result is obtained.
   The result is FALSE if no true result is found (including the special
   case where the subquery returns no rows).
  </para>

  <para>
   <token>SOME</> is a synonym for <token>ANY</>.
   <token>IN</> is equivalent to <literal>= ANY</>.
  </para>

  <para>
   Note that if there are no successes and at least one right-hand row yields
   NULL for the operator's result, the result of the <token>ANY</> construct
   will be NULL, not FALSE.
   This is in accordance with SQL's normal rules for Boolean combinations
   of NULL values.
  </para>

  <para>
   As with <token>EXISTS</>, it's unwise to assume that the subquery will
   be evaluated completely.
  </para>

<synopsis>
(<replaceable>expression</replaceable>, <replaceable>expression</replaceable><optional>, ...</optional>) <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
(<replaceable>expression</replaceable>, <replaceable>expression</replaceable><optional>, ...</optional>) <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The right-hand side of this form of <token>ANY</> is a parenthesized
   subquery, which must return exactly as many columns as there are
   expressions in the left-hand list.  The left-hand expressions are
   evaluated and compared row-wise to each row of the subquery result,
   using the given <replaceable>operator</replaceable>.  Presently,
   only <literal>=</> and <literal>&lt;&gt;</> operators are allowed
   in row-wise <token>ANY</> queries.
   The result of <token>ANY</> is TRUE if any equal or unequal row is
   found, respectively.
   The result is FALSE if no such row is found (including the special
   case where the subquery returns no rows).
  </para>

  <para>
   As usual, NULLs in the expressions or subquery rows are combined per
   the normal rules of SQL boolean expressions.  Two rows are considered
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
   otherwise the result of that row comparison is unknown (NULL).
   If there is at least one NULL row result, then the result of <token>ANY</>
   cannot be FALSE; it will be TRUE or NULL. 
  </para>

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

<synopsis>
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The right-hand side of this form of <token>ALL</> is a parenthesized
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result using the
   given <replaceable>operator</replaceable>, which must yield a boolean
   result.
   The result of <token>ALL</> is TRUE if all rows yield TRUE
   (including the special case where the subquery returns no rows).
   The result is FALSE if any false result is found.
  </para>

  <para>
   <token>NOT IN</> is equivalent to <literal>&lt;&gt; ALL</>.
  </para>

  <para>
   Note that if there are no failures but at least one right-hand row yields
   NULL for the operator's result, the result of the <token>ALL</> construct
   will be NULL, not TRUE.
   This is in accordance with SQL's normal rules for Boolean combinations
   of NULL values.
  </para>

  <para>
   As with <token>EXISTS</>, it's unwise to assume that the subquery will
   be evaluated completely.
  </para>

<synopsis>
(<replaceable>expression</replaceable>, <replaceable>expression</replaceable><optional>, ...</optional>) <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
</synopsis>

  <para>
   The right-hand side of this form of <token>ALL</> is a parenthesized
   subquery, which must return exactly as many columns as there are
   expressions in the left-hand list.  The left-hand expressions are
   evaluated and compared row-wise to each row of the subquery result,
   using the given <replaceable>operator</replaceable>.  Presently,
   only <literal>=</> and <literal>&lt;&gt;</> operators are allowed
   in row-wise <token>ALL</> queries.
   The result of <token>ALL</> is TRUE if all subquery rows are equal
   or unequal, respectively (including the special
   case where the subquery returns no rows).
   The result is FALSE if any row is found to be unequal or equal,
   respectively.
  </para>

  <para>
   As usual, NULLs in the expressions or subquery rows are combined per
   the normal rules of SQL boolean expressions.  Two rows are considered
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
   otherwise the result of that row comparison is unknown (NULL).
   If there is at least one NULL row result, then the result of <token>ALL</>
   cannot be TRUE; it will be FALSE or NULL. 
  </para>

   <bridgehead renderas="sect2">Row-wise comparison</bridgehead>

<synopsis>
(<replaceable>expression</replaceable>, <replaceable>expression</replaceable><optional>, ...</optional>) <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
(<replaceable>expression</replaceable>, <replaceable>expression</replaceable><optional>, ...</optional>) <replaceable>operator</replaceable> (<replaceable>expression</replaceable>, <replaceable>expression</replaceable><optional>, ...</optional>)
</synopsis>

  <para>
   The left-hand side is a list of scalar expressions.  The right-hand side
   can be either a list of scalar expressions of the same length, or a
   parenthesized subquery, which must return exactly as many columns as there
   are expressions on the left-hand side.  Furthermore, the subquery cannot
   return more than one row.  (If it returns zero rows, the result is taken to
   be NULL.)  The left-hand side is evaluated and compared row-wise to the
   single subquery result row, or to the right-hand expression list.
   Presently, only <literal>=</> and <literal>&lt;&gt;</> operators are allowed
   in row-wise comparisons.
   The result is TRUE if the two rows are equal or unequal, respectively.
  </para>

  <para>
   As usual, NULLs in the expressions or subquery rows are combined per
   the normal rules of SQL boolean expressions.  Two rows are considered
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
   otherwise the result of the row comparison is unknown (NULL).
  </para>

 </sect1>

4965
</chapter>
4966

4967 4968
<!-- Keep this comment at the end of the file
Local variables:
Thomas G. Lockhart's avatar
Thomas G. Lockhart committed
4969
mode:sgml
4970
sgml-omittag:nil
4971 4972 4973 4974 4975 4976 4977 4978
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
4979
sgml-local-catalogs:("/usr/lib/sgml/catalog")
4980 4981 4982
sgml-local-ecat-files:nil
End:
-->