func.sgml 144.8 KB
Newer Older
1
<!--
2 3
$Header: /cvsroot/pgsql/doc/src/sgml/func.sgml,v 1.84 2001/11/21 05:53:41 thomas Exp $
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
T
Tom Lane 已提交
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>
T
Thomas G. Lockhart 已提交
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.
T
Thomas G. Lockhart 已提交
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

P
Peter Eisentraut 已提交
236
  <para>
237 238 239
   <indexterm>
    <primary>between</primary>
   </indexterm>
P
Peter Eisentraut 已提交
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 268 269 270
  <para>
   To check whether a value is or is not NULL, use the constructs
<synopsis>
<replaceable>expression</replaceable> IS NULL
<replaceable>expression</replaceable> IS NOT NULL
</synopsis>
   Do <emphasis>not</emphasis> use
   <literal><replaceable>expression</replaceable> = NULL</literal>
   because NULL is not <quote>equal to</quote> NULL.  (NULL represents
271 272
   an unknown value, and it is not known whether two unknown values are
   equal.)
273
  </para>
274 275

  <para>
276 277 278 279 280 281 282 283 284 285 286 287 288
   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>).
   <productname>PostgreSQL</productname> would then convert <literal>x
   = 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
289 290 291 292 293 294 295 296 297 298 299 300
<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>
301 302 303 304 305 306
 </sect1>


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

307 308 309 310 311 312 313 314
  <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>

315
  <table>
316
   <title>Mathematical Operators</title>
317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367

   <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>
368
      <entry>8</entry>
369 370 371 372 373 374
     </row>

     <row>
      <entry> <literal>|/</literal> </entry>
      <entry>Square root</entry>
      <entry>|/ 25.0</entry>
375
      <entry>5</entry>
376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393
     </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>
394
      <entry>Factorial (prefix operator)</entry>
395 396 397 398 399 400 401 402
      <entry>!! 5</entry>
      <entry>120</entry>
     </row>

     <row>
      <entry> <literal>@</literal> </entry>
      <entry>Absolute value</entry>
      <entry>@ -5.0</entry>
403
      <entry>5</entry>
404
     </row>
405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447

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

448 449 450 451
    </tbody>
   </tgroup>
  </table>

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

  <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>
517
      <entry><function>abs</function>(<replaceable>x</replaceable>)</entry>
518
      <entry>(same as x)</entry>
519
      <entry>absolute value</entry>
520
      <entry><literal>abs(-17.4)</literal></entry>
521 522 523 524
      <entry>17.4</entry>
     </row>

     <row>
525
      <entry><function>cbrt</function>(<type>dp</type>)</entry>
526
      <entry><type>dp</type></entry>
527
      <entry>cube root</entry>
528
      <entry><literal>cbrt(27.0)</literal></entry>
529
      <entry>3</entry>
530 531 532
     </row>

     <row>
533
      <entry><function>ceil</function>(<type>numeric</type>)</entry>
534 535
      <entry><type>numeric</type></entry>
      <entry>smallest integer not less than argument</entry>
536
      <entry><literal>ceil(-42.8)</literal></entry>
537 538 539 540
      <entry>-42</entry>
     </row>

     <row>
541
      <entry><function>degrees</function>(<type>dp</type>)</entry>
542 543
      <entry><type>dp</type></entry>
      <entry>radians to degrees</entry>
544
      <entry><literal>degrees(0.5)</literal></entry>
545 546 547 548
      <entry>28.6478897565412</entry>
     </row>

     <row>
549
      <entry><function>exp</function>(<type>dp</type>)</entry>
550 551
      <entry><type>dp</type></entry>
      <entry>exponential</entry>
552
      <entry><literal>exp(1.0)</literal></entry>
553 554 555 556
      <entry>2.71828182845905</entry>
     </row>

     <row>
557
      <entry><function>floor</function>(<type>numeric</type>)</entry>
558 559
      <entry><type>numeric</type></entry>
      <entry>largest integer not greater than argument</entry>
560
      <entry><literal>floor(-42.8)</literal></entry>
561
      <entry>-43</entry>
562 563 564
     </row>

     <row>
565
      <entry><function>ln</function>(<type>dp</type>)</entry>
566
      <entry><type>dp</type></entry>
567
      <entry>natural logarithm</entry>
568
      <entry><literal>ln(2.0)</literal></entry>
569 570 571 572
      <entry>0.693147180559945</entry>
     </row>

     <row>
573
      <entry><function>log</function>(<type>dp</type>)</entry>
574
      <entry><type>dp</type></entry>
575
      <entry>base 10 logarithm</entry>
576
      <entry><literal>log(100.0)</literal></entry>
577
      <entry>2</entry>
578 579 580
     </row>

     <row>
581
      <entry><function>log</function>(<parameter>b</parameter> <type>numeric</type>,
582
       <parameter>x</parameter> <type>numeric</type>)</entry>
583
      <entry><type>numeric</type></entry>
584
      <entry>logarithm to base <parameter>b</parameter></entry>
585
      <entry><literal>log(2.0, 64.0)</literal></entry>
586
      <entry>6.0000000000</entry>
587 588 589
     </row>

     <row>
590
      <entry><function>mod</function>(<parameter>y</parameter>, <parameter>x</parameter>)</entry>
591
      <entry>(same as argument types)</entry>
592
      <entry>remainder of <parameter>y</parameter>/<parameter>x</parameter></entry>
593
      <entry><literal>mod(9,4)</literal></entry>
594 595 596 597
      <entry>1</entry>
     </row>

     <row>
598
      <entry><function>pi</function>()</entry>
599
      <entry><type>dp</type></entry>
600
      <entry><quote>Pi</quote> constant</entry>
601
      <entry><literal>pi()</literal></entry>
602 603 604 605
      <entry>3.14159265358979</entry>
     </row>

     <row>
606
      <entry><function>pow</function>(<parameter>e</parameter> <type>dp</type>,
607 608 609
       <parameter>n</parameter> <type>dp</type>)</entry>
      <entry><type>dp</type></entry>
      <entry>raise a number to exponent <parameter>e</parameter></entry>
610
      <entry><literal>pow(9.0, 3.0)</literal></entry>
611
      <entry>729</entry>
612 613 614
     </row>

     <row>
615
      <entry><function>radians</function>(<type>dp</type>)</entry>
616 617
      <entry><type>dp</type></entry>
      <entry>degrees to radians</entry>
618
      <entry><literal>radians(45.0)</literal></entry>
619 620 621 622
      <entry>0.785398163397448</entry>
     </row>

     <row>
623
      <entry><function>random</function>()</entry>
624 625
      <entry><type>dp</type></entry>
      <entry>value between 0.0 to 1.0</entry>
626
      <entry><literal>random()</literal></entry>
627 628 629 630
      <entry></entry>
     </row>

     <row>
631
      <entry><function>round</function>(<type>dp</type>)</entry>
632
      <entry><type>dp</type></entry>
633
      <entry>round to nearest integer</entry>
634
      <entry><literal>round(42.4)</literal></entry>
635 636 637 638
      <entry>42</entry>
     </row>

     <row>
639
      <entry><function>round</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type>)</entry>
640
      <entry><type>numeric</type></entry>
641
      <entry>round to <parameter>s</parameter> decimal places</entry>
642
      <entry><literal>round(42.4382, 2)</literal></entry>
643 644 645 646
      <entry>42.44</entry>
     </row>
<!--
     <row>
647
      <entry><function>setseed</function>(<replaceable>new-seed</replaceable>)</entry>
648
      <entry>set seed for subsequent random() calls</entry>
649
      <entry><literal>setseed(0.54823)</literal></entry>
650 651 652
      <entry></entry>
     </row>
-->
P
Peter Eisentraut 已提交
653 654 655 656 657 658 659 660
     <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>

661
     <row>
662
      <entry><function>sqrt</function>(<type>dp</type>)</entry>
663
      <entry><type>dp</type></entry>
664
      <entry>square root</entry>
665
      <entry><literal>sqrt(2.0)</literal></entry>
666 667 668 669
      <entry>1.4142135623731</entry>
     </row>

     <row>
670
      <entry><function>trunc</function>(<type>dp</type>)</entry>
671 672
      <entry><type>dp</type></entry>
      <entry>truncate toward zero</entry>
673
      <entry><literal>trunc(42.8)</literal></entry>
674 675 676 677
      <entry>42</entry>
     </row>

     <row>
678
      <entry><function>trunc</function>(<type>numeric</type>, <parameter>s</parameter> <type>integer</type>)</entry>
679
      <entry><type>numeric</type></entry>
680
      <entry>truncate to <parameter>s</parameter> decimal places</entry>
681
      <entry><literal>trunc(42.4382, 2)</literal></entry>
682 683 684 685 686 687 688 689
      <entry>42.43</entry>
     </row>

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

  <para>
690
   In the table above, <literal>dp</literal> indicates <type>double precision</type>.
691 692 693 694 695
   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
696 697 698 699
   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
T
Tom Lane 已提交
700 701
   of the host system's C library; accuracy and behavior in boundary cases
   could therefore vary depending on the host system.
702 703 704 705 706 707 708 709 710 711 712 713 714 715 716
  </para>

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

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

    <tbody>
     <row>
717
      <entry><function>acos</function>(<replaceable>x</replaceable>)</entry>
718 719 720 721
      <entry>inverse cosine</entry>
     </row>

     <row>
722
      <entry><function>asin</function>(<replaceable>x</replaceable>)</entry>
723 724 725 726
      <entry>inverse sine</entry>
     </row>

     <row>
727
      <entry><function>atan</function>(<replaceable>x</replaceable>)</entry>
728 729 730 731
      <entry>inverse tangent</entry>
     </row>

     <row>
732
      <entry><function>atan2</function>(<replaceable>x</replaceable>, <replaceable>y</replaceable>)</entry>
733 734 735 736
      <entry>inverse tangent of <replaceable>y</replaceable>/<replaceable>x</replaceable></entry>
     </row>

     <row>
737
      <entry><function>cos</function>(<replaceable>x</replaceable>)</entry>
738 739 740 741
      <entry>cosine</entry>
     </row>

     <row>
742
      <entry><function>cot</function>(<replaceable>x</replaceable>)</entry>
743 744 745 746
      <entry>cotangent</entry>
     </row>

     <row>
747
      <entry><function>sin</function>(<replaceable>x</replaceable>)</entry>
748 749 750 751
      <entry>sine</entry>
     </row>

     <row>
752
      <entry><function>tan</function>(<replaceable>x</replaceable>)</entry>
753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778
      <entry>tangent</entry>
     </row>
    </tbody>
   </tgroup>
  </table>

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

 </sect1>


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

  <para>
   This section describes functions and operators for examining and
   manipulating string values.  Strings in this context include values
   of all the types <type>CHARACTER</type>, <type>CHARACTER
   VARYING</type>, and <type>TEXT</type>.  Unless otherwise noted, all
   of the functions listed below work on all of these types, but be
   wary of potential effects of the automatic padding when using the
   <type>CHARACTER</type> type.  Generally the functions described
   here also work on data of non-string types by converting that data
779 780
   to a string representation first.  Some functions also exist
   natively for bit string types.
781 782 783
  </para>

  <para>
784
   <acronym>SQL</acronym> defines some string functions with a special syntax where
785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807
   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>
808 809 810 811 812 813 814
      <entry>
       string concatenation
       <indexterm>
        <primary>character strings</primary>
	<secondary>concatenation</secondary>
       </indexterm>
      </entry>
815 816
      <entry><literal>'Postgre' || 'SQL'</></entry>
      <entry><literal>PostgreSQL</></entry>
817 818
     </row>

P
Peter Eisentraut 已提交
819
     <row>
820
      <entry><function>bit_length</function>(<parameter>string</parameter>)</entry>
P
Peter Eisentraut 已提交
821 822
      <entry><type>integer</type></entry>
      <entry>number of bits in string</entry>
823 824
      <entry><literal>bit_length('jose')</literal></entry>
      <entry><literal>32</literal></entry>
P
Peter Eisentraut 已提交
825 826
     </row>

827
     <row>
828
      <entry><function>char_length</function>(<parameter>string</parameter>) or <function>character_length</function>(<parameter>string</parameter>)</entry>
829
      <entry><type>integer</type></entry>
830
      <entry>
T
Tom Lane 已提交
831
       number of characters in string
832 833 834 835 836 837 838 839 840 841
       <indexterm>
        <primary>character strings</primary>
	<secondary>length</secondary>
       </indexterm>
       <indexterm>
        <primary>length</primary>
	<secondary>character strings</secondary>
	<see>character strings, length</see>
       </indexterm>
      </entry>
842 843
      <entry><literal>char_length('jose')</></entry>
      <entry><literal>4</></entry>
844 845 846
     </row>

     <row>
847
      <entry><function>lower</function>(<parameter>string</parameter>)</entry>
848 849
      <entry><type>text</type></entry>
      <entry>Convert string to lower case.</entry>
850 851
      <entry><literal>lower('TOM')</literal></entry>
      <entry><literal>tom</literal></entry>
852 853 854
     </row>

     <row>
855
      <entry><function>octet_length</function>(<parameter>string</parameter>)</entry>
856 857
      <entry><type>integer</type></entry>
      <entry>number of bytes in string</entry>
858 859
      <entry><literal>octet_length('jose')</literal></entry>
      <entry><literal>4</literal></entry>
860 861 862
     </row>

     <row>
863
      <entry><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</entry>
864 865
      <entry><type>integer</type></entry>
      <entry>location of specified substring</entry>
866 867
      <entry><literal>position('om' in 'Thomas')</literal></entry>
      <entry><literal>3</literal></entry>
868 869 870
     </row>

     <row>
871
      <entry><function>substring</function>(<parameter>string</parameter> <optional>from <type>integer</type></optional> <optional>for <type>integer</type></optional>)</entry>
872
      <entry><type>text</type></entry>
873 874 875 876 877 878
      <entry>
       extract substring
       <indexterm>
        <primary>substring</primary>
       </indexterm>
      </entry>
879 880
      <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
      <entry><literal>hom</literal></entry>
881 882 883 884
     </row>

     <row>
      <entry>
885
       <function>trim</function>(<optional>leading | trailing | both</optional>
886 887 888 889 890 891 892 893 894
       <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>
T
Tom Lane 已提交
895
      <entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
896
      <entry><literal>Tom</literal></entry>
897 898 899
     </row>

     <row>
900
      <entry><function>upper</function>(<parameter>string</parameter>)</entry>
901 902
      <entry><type>text</type></entry>
      <entry>Convert string to upper case.</entry>
903 904
      <entry><literal>upper('tom')</literal></entry>
      <entry><literal>TOM</literal></entry>
905 906 907 908
     </row>
    </tbody>
   </tgroup>
  </table>
909

T
Thomas G. Lockhart 已提交
910
  <para>
911 912
   Additional string manipulation functions are available and are
   listed below.  Some of them are used internally to implement the
T
Tom Lane 已提交
913
   <acronym>SQL</acronym>-standard string functions listed above.
T
Thomas G. Lockhart 已提交
914
  </para>
915

916 917 918 919 920 921
  <table id="functions-string-other">
   <title>Other String Functions</title>
   <tgroup cols="5">
    <thead>
     <row>
      <entry>Function</entry>
922
      <entry>Return Type</entry>
923 924 925 926 927 928 929 930
      <entry>Description</entry>
      <entry>Example</entry>
      <entry>Result</entry>
     </row>
    </thead>

    <tbody>
     <row>
931
      <entry><function>ascii</function>(<type>text</type>)</entry>
932 933
      <entry>integer</entry>
      <entry>Returns the <acronym>ASCII</acronym> code of the first character of the argument.</entry>
934 935
      <entry><literal>ascii('x')</literal></entry>
      <entry><literal>120</literal></entry>
936 937 938
     </row>

     <row>
939
      <entry><function>btrim</function>(<parameter>string</parameter> <type>text</type>, <parameter>trim</parameter> <type>text</type>)</entry>
940 941 942 943 944 945
      <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>
946 947
      <entry><literal>btrim('xyxtrimyyx','xy')</literal></entry>
      <entry><literal>trim</literal></entry>
948 949 950
     </row>

     <row>
951
      <entry><function>chr</function>(<type>integer</type>)</entry>
952 953
      <entry><type>text</type></entry>
      <entry>Returns the character with the given <acronym>ASCII</acronym> code.</entry>
954 955
      <entry><literal>chr(65)</literal></entry>
      <entry><literal>A</literal></entry>
956 957
     </row>

T
Tatsuo Ishii 已提交
958
     <row>
959 960 961 962 963
      <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>
T
Tatsuo Ishii 已提交
964
      <entry><type>text</type></entry>
965 966 967 968 969 970
      <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.
T
Tatsuo Ishii 已提交
971
      </entry>
972 973
      <entry><literal>convert('text_in_unicode', 'UNICODE', 'LATIN1')</literal></entry>
      <entry><literal>text_in_unicode</literal> represented in ISO 8859-1</entry>
T
Tatsuo Ishii 已提交
974 975
     </row>

976
     <row>
977
      <entry><function>initcap</function>(<type>text</type>)</entry>
978 979
      <entry><type>text</type></entry>
      <entry>Converts first letter of each word (whitespace separated) to upper case.</entry>
980 981
      <entry><literal>initcap('hi thomas')</literal></entry>
      <entry><literal>Hi Thomas</literal></entry>
982 983
     </row>

984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001 1002
     <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>

1003 1004
     <row>
      <entry>
1005
       <function>lpad</function>(<parameter>string</parameter> <type>text</type>,
1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016 1017
       <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>
1018 1019
      <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
      <entry><literal>xyxhi</literal></entry>
1020 1021 1022
     </row>

     <row>
1023
      <entry><function>ltrim</function>(<parameter>string</parameter> <type>text</type>, <parameter>trim</parameter> <type>text</type>)</entry>
1024 1025 1026 1027 1028
      <entry><type>text</type></entry>
      <entry>
       Removes the longest string containing only characters from
       <parameter>trim</parameter> from the start of the string.
      </entry>
1029 1030
      <entry><literal>ltrim('zzzytrim','xyz')</literal></entry>
      <entry><literal>trim</literal></entry>
1031 1032
     </row>

1033 1034 1035 1036 1037 1038 1039 1040 1041 1042
     <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>

1043
     <row>
1044
      <entry><function>repeat</function>(<type>text</type>, <type>integer</type>)</entry>
1045 1046
      <entry><type>text</type></entry>
      <entry>Repeat text a number of times.</entry>
1047 1048
      <entry><literal>repeat('Pg', 4)</literal></entry>
      <entry><literal>PgPgPgPg</literal></entry>
1049 1050 1051 1052
     </row>

     <row>
      <entry>
1053
       <function>rpad</function>(<parameter>string</parameter> <type>text</type>,
1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064
       <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>
1065 1066
      <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
      <entry><literal>hixyx</literal></entry>
1067 1068 1069
     </row>

     <row>
1070
      <entry><function>rtrim</function>(<parameter>string</parameter> text, <parameter>trim</parameter> text)</entry>
1071 1072 1073 1074 1075
      <entry><type>text</type></entry>
      <entry>
       Removes the longest string containing only characters from
       <parameter>trim</parameter> from the end of the string.
      </entry>
1076 1077
      <entry><literal>rtrim('trimxxxx','x')</literal></entry>
      <entry><literal>trim</literal></entry>
1078 1079 1080
     </row>

     <row>
1081
      <entry><function>strpos</function>(<parameter>string</parameter>, <parameter>substring</parameter>)</entry>
1082 1083 1084 1085 1086 1087 1088
      <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>
1089 1090
      <entry><literal>strpos('high','ig')</literal></entry>
      <entry><literal>2</literal></entry>
1091 1092 1093
     </row>

     <row>
1094
      <entry><function>substr</function>(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</entry>
1095 1096 1097 1098
      <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>
1099 1100
      <entry><literal>substr('alphabet', 3, 2)</literal></entry>
      <entry><literal>ph</literal></entry>
1101 1102 1103
     </row>

     <row>
1104
      <entry><function>to_ascii</function>(<type>text</type> <optional>, <parameter>encoding</parameter></optional>)</entry>
1105 1106
      <entry><type>text</type></entry>
      <entry>Converts text from multibyte encoding to <acronym>ASCII</acronym>.</entry>
1107 1108
      <entry><literal>to_ascii('Karel')</literal></entry>
      <entry><literal>Karel</literal></entry>
1109 1110 1111 1112
     </row>

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

     <row>
      <entry>
1144
       <function>decode</function>(<parameter>string</parameter> <type>text</type>,
1145 1146 1147 1148 1149 1150 1151
              <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>
1152 1153
      <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
      <entry><literal>123\000\001</literal></entry>
1154
     </row>       
1155 1156 1157 1158 1159 1160 1161 1162 1163 1164 1165 1166

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

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


1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 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
 <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>


1347 1348 1349 1350 1351
 <sect1 id="functions-matching">
  <title>Pattern Matching</title>

  <para>
   There are two separate approaches to pattern matching provided by
1352
   <productname>PostgreSQL</productname>:  the <acronym>SQL</acronym>
1353 1354 1355
   <function>LIKE</function> operator and
   <acronym>POSIX</acronym>-style regular expressions.
  </para>
1356

1357
  <tip>
1358
   <para>
1359 1360 1361
    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.
1362
   </para>
1363 1364 1365 1366 1367
  </tip>

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

1368 1369 1370 1371
   <indexterm>
    <primary>like</primary>
   </indexterm>

1372 1373 1374 1375
<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>
1376 1377

   <para>
1378 1379 1380 1381 1382 1383 1384 1385 1386
    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>.)
1387 1388
   </para>

1389 1390
   <para>
    If <replaceable>pattern</replaceable> does not contain percent
1391
    signs or underscore, then the pattern only represents the string
1392 1393 1394
    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
1395 1396
    character; a percent sign (<literal>%</literal>) matches any string
    of zero or more characters.
1397 1398 1399 1400 1401 1402 1403 1404 1405 1406 1407 1408 1409
   </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>
1410

T
Thomas G. Lockhart 已提交
1411
   <para>
1412
    <function>LIKE</function> pattern matches always cover the entire
1413
    string.  To match a pattern anywhere within a string, the
1414
    pattern must therefore start and end with a percent sign.
T
Thomas G. Lockhart 已提交
1415
   </para>
1416 1417

   <para>
1418 1419 1420 1421
    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
1422
    character is the backslash but a different one may be selected by
1423 1424 1425 1426 1427 1428 1429
    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
1430 1431 1432 1433 1434 1435 1436 1437 1438 1439 1440 1441 1442
    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
    character with <literal>ESCAPE</literal>; then backslash isn't special
    to <function>LIKE</> anymore. (But it's still special to the string
    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.
1443
   </para>
1444 1445

   <para>
1446 1447
    The keyword <token>ILIKE</token> can be used instead of
    <token>LIKE</token> to make the match case insensitive according
1448
    to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
1449
    <productname>PostgreSQL</productname> extension.
T
Thomas G. Lockhart 已提交
1450
   </para>
1451

1452 1453
   <para>
    The operator <literal>~~</literal> is equivalent to
1454 1455 1456
    <function>LIKE</function>, and <literal>~~*</literal> corresponds to
    <function>ILIKE</function>.  There are also
    <literal>!~~</literal> and <literal>!~~*</literal> operators that
1457
    represent <function>NOT LIKE</function> and <function>NOT
1458
    ILIKE</function>.  All of these operators are
1459
    <productname>PostgreSQL</productname>-specific.
1460 1461
   </para>
  </sect2>
1462

1463 1464

  <sect2 id="functions-regexp">
1465
   <title><acronym>POSIX</acronym> Regular Expressions</title>
1466

1467 1468 1469 1470 1471
   <indexterm zone="functions-regexp">
    <primary>regular expressions</primary>
    <seealso>pattern matching</seealso>
   </indexterm>

1472 1473 1474 1475 1476 1477 1478 1479 1480 1481 1482 1483 1484 1485 1486 1487
   <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>
1488
	<ENTRY><literal>'thomas' ~ '.*thomas.*'</literal></ENTRY>
1489 1490 1491 1492
       </ROW>
       <ROW>
	<ENTRY> <literal>~*</literal> </ENTRY>
	<ENTRY>Matches regular expression, case insensitive</ENTRY>
1493
	<ENTRY><literal>'thomas' ~* '.*Thomas.*'</literal></ENTRY>
1494 1495 1496 1497
       </ROW>
       <ROW>
	<ENTRY> <literal>!~</literal> </ENTRY>
	<ENTRY>Does not match regular expression, case sensitive</ENTRY>
1498
	<ENTRY><literal>'thomas' !~ '.*Thomas.*'</literal></ENTRY>
1499 1500 1501 1502
       </ROW>
       <ROW>
	<ENTRY> <literal>!~*</literal> </ENTRY>
	<ENTRY>Does not match regular expression, case insensitive</ENTRY>
1503
	<ENTRY><literal>'thomas' !~* '.*vadim.*'</literal></ENTRY>
1504 1505 1506 1507 1508
       </ROW>
     </tbody>
    </tgroup>
   </table>

1509
   <para>
1510
    <acronym>POSIX</acronym> regular expressions provide a more powerful means for
1511 1512 1513 1514 1515 1516 1517 1518 1519 1520 1521 1522 1523 1524 1525 1526 1527 1528 1529 1530 1531
    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>

1532 1533

<!-- derived from the re_format.7 man page -->
T
Thomas G. Lockhart 已提交
1534
   <para>
1535
    Regular expressions (<quote>RE</quote>s), as defined in <acronym>POSIX</acronym>
1536 1537 1538
    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
1539
    <command>ed</command>; 1003.2 <quote>basic</quote> REs).
1540
    <productname>PostgreSQL</productname> implements the modern form.
T
Thomas G. Lockhart 已提交
1541
   </para>
1542

T
Thomas G. Lockhart 已提交
1543
   <para>
1544 1545 1546 1547
    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.
T
Thomas G. Lockhart 已提交
1548
   </para>
1549

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

B
Bruce Momjian 已提交
1556
   <para>
1557 1558 1559 1560 1561 1562 1563 1564
    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.
B
Bruce Momjian 已提交
1565
   </para>
1566

1567 1568 1569 1570 1571 1572 1573 1574 1575 1576 1577 1578 1579 1580 1581 1582 1583 1584 1585 1586 1587 1588 1589 1590 1591 1592 1593 1594
   <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>
1595

1596
   <para>
1597 1598 1599 1600 1601
    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),
1602 1603 1604
    <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
1605 1606 1607 1608 1609 1610 1611 1612 1613
    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>.
1614
   </para>
1615

1616 1617 1618 1619 1620 1621 1622
   <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>

T
Thomas G. Lockhart 已提交
1623
   <para>
1624 1625 1626 1627 1628 1629 1630 1631 1632 1633 1634 1635 1636
    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.
T
Thomas G. Lockhart 已提交
1637
   </para>
1638

T
Thomas G. Lockhart 已提交
1639
   <para>
1640 1641 1642 1643 1644 1645 1646 1647 1648 1649 1650 1651 1652 1653 1654
    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
1655
    multiple-character sequence that collates as if it were a single
1656 1657 1658 1659
    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
1660
    expression containing a multiple-character collating element can thus
1661 1662 1663 1664 1665 1666 1667 1668 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
    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
1707
    specified by <acronym>POSIX</acronym> 1003.2, and should be used with caution in
1708 1709 1710 1711 1712 1713 1714 1715 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
    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
1759 1760 1761 1762 1763 1764 1765 1766
    space.
    <footnote>
     <para>
      This was written in 1994, mind you.  The
      numbers have probably changed, but the problem
      persists.
     </para>
    </footnote>
T
Thomas G. Lockhart 已提交
1767
   </para>
1768 1769
<!-- end re_format.7 man page -->
  </sect2>
1770

1771 1772 1773 1774
 </sect1>


  <sect1 id="functions-formatting">
1775
   <title>Data Type Formatting Functions</title>
1776

1777 1778 1779 1780
   <indexterm zone="functions-formatting">
    <primary>formatting</primary>
   </indexterm>

1781 1782 1783
   <note>
    <title>Author</title>
    <para>
1784
     Written by Karel Zak (<email>zakkr@zf.jcu.cz</email>) on 2000-01-24
1785 1786
    </para>
   </note>
1787

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

1864 1865 1866 1867 1868 1869 1870 1871 1872
   <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
    copied verbatim.  Similarly, in an input template string template patterns
    identify the parts of the input data string to be looked at and the
    values to be found there.
   </para>

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

   <para>
2062 2063 2064 2065
    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.
2066 2067 2068 2069
   </para>

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

   <para>
2111 2112 2113
    Usage notes:

    <itemizedlist>
2114 2115 2116 2117 2118 2119 2120 2121
     <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>

2122 2123 2124
     <listitem>
      <para>
       <function>to_timestamp</function> and <function>to_date</function>
2125
       skip multiple blank spaces in the input string if the <literal>FX</literal> option 
2126 2127 2128
       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
2129 2130
       <literal>to_timestamp('2000    JUN','FXYYYY MON')</literal> returns an error,
       because <function>to_timestamp</function> expects one blank space only.
2131 2132 2133 2134 2135
      </para>
     </listitem>

     <listitem>
      <para>
2136 2137 2138 2139
       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
2140
       any string constant in <productname>PostgreSQL</productname>.
2141 2142 2143 2144 2145
      </para>
     </listitem>

     <listitem>
      <para>
2146
       Ordinary text is allowed in <function>to_char</function>
2147 2148 2149 2150 2151 2152
       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.
2153 2154 2155 2156 2157
      </para>
     </listitem>

     <listitem>
      <para>
2158 2159 2160
       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 :-) -->
2161 2162
      </para>
     </listitem>
2163 2164 2165

     <listitem>
      <para>
2166 2167
       <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
P
Peter Eisentraut 已提交
2168
       use some non-digit character or template after <literal>YYYY</literal>,
2169
       otherwise the year is always interpreted as 4 digits. For example
P
Peter Eisentraut 已提交
2170 2171
       (with year 20000):
       <literal>to_date('200001131', 'YYYYMMDD')</literal> will be 
2172
       interpreted as a 4-digit year; better is to use a non-digit 
P
Peter Eisentraut 已提交
2173 2174 2175
       separator after the year, like
       <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
       <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
2176 2177
      </para>
     </listitem>
B
Bruce Momjian 已提交
2178 2179 2180

     <listitem>
      <para>
2181 2182
       Millisecond <literal>MS</literal> and microsecond <literal>US</literal>
       values are in conversion from string to time stamp used as part of
B
Bruce Momjian 已提交
2183 2184 2185 2186
       second after decimal point. For example 
       <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
       but 300, because the conversion count it as <literal>12 + 0.3</literal>.
       It means for format 'SS:MS' is '12:3' or '12:30' or '12:300' same
2187 2188
       number of milliseconds. For the three milliseconds must be used
       '12:003' that the conversion count as
B
Bruce Momjian 已提交
2189 2190 2191 2192 2193 2194
       <literal> 12 + 0.003 = 12.003 seconds </literal>. Here is a more 
       complex example: 
       <literal>to_timestamp('15:12:02.020.001230','HH:MI:SS.MS.US')</literal>
       is 15 hours, 12 minutes, 2.021230 seconds. 
      </para>
     </listitem>
2195
    </itemizedlist>
2196
   </para>
2197

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

   <para>
2280 2281 2282 2283 2284 2285 2286 2287 2288 2289 2290
    Usage notes:

    <itemizedlist>
     <listitem>
      <para>
       A sign formatted using 'SG', 'PL' or 'MI' is not an anchor in
       the number; for example,
       to_char(-12, 'S9999') produces <literal>'  -12'</literal>,
       but to_char(-12, 'MI9999') produces <literal>'-  12'</literal>.
       The Oracle implementation does not allow the use of
       <literal>MI</literal> ahead of <literal>9</literal>, but rather
2291
       requires that <literal>9</literal> precede
2292 2293 2294 2295 2296 2297
       <literal>MI</literal>.
      </para>
     </listitem>

     <listitem>
      <para>
2298 2299 2300
       <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.
2301 2302 2303 2304 2305
      </para>
     </listitem>

     <listitem>
      <para>
2306 2307
       <literal>TH</literal> does not convert values less than zero
       and does not convert decimal numbers.
2308 2309 2310 2311 2312
      </para>
     </listitem>

     <listitem>
      <para>
2313
       <literal>PL</literal>, <literal>SG</literal>, and
2314
       <literal>TH</literal> are <productname>PostgreSQL</productname>
2315
       extensions. 
2316 2317 2318 2319 2320 2321 2322 2323 2324 2325 2326
      </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
2327 2328
       <literal>V</literal> combined with a decimal point.
       (E.g., <literal>99.9V99</literal> is not allowed.)
2329 2330 2331
      </para>
     </listitem>
    </itemizedlist>
2332
   </para>   
2333 2334 2335

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


2484
  <sect1 id="functions-datetime">
2485
   <title>Date/Time Functions and Operators</title>
2486

2487
   <para>
2488
    <xref linkend="functions-datetime-table"> shows the available
2489 2490 2491 2492 2493
    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
2494 2495 2496
    linkend="functions-formatting">.  You should be familiar with the
    background information on date/time data types (see <xref
    linkend="datatype-datetime">).
2497
   </para>
2498

2499 2500 2501 2502 2503 2504 2505
   <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>

2506
     <tgroup cols="3">
2507 2508 2509 2510 2511 2512 2513 2514 2515 2516
      <thead>
       <row>
        <entry>Name</entry>
        <entry>Example</entry>
        <entry>Result</entry>
       </row>
      </thead>

      <tbody>
       <row>
2517
        <entry> <literal>+</literal> </entry>
2518 2519 2520 2521 2522
        <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>
2523
        <entry> <literal>+</literal> </entry>
2524 2525 2526 2527 2528
        <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>
2529
        <entry> <literal>+</literal> </entry>
2530 2531 2532 2533 2534
        <entry><type>time</type> '01:00' + <type>interval</type> '3 hours'</entry>
        <entry><type>time</type> '04:00'</entry>
       </row>

       <row>
2535
        <entry> <literal>-</literal> </entry>
2536 2537 2538 2539 2540
        <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>
2541
        <entry> <literal>-</literal> </entry>
2542 2543 2544 2545 2546
        <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>
2547
        <entry> <literal>-</literal> </entry>
2548 2549 2550 2551 2552
        <entry><type>time</type> '05:00' + <type>interval</type> '2 hours'</entry>
        <entry><type>time</type> '03:00'</entry>
       </row>

       <row>
2553
        <entry> <literal>-</literal> </entry>
2554 2555 2556 2557 2558 2559 2560 2561 2562 2563 2564 2565 2566 2567 2568 2569 2570 2571 2572 2573 2574 2575 2576 2577
        <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.

2578
    <table id="functions-datetime-table">
2579
     <title>Date/Time Functions</title>
2580
     <tgroup cols="5">
2581 2582
      <thead>
       <row>
2583 2584
	<entry>Name</entry>
	<entry>Return Type</entry>
2585 2586
	<entry>Description</entry>
	<entry>Example</entry>
2587
	<entry>Result</entry>
2588 2589
       </row>
      </thead>
2590

2591 2592
      <tbody>
       <row>
2593 2594
	<entry><function>age</function>(<type>timestamp</type>)</entry>
	<entry><type>interval</type></entry>
2595
	<entry>Subtract from today</entry>
2596 2597
	<entry><literal>age(timestamp '1957-06-13')</literal></entry>
	<entry><literal>43 years 8 mons 3 days</literal></entry>
2598
       </row>
2599

2600
       <row>
2601 2602
	<entry><function>age</function>(<type>timestamp</type>, <type>timestamp</type>)</entry>
	<entry><type>interval</type></entry>
2603
	<entry>Subtract arguments</entry>
2604 2605
	<entry><literal>age('2001-04-10', timestamp '1957-06-13')</literal></entry>
	<entry><literal>43 years 9 mons 27 days</literal></entry>
2606 2607 2608
       </row>

       <row>
2609 2610
	<entry><function>current_date</function></entry>
	<entry><type>date</type></entry>
2611
	<entry>Today's date; see <link
2612 2613 2614 2615
	 linkend="functions-datetime-current">below</link>
	</entry>
	<entry></entry>
	<entry></entry>
2616
       </row>
2617 2618

       <row>
2619 2620
	<entry><function>current_time</function></entry>
	<entry><type>time</type></entry>
2621
	<entry>Time of day; see <link
2622 2623 2624 2625 2626 2627
	 linkend="functions-datetime-current">below</link>
	</entry>
	<entry></entry>
	<entry></entry>
       </row>

2628
       <row>
2629 2630
	<entry><function>current_timestamp</function></entry>
	<entry><type>timestamp</type></entry>
2631
	<entry>date and time; see also <link
2632 2633 2634 2635 2636 2637 2638
	 linkend="functions-datetime-current">below</link>
	</entry>
	<entry></entry>
	<entry></entry>
       </row>

       <row>
2639 2640
	<entry><function>date_part</function>(<type>text</type>, <type>timestamp</type>)</entry>
	<entry><type>double precision</type></entry>
2641
	<entry>Get subfield (equivalent to
2642 2643 2644
	 <function>extract</function>); see also <link
	 linkend="functions-datetime-datepart">below</link>
        </entry>
2645 2646
	<entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
	<entry><literal>20</literal></entry>
2647
       </row>
2648

2649
       <row>
2650 2651
	<entry><function>date_part</function>(<type>text</type>, <type>interval</type>)</entry>
	<entry><type>double precision</type></entry>
2652
	<entry>Get subfield (equivalent to
2653 2654 2655
	 <function>extract</function>); see also <link
	 linkend="functions-datetime-datepart">below</link>
        </entry>
2656 2657
	<entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
	<entry><literal>3</literal></entry>
2658
       </row>
2659

2660
       <row>
2661 2662
	<entry><function>date_trunc</function>(<type>text</type>, <type>timestamp</type>)</entry>
	<entry><type>timestamp</type></entry>
2663
	<entry>Truncate to specified precision; see also <link
2664 2665
         linkend="functions-datetime-trunc">below</link>
        </entry>
2666 2667
	<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>
2668
       </row>
2669

2670
       <row>
2671 2672
	<entry><function>extract</function>(<parameter>field</parameter> from <type>timestamp</type>)</entry>
	<entry><type>double precision</type></entry>
2673
	<entry>Get subfield; see also <link
2674 2675
         linkend="functions-datetime-extract">below</link>
        </entry>
2676 2677
	<entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
	<entry><literal>20</literal></entry>
2678
       </row>
2679 2680

       <row>
2681 2682
	<entry><function>extract</function>(<parameter>field</parameter> from <type>interval</type>)</entry>
	<entry><type>double precision</type></entry>
2683
	<entry>Get subfield; see also <link
2684 2685
         linkend="functions-datetime-extract">below</link>
        </entry>
2686 2687
	<entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
	<entry><literal>3</literal></entry>
2688 2689
       </row>

2690
       <row>
2691 2692
	<entry><function>isfinite</function>(<type>timestamp</type>)</entry>
	<entry><type>boolean</type></entry>
2693
	<entry>Test for finite time stamp (neither invalid nor infinity)</entry>
2694 2695
	<entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
	<entry><literal>true</literal></entry>
2696
       </row>
2697

2698
       <row>
2699 2700
	<entry><function>isfinite</function>(<type>interval</type>)</entry>
	<entry><type>boolean</type></entry>
2701
	<entry>Test for finite interval</entry>
2702 2703
	<entry><literal>isfinite(interval '4 hours')</literal></entry>
	<entry><literal>true</literal></entry>
2704
       </row>
2705

2706
       <row>
2707 2708
	<entry><function>now</function>()</entry>
	<entry><type>timestamp</type></entry>
2709
	<entry>Current date and time (equivalent to
2710 2711 2712 2713 2714
	 <function>current_timestamp</function>); see also <link
	 linkend="functions-datetime-current">below</link>
	</entry>
	<entry></entry>
	<entry></entry>
2715
       </row>
2716

2717
       <row>
2718 2719
	<entry><function>timeofday()</function></entry>
	<entry><type>text</type></entry>
2720
	<entry>High-precision date and time; see also <link
2721 2722
	 linkend="functions-datetime-current">below</link>
	</entry>
2723 2724
	<entry><literal>timeofday()</literal></entry>
	<entry><literal>Wed Feb 21 17:01:13.000126 2001 EST</literal></entry>
2725 2726
       </row>

2727
       <row>
2728 2729 2730 2731 2732
	<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>
2733
       </row>
2734

2735
       <row>
2736 2737 2738 2739 2740
	<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>
2741 2742 2743 2744
       </row>
      </tbody>
     </tgroup>
    </table>
2745
   </para>
2746 2747 2748 2749 2750 2751 2752 2753 2754 2755 2756 2757 2758 2759 2760

  <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
2761 2762
    well.)  <replaceable>field</replaceable> is an identifier or
    string that selects what field to extract from the source value.
2763 2764 2765 2766 2767 2768 2769
    The <function>extract</function> function returns values of type
    <type>double precision</type>.
    The following are valid values:

    <!-- alphabetical -->
    <variablelist>
     <varlistentry>
2770
      <term><literal>century</literal></term>
2771 2772 2773 2774 2775 2776 2777 2778 2779 2780 2781 2782 2783
      <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>
2784 2785 2786
        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.
2787 2788 2789 2790 2791
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
2792
      <term><literal>day</literal></term>
2793 2794 2795 2796 2797 2798 2799 2800 2801 2802 2803 2804 2805 2806 2807
      <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>
2808
      <term><literal>decade</literal></term>
2809 2810 2811 2812 2813 2814 2815 2816 2817 2818 2819 2820 2821 2822 2823
      <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>
2824
      <term><literal>dow</literal></term>
2825 2826 2827 2828 2829 2830 2831 2832 2833 2834 2835 2836 2837 2838 2839 2840
      <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>
2841
      <term><literal>doy</literal></term>
2842 2843 2844 2845 2846 2847 2848 2849 2850 2851 2852 2853 2854 2855
      <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>
2856
      <term><literal>epoch</literal></term>
2857 2858 2859
      <listitem>
       <para>
        For <type>date</type> and <type>timestamp</type> values, the
2860
        number of seconds since 1970-01-01 00:00:00-00 (Result may be
2861 2862 2863 2864 2865 2866 2867 2868 2869 2870 2871 2872 2873 2874 2875 2876 2877
        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>
2878
      <term><literal>hour</literal></term>
2879 2880 2881 2882 2883 2884 2885 2886 2887 2888 2889 2890 2891 2892 2893
      <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>
2894
      <term><literal>microseconds</literal></term>
2895 2896 2897 2898 2899 2900 2901 2902 2903 2904 2905 2906 2907 2908 2909 2910
      <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>
2911
      <term><literal>millennium</literal></term>
2912 2913 2914 2915 2916 2917 2918 2919 2920 2921 2922 2923 2924
      <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>
2925 2926 2927
        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.
2928 2929 2930 2931 2932
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
2933
      <term><literal>milliseconds</literal></term>
2934 2935 2936 2937 2938 2939 2940 2941 2942 2943 2944 2945 2946 2947 2948 2949
      <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>
2950
      <term><literal>minute</literal></term>
2951 2952 2953 2954 2955 2956 2957 2958 2959 2960 2961 2962 2963 2964 2965
      <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>
2966
      <term><literal>month</literal></term>
2967 2968 2969 2970 2971 2972 2973 2974 2975 2976 2977 2978 2979 2980 2981 2982 2983 2984 2985 2986 2987 2988 2989
      <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>
2990
      <term><literal>quarter</literal></term>
2991 2992 2993 2994 2995 2996 2997 2998 2999 3000 3001 3002 3003 3004 3005 3006
      <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>
3007
      <term><literal>second</literal></term>
3008 3009 3010 3011 3012 3013 3014 3015 3016 3017 3018 3019 3020 3021 3022 3023 3024 3025
      <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>
3026 3027 3028 3029 3030 3031 3032 3033 3034 3035 3036 3037 3038 3039 3040 3041 3042 3043 3044 3045 3046 3047 3048 3049 3050 3051 3052 3053
<!--
     <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>
3054 3055

     <varlistentry>
3056
      <term><literal>week</literal></term>
3057 3058 3059 3060 3061 3062 3063 3064 3065 3066 3067 3068 3069 3070 3071 3072 3073 3074 3075 3076
      <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>
3077
      <term><literal>year</literal></term>
3078 3079 3080 3081 3082 3083 3084 3085 3086 3087 3088 3089 3090 3091 3092 3093
      <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>

3094 3095 3096
   </para>

   <para>
3097 3098 3099
    The <function>extract</function> function is primarily intended
    for computational processing.  For formatting date/time values for
    display, see <xref linkend="functions-formatting">.
3100
   </para>
3101 3102 3103

   <anchor id="functions-datetime-datepart">
   <para>
3104 3105
    The <function>date_part</function> function is modeled on the traditional
    <productname>Ingres</productname> equivalent to the
3106 3107 3108 3109 3110 3111 3112 3113 3114 3115 3116 3117 3118 3119 3120
    <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>

T
Tatsuo Ishii 已提交
3121
SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
3122 3123 3124 3125 3126 3127 3128 3129 3130 3131 3132 3133 3134 3135 3136 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
<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>

3182 3183 3184 3185 3186 3187 3188 3189 3190 3191
   <indexterm>
    <primary>date</primary>
    <secondary>current</secondary>
   </indexterm>

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

3192
   <para>
3193 3194
    The following functions are available to obtain the current date and/or
    time:
3195 3196 3197 3198 3199 3200 3201 3202 3203 3204 3205 3206 3207
<synopsis>
CURRENT_TIME
CURRENT_DATE
CURRENT_TIMESTAMP
</synopsis>
    Note that because of the requirements of the
    <acronym>SQL</acronym> standard, these functions must not be
    called with trailing parentheses.
   </para>

   <informalexample>
<screen>
SELECT CURRENT_TIME;
3208
<computeroutput>19:07:32</computeroutput>
3209 3210 3211 3212 3213

SELECT CURRENT_DATE;
<computeroutput>2001-02-17</computeroutput>

SELECT CURRENT_TIMESTAMP;
3214
<computeroutput>2001-02-17 19:07:32-05</computeroutput>
3215 3216 3217 3218 3219
</screen>
   </informalexample>

   <para>
    The function <function>now()</function> is the traditional
3220
    <productname>PostgreSQL</productname> equivalent to
3221
    <function>CURRENT_TIMESTAMP</function>.
3222 3223 3224 3225 3226 3227 3228 3229 3230 3231 3232 3233 3234 3235 3236 3237 3238 3239 3240 3241 3242
   </para>

   <para>
    There is also <function>timeofday()</function>, which returns current
    time to higher precision than the <function>CURRENT_TIMESTAMP</function>
    family does:
   </para>

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

   <para>
    <function>timeofday()</function> uses the operating system call
    <function>gettimeofday(2)</function>, which may have resolution as
    good as microseconds (depending on your platform); the other functions
    rely on <function>time(2)</function> which is restricted to one-second
    resolution.  For historical reasons, <function>timeofday()</function>
3243
    returns its result as a text string rather than a <type>timestamp</type> value.
3244 3245 3246 3247 3248 3249 3250 3251 3252 3253 3254
   </para>

   <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>
3255
    All the date/time data types also accept the special literal value
3256 3257
    <literal>now</> to specify the current date and time.  Thus,
    the following three all return the same result:
3258 3259 3260 3261 3262 3263 3264 3265
<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
3266
      value while creating a table.  The system will convert <literal>now</>
3267
      to a <type>timestamp</type> as soon as the constant is parsed, so that when
3268
      the default value is needed,
3269 3270
      the time of the table creation would be used!  The first two
      forms will not be evaluated until the default value is used,
3271 3272
      because they are function calls.  Thus they will give the desired
      behavior of defaulting to the time of row insertion.
3273 3274 3275 3276 3277
     </para>
    </note>
   </para>
  </sect2>
 </sect1>
3278 3279 3280 3281 3282 3283

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

   <para>
3284 3285 3286 3287
    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.
3288 3289 3290 3291 3292 3293 3294 3295 3296 3297 3298 3299 3300 3301 3302 3303
   </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>
3304
	<ENTRY><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></ENTRY>
3305 3306 3307 3308
       </ROW>
       <ROW>
	<ENTRY> - </ENTRY>
	<ENTRY>Translation</ENTRY>
3309
	<ENTRY><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></ENTRY>
3310 3311 3312 3313
       </ROW>
       <ROW>
	<ENTRY> * </ENTRY>
	<ENTRY>Scaling/rotation</ENTRY>
3314
	<ENTRY><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></ENTRY>
3315 3316 3317 3318
       </ROW>
       <ROW>
	<ENTRY> / </ENTRY>
	<ENTRY>Scaling/rotation</ENTRY>
3319
	<ENTRY><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></ENTRY>
3320 3321 3322 3323
       </ROW>
       <ROW>
	<ENTRY> # </ENTRY>
	<ENTRY>Intersection</ENTRY>
3324
	<ENTRY><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></ENTRY>
3325 3326 3327 3328
       </ROW>
       <ROW>
	<ENTRY> # </ENTRY>
	<ENTRY>Number of points in polygon</ENTRY>
3329
	<ENTRY><literal># '((1,0),(0,1),(-1,0))'</literal></ENTRY>
3330 3331 3332 3333
       </ROW>
       <ROW>
	<ENTRY> ## </ENTRY>
	<ENTRY>Point of closest proximity</ENTRY>
3334
	<ENTRY><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></ENTRY>
3335 3336 3337 3338
       </ROW>
       <ROW>
	<ENTRY> &amp;&amp; </ENTRY>
	<ENTRY>Overlaps?</ENTRY>
3339
	<ENTRY><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></ENTRY>
3340 3341 3342 3343
       </ROW>
       <ROW>
	<ENTRY> &amp;&lt; </ENTRY>
	<ENTRY>Overlaps to left?</ENTRY>
3344
	<ENTRY><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></ENTRY>
3345 3346 3347 3348
       </ROW>
       <ROW>
	<ENTRY> &amp;&gt; </ENTRY>
	<ENTRY>Overlaps to right?</ENTRY>
3349
	<ENTRY><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></ENTRY>
3350 3351 3352 3353
       </ROW>
       <ROW>
	<ENTRY> &lt;-&gt; </ENTRY>
	<ENTRY>Distance between</ENTRY>
3354
	<ENTRY><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></ENTRY>
3355 3356 3357 3358
       </ROW>
       <ROW>
	<ENTRY> &lt;&lt; </ENTRY>
	<ENTRY>Left of?</ENTRY>
3359
	<ENTRY><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></ENTRY>
3360 3361 3362 3363
       </ROW>
       <ROW>
	<ENTRY> &lt;^ </ENTRY>
	<ENTRY>Is below?</ENTRY>
3364
	<ENTRY><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></ENTRY>
3365 3366 3367 3368
       </ROW>
       <ROW>
	<ENTRY> &gt;&gt; </ENTRY>
	<ENTRY>Is right of?</ENTRY>
3369
	<ENTRY><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></ENTRY>
3370 3371 3372 3373
       </ROW>
       <ROW>
	<ENTRY> &gt;^ </ENTRY>
	<ENTRY>Is above?</ENTRY>
3374
	<ENTRY><literal>circle '((0,5),1)' >^ circle '((0,0),1)'</literal></ENTRY>
3375 3376 3377 3378
       </ROW>
       <ROW>
	<ENTRY> ?# </ENTRY>
	<ENTRY>Intersects or overlaps</ENTRY>
3379
	<ENTRY><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></ENTRY>
3380 3381 3382 3383
       </ROW>
       <ROW>
	<ENTRY> ?- </ENTRY>
	<ENTRY>Is horizontal?</ENTRY>
3384
	<ENTRY><literal>point '(1,0)' ?- point '(0,0)'</literal></ENTRY>
3385 3386 3387 3388
       </ROW>
       <ROW>
	<ENTRY> ?-| </ENTRY>
	<ENTRY>Is perpendicular?</ENTRY>
3389
	<ENTRY><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></ENTRY>
3390 3391 3392 3393
       </ROW>
       <ROW>
	<ENTRY> @-@  </ENTRY>
	<ENTRY>Length or circumference</ENTRY>
3394
	<ENTRY><literal>@-@ path '((0,0),(1,0))'</literal></ENTRY>
3395 3396 3397 3398
       </ROW>
       <ROW>
	<ENTRY> ?| </ENTRY>
	<ENTRY>Is vertical?</ENTRY>
3399
	<ENTRY><literal>point '(0,1)' ?| point '(0,0)'</literal></ENTRY>
3400 3401 3402 3403
       </ROW>
       <ROW>
	<ENTRY> ?|| </ENTRY>
	<ENTRY>Is parallel?</ENTRY>
3404
	<ENTRY><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></ENTRY>
3405 3406 3407 3408
       </ROW>
       <ROW>
	<ENTRY> @ </ENTRY>
	<ENTRY>Contained or on</ENTRY>
3409
	<ENTRY><literal>point '(1,1)' @ circle '((0,0),2)'</literal></ENTRY>
3410 3411 3412 3413
       </ROW>
       <ROW>
	<ENTRY> @@ </ENTRY>
	<ENTRY>Center of</ENTRY>
3414
	<ENTRY><literal>@@ circle '((0,0),10)'</literal></ENTRY>
3415 3416 3417 3418
       </ROW>
       <ROW>
	<ENTRY> ~= </ENTRY>
	<ENTRY>Same as</ENTRY>
3419
	<ENTRY><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></ENTRY>
3420 3421 3422 3423 3424 3425
       </ROW>
      </TBODY>
     </TGROUP>
   </TABLE>

   <table>
T
Thomas G. Lockhart 已提交
3426 3427 3428 3429 3430 3431 3432 3433 3434 3435 3436 3437
     <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>
3438 3439
	<entry><function>area</function>(object)</entry>
	<entry><type>double precision</type></entry>
3440
	<entry>area of item</entry>
3441
	<entry><literal>area(box '((0,0),(1,1))')</literal></entry>
T
Thomas G. Lockhart 已提交
3442 3443
       </row>
       <row>
3444 3445
	<entry><function>box</function>(box, box)</entry>
	<entry><type>box</type></entry>
3446
	<entry>intersection box</entry>
3447
	<entry><literal>box(box '((0,0),(1,1))',box '((0.5,0.5),(2,2))')</literal></entry>
T
Thomas G. Lockhart 已提交
3448 3449
       </row>
       <row>
3450 3451
	<entry><function>center</function>(object)</entry>
	<entry><type>point</type></entry>
3452
	<entry>center of item</entry>
3453
	<entry><literal>center(box '((0,0),(1,2))')</literal></entry>
T
Thomas G. Lockhart 已提交
3454 3455
       </row>
       <row>
3456 3457
	<entry><function>diameter</function>(circle)</entry>
	<entry><type>double precision</type></entry>
3458
	<entry>diameter of circle</entry>
3459
	<entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
T
Thomas G. Lockhart 已提交
3460 3461
       </row>
       <row>
3462 3463
	<entry><function>height</function>(box)</entry>
	<entry><type>double precision</type></entry>
3464
	<entry>vertical size of box</entry>
3465
	<entry><literal>height(box '((0,0),(1,1))')</literal></entry>
T
Thomas G. Lockhart 已提交
3466 3467
       </row>
       <row>
3468 3469
	<entry><function>isclosed</function>(path)</entry>
	<entry><type>boolean</type></entry>
3470
	<entry>a closed path?</entry>
3471
	<entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
T
Thomas G. Lockhart 已提交
3472 3473
       </row>
       <row>
3474 3475
	<entry><function>isopen</function>(path)</entry>
	<entry><type>boolean</type></entry>
3476
	<entry>an open path?</entry>
3477
	<entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
T
Thomas G. Lockhart 已提交
3478 3479
       </row>
       <row>
3480 3481
	<entry><function>length</function>(object)</entry>
	<entry><type>double precision</type></entry>
3482
	<entry>length of item</entry>
3483
	<entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
T
Thomas G. Lockhart 已提交
3484 3485
       </row>
       <row>
3486 3487
	<entry><function>pclose</function>(path)</entry>
	<entry><type>path</type></entry>
3488
	<entry>convert path to closed</entry>
3489
	<entry><literal>popen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
T
Thomas G. Lockhart 已提交
3490
       </row>
3491 3492
<![IGNORE[
<!-- Not defined by this name. Implements the intersection operator '#' -->
T
Thomas G. Lockhart 已提交
3493
       <row>
3494 3495
	<entry><function>point</function>(lseg,lseg)</entry>
	<entry><type>point</type></entry>
3496
	<entry>intersection</entry>
3497
	<entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
T
Thomas G. Lockhart 已提交
3498
       </row>
3499
]]>
T
Thomas G. Lockhart 已提交
3500
       <row>
3501 3502
	<entry><function>npoint</function>(path)</entry>
	<entry><type>integer</type></entry>
3503
	<entry>number of points</entry>
3504
	<entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
T
Thomas G. Lockhart 已提交
3505 3506
       </row>
       <row>
3507 3508
	<entry><function>popen</function>(path)</entry>
	<entry><type>path</type></entry>
3509
	<entry>convert path to open path</entry>
3510
	<entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
T
Thomas G. Lockhart 已提交
3511 3512
       </row>
       <row>
3513 3514
	<entry><function>radius</function>(circle)</entry>
	<entry><type>double precision</type></entry>
3515
	<entry>radius of circle</entry>
3516
	<entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
T
Thomas G. Lockhart 已提交
3517 3518
       </row>
       <row>
3519 3520
	<entry><function>width</function>(box)</entry>
	<entry><type>double precision</type></entry>
3521
	<entry>horizontal size</entry>
3522
	<entry><literal>width(box '((0,0),(1,1))')</literal></entry>
T
Thomas G. Lockhart 已提交
3523 3524 3525
       </row>
      </tbody>
     </tgroup>
3526
   </table>
3527

3528 3529

   <table>
T
Thomas G. Lockhart 已提交
3530 3531 3532 3533 3534 3535 3536 3537 3538 3539 3540 3541
     <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>
3542 3543
	<entry><function>box</function>(<type>circle</type>)</entry>
	<entry><type>box</type></entry>
3544
	<entry>circle to box</entry>
3545
	<entry><literal>box(circle '((0,0),2.0)')</literal></entry>
T
Thomas G. Lockhart 已提交
3546 3547
       </row>
       <row>
3548 3549
	<entry><function>box</function>(<type>point</type>, <type>point</type>)</entry>
	<entry><type>box</type></entry>
3550
	<entry>points to box</entry>
3551
	<entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
T
Thomas G. Lockhart 已提交
3552 3553
       </row>
       <row>
3554 3555
	<entry><function>box</function>(<type>polygon</type>)</entry>
	<entry><type>box</type></entry>
3556
	<entry>polygon to box</entry>
3557
	<entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
T
Thomas G. Lockhart 已提交
3558 3559
       </row>
       <row>
3560 3561
	<entry><function>circle</function>(<type>box</type>)</entry>
	<entry><type>circle</type></entry>
3562
	<entry>to circle</entry>
3563
	<entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
T
Thomas G. Lockhart 已提交
3564 3565
       </row>
       <row>
3566 3567
	<entry><function>circle</function>(<type>point</type>, <type>double precision</type>)</entry>
	<entry><type>circle</type></entry>
3568
	<entry>point to circle</entry>
3569
	<entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
T
Thomas G. Lockhart 已提交
3570 3571
       </row>
       <row>
3572 3573
	<entry><function>lseg</function>(<type>box</type>)</entry>
	<entry><type>lseg</type></entry>
3574
	<entry>box diagonal to lseg</entry>
3575
	<entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
T
Thomas G. Lockhart 已提交
3576 3577
       </row>
       <row>
3578 3579
	<entry><function>lseg</function>(<type>point</type>, <type>point</type>)</entry>
	<entry><type>lseg</type></entry>
3580
	<entry>points to lseg</entry>
3581
	<entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
T
Thomas G. Lockhart 已提交
3582 3583
       </row>
       <row>
3584 3585
	<entry><function>path</function>(<type>polygon</type>)</entry>
	<entry><type>point</type></entry>
3586
	<entry>polygon to path</entry>
3587
	<entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
T
Thomas G. Lockhart 已提交
3588 3589
       </row>
       <row>
3590 3591
	<entry><function>point</function>(<type>circle</type>)</entry>
	<entry><type>point</type></entry>
3592
	<entry>center</entry>
3593
	<entry><literal>point(circle '((0,0),2.0)')</literal></entry>
T
Thomas G. Lockhart 已提交
3594 3595
       </row>
       <row>
3596 3597
	<entry><function>point</function>(<type>lseg</type>, <type>lseg</type>)</entry>
	<entry><type>point</type></entry>
3598
	<entry>intersection</entry>
3599
	<entry><literal>point(lseg '((-1,0),(1,0))', lseg '((-2,-2),(2,2))')</literal></entry>
T
Thomas G. Lockhart 已提交
3600 3601
       </row>
       <row>
3602 3603
	<entry><function>point</function>(<type>polygon</type>)</entry>
	<entry><type>point</type></entry>
3604
	<entry>center</entry>
3605
	<entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
T
Thomas G. Lockhart 已提交
3606 3607
       </row>
       <row>
3608 3609
	<entry><function>polygon</function>(<type>box</type>)</entry>
	<entry><type>polygon</type></entry>
3610
	<entry>12 point polygon</entry>
3611
	<entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
T
Thomas G. Lockhart 已提交
3612 3613
       </row>
       <row>
3614 3615
	<entry><function>polygon</function>(<type>circle</type>)</entry>
	<entry><type>polygon</type></entry>
3616
	<entry>12-point polygon</entry>
3617
	<entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
T
Thomas G. Lockhart 已提交
3618 3619
       </row>
       <row>
3620 3621
	<entry><function>polygon</function>(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</entry>
	<entry><type>polygon</type></entry>
3622
	<entry><replaceable class="parameter">npts</replaceable> polygon</entry>
3623
	<entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
T
Thomas G. Lockhart 已提交
3624 3625
       </row>
       <row>
3626 3627
	<entry><function>polygon</function>(<type>path</type>)</entry>
	<entry><type>polygon</type></entry>
3628
	<entry>path to polygon</entry>
3629
	<entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
T
Thomas G. Lockhart 已提交
3630 3631 3632
       </row>
      </tbody>
     </tgroup>
3633 3634
   </table>

3635
  </sect1>
3636

3637 3638

  <sect1 id="functions-net">
3639
   <title>Network Address Type Functions</title>
3640

3641 3642 3643 3644 3645 3646 3647 3648 3649 3650 3651 3652 3653 3654 3655

    <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>
3656
	<ENTRY><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></ENTRY>
3657 3658 3659 3660
       </ROW>
       <ROW>
	<ENTRY> &lt;= </ENTRY>
	<ENTRY>Less than or equal</ENTRY>
3661
	<ENTRY><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></ENTRY>
3662 3663 3664 3665
       </ROW>
       <ROW>
	<ENTRY> = </ENTRY>
	<ENTRY>Equals</ENTRY>
3666
	<ENTRY><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></ENTRY>
3667 3668 3669 3670
       </ROW>
       <ROW>
	<ENTRY> &gt;= </ENTRY>
	<ENTRY>Greater or equal</ENTRY>
3671
	<ENTRY><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></ENTRY>
3672 3673 3674 3675
       </ROW>
       <ROW>
	<ENTRY> &gt; </ENTRY>
	<ENTRY>Greater</ENTRY>
3676
	<ENTRY><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></ENTRY>
3677 3678 3679 3680
       </ROW>
       <ROW>
	<ENTRY> &lt;&gt; </ENTRY>
	<ENTRY>Not equal</ENTRY>
3681
	<ENTRY><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></ENTRY>
3682 3683 3684 3685
       </ROW>
       <ROW>
	<ENTRY> &lt;&lt; </ENTRY>
	<ENTRY>is contained within</ENTRY>
3686
	<ENTRY><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></ENTRY>
3687 3688 3689 3690
       </ROW>
       <ROW>
	<ENTRY> &lt;&lt;= </ENTRY>
	<ENTRY>is contained within or equals</ENTRY>
3691
	<ENTRY><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></ENTRY>
3692 3693 3694 3695
       </ROW>
       <ROW>
	<ENTRY> &gt;&gt; </ENTRY>
	<ENTRY>contains</ENTRY>
3696
	<ENTRY><literal>inet'192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></ENTRY>
3697 3698 3699 3700
       </ROW>
       <ROW>
	<ENTRY> &gt;&gt;= </ENTRY>
	<ENTRY>contains or equals</ENTRY>
3701
	<ENTRY><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></ENTRY>
3702 3703 3704 3705 3706 3707 3708 3709 3710 3711 3712 3713 3714 3715 3716 3717
       </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>


3718 3719
    <table tocentry="1" id="cidr-inet-functions">
     <title><type>cidr</> and <type>inet</> Functions</title>
3720
     <tgroup cols="5">
T
Thomas G. Lockhart 已提交
3721 3722 3723 3724 3725 3726
      <thead>
       <row>
	<entry>Function</entry>
	<entry>Returns</entry>
	<entry>Description</entry>
	<entry>Example</entry>
3727
	<entry>Result</entry>
T
Thomas G. Lockhart 已提交
3728 3729 3730 3731
       </row>
      </thead>
      <tbody>
       <row>
3732 3733
	<entry><function>broadcast</function>(<type>inet</type>)</entry>
	<entry><type>inet</type></entry>
3734
	<entry>broadcast address for network</entry>
3735 3736
	<entry><literal>broadcast('192.168.1.5/24')</literal></entry>
	<entry><literal>192.168.1.255/24</literal></entry>
T
Thomas G. Lockhart 已提交
3737 3738
       </row>
       <row>
3739 3740
	<entry><function>host</function>(<type>inet</type>)</entry>
	<entry><type>text</type></entry>
3741
	<entry>extract IP address as text</entry>
3742 3743
	<entry><literal>host('192.168.1.5/24')</literal></entry>
	<entry><literal>192.168.1.5</literal></entry>
T
Thomas G. Lockhart 已提交
3744 3745
       </row>
       <row>
3746 3747
	<entry><function>masklen</function>(<type>inet</type>)</entry>
	<entry><type>integer</type></entry>
3748
	<entry>extract netmask length</entry>
3749 3750
	<entry><literal>masklen('192.168.1.5/24')</literal></entry>
	<entry><literal>24</literal></entry>
T
Thomas G. Lockhart 已提交
3751
       </row>
B
Bruce Momjian 已提交
3752
       <row>
3753 3754
	<entry><function>set_masklen</function>(<type>inet</type>,<type>integer</type>)</entry>
	<entry><type>inet</type></entry>
B
Bruce Momjian 已提交
3755
	<entry>set netmask length for inet value</entry>
3756 3757
	<entry><literal>set_masklen('192.168.1.5/24',16)</literal></entry>
	<entry><literal>192.168.1.5/16</literal></entry>
B
Bruce Momjian 已提交
3758
       </row>
T
Thomas G. Lockhart 已提交
3759
       <row>
3760 3761
	<entry><function>netmask</function>(<type>inet</type>)</entry>
	<entry><type>inet</type></entry>
3762
	<entry>construct netmask for network</entry>
3763 3764
	<entry><literal>netmask('192.168.1.5/24')</literal></entry>
	<entry><literal>255.255.255.0</literal></entry>
3765 3766
       </row>
       <row>
3767 3768
	<entry><function>network</function>(<type>inet</type>)</entry>
	<entry><type>cidr</type></entry>
3769
	<entry>extract network part of address</entry>
3770 3771
	<entry><literal>network('192.168.1.5/24')</literal></entry>
	<entry><literal>192.168.1.0/24</literal></entry>
3772 3773
       </row>
       <row>
3774 3775
	<entry><function>text</function>(<type>inet</type>)</entry>
	<entry><type>text</type></entry>
3776
	<entry>extract IP address and masklen as text</entry>
3777 3778
	<entry><literal>text(inet '192.168.1.5')</literal></entry>
	<entry><literal>192.168.1.5/32</literal></entry>
3779
       </row>
3780
       <row>
3781 3782
	<entry><function>abbrev</function>(<type>inet</type>)</entry>
	<entry><type>text</type></entry>
3783
	<entry>extract abbreviated display as text</entry>
3784 3785
	<entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
	<entry><literal>10.1/16</literal></entry>
3786
       </row>
3787 3788 3789 3790 3791 3792
      </tbody>
     </tgroup>
    </table>

   <para>
    All of the functions for <type>inet</type> can be applied to
3793 3794
    <type>cidr</type> values as well.  The <function>host</>(),
    <function>text</>(), and <function>abbrev</>() functions are primarily
B
Bruce Momjian 已提交
3795
    intended to offer alternative display formats. You can cast a text
3796 3797
    field to inet using normal casting syntax: <literal>inet(expression)</literal> or 
    <literal>colname::inet</literal>.
3798 3799 3800 3801 3802 3803 3804 3805 3806 3807 3808 3809 3810
   </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>
T
Thomas G. Lockhart 已提交
3811
       </row>
3812 3813
      </thead>
      <tbody>
3814
       <row>
3815 3816
	<entry><function>trunc</function>(<type>macaddr</type>)</entry>
	<entry><type>macaddr</type></entry>
3817
	<entry>set last 3 bytes to zero</entry>
3818 3819
	<entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
	<entry><literal>12:34:56:00:00:00</literal></entry>
3820
       </row>
T
Thomas G. Lockhart 已提交
3821 3822 3823
      </tbody>
     </tgroup>
    </table>
3824
   </para>
3825

3826
   <para>
3827 3828 3829 3830 3831
    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.
T
Thomas G. Lockhart 已提交
3832
   </para>
3833

3834 3835 3836 3837 3838 3839
   <para>
    The <type>macaddr</> type also supports the standard relational
    operators (<literal>&gt;</>, <literal>&lt;=</>, etc.) for
    lexicographical ordering.
   </para>

T
Thomas G. Lockhart 已提交
3840
  </sect1>
3841

3842

3843 3844 3845 3846 3847 3848 3849 3850 3851 3852 3853 3854 3855 3856 3857 3858 3859 3860 3861 3862 3863 3864 3865 3866 3867 3868 3869 3870 3871 3872 3873 3874 3875 3876 3877 3878 3879 3880 3881 3882 3883 3884 3885 3886 3887 3888 3889 3890 3891
 <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>
3892
   This section describes <productname>PostgreSQL</productname>'s functions
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 3922 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
   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>


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

4006 4007 4008 4009 4010 4011 4012 4013
  <indexterm>
   <primary>case</primary>
  </indexterm>

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

4014
  <para>
4015
   This section describes the <acronym>SQL</acronym>-compliant conditional expressions
4016
   available in <productname>PostgreSQL</productname>.
4017 4018 4019 4020 4021 4022 4023 4024 4025 4026 4027 4028 4029 4030 4031 4032 4033 4034 4035 4036 4037 4038
  </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
4039
   other languages.  <token>CASE</token> clauses can be used wherever
4040
   an expression is valid.  <replaceable>condition</replaceable> is an
4041
   expression that returns a <type>boolean</type> result.  If the result is true
4042 4043 4044 4045 4046 4047 4048 4049 4050 4051 4052 4053 4054 4055 4056 4057 4058 4059 4060 4061 4062 4063 4064
   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>

4065 4066 4067 4068 4069 4070
<prompt>=&gt;</prompt> <userinput>SELECT a,
          CASE WHEN a=1 THEN 'one'
               WHEN a=2 THEN 'two'
               ELSE 'other'
          END
    FROM test;</userinput>
4071 4072 4073 4074 4075 4076 4077 4078 4079 4080 4081 4082
<computeroutput>
 a | case
---+-------
 1 | one
 2 | two
 3 | other
</computeroutput>
</screen>
   </para>
  </informalexample>

  <para>
4083 4084 4085
   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.
4086 4087 4088 4089 4090 4091 4092 4093 4094 4095 4096 4097 4098 4099 4100 4101 4102 4103 4104 4105 4106 4107 4108 4109 4110 4111
  </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>
4112 4113 4114 4115 4116 4117
<prompt>=&gt;</prompt> <userinput>SELECT a,
          CASE a WHEN 1 THEN 'one'
                 WHEN 2 THEN 'two'
                 ELSE 'other'
          END
    FROM test;</userinput>
4118 4119 4120 4121 4122 4123 4124 4125 4126 4127 4128 4129 4130 4131 4132 4133 4134 4135 4136 4137 4138 4139 4140 4141 4142 4143 4144 4145 4146
<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>

4147 4148 4149 4150
  <indexterm>
   <primary>nullif</primary>
  </indexterm>

4151 4152 4153 4154 4155 4156 4157 4158 4159 4160 4161 4162 4163 4164 4165
<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>
4166 4167 4168 4169 4170 4171 4172 4173 4174 4175 4176 4177 4178

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

4179 4180 4181 4182
 </sect1>


  <sect1 id="functions-misc">
4183
   <title>Miscellaneous Functions</>
4184 4185

   <table>
4186
    <title>Session Information Functions</>
4187 4188
    <tgroup cols="3">
     <thead>
4189
      <row><entry>Name</> <entry>Return Type</> <entry>Description</></row>
4190 4191 4192 4193 4194 4195 4196 4197 4198
     </thead>

     <tbody>
      <row>
       <entry>current_user</>
       <entry>name</>
       <entry>user name of current execution context</>
      </row>
      <row>
4199
       <entry>session_user</>
4200
       <entry>name</>
4201
       <entry>session user name</>
4202 4203
      </row>
      <row>
4204
       <entry>user</>
4205
       <entry>name</>
4206
       <entry>equivalent to <function>current_user</></>
4207 4208 4209 4210 4211
      </row>
     </tbody>
    </tgroup>
   </table>

4212 4213 4214 4215 4216
   <indexterm zone="functions-misc">
    <primary>user</primary>
    <secondary>current</secondary>
   </indexterm>

4217 4218 4219 4220 4221 4222 4223 4224 4225 4226 4227 4228 4229 4230 4231 4232 4233 4234 4235 4236 4237 4238 4239
   <para>
    The <function>session_user</> is the user that initiated a database
    connection and is fixed for the duration of that connection. The
    <function>current_user</> is the user identifier that is applicable
    for permission checking. Currently it is always equal to the session
    user, but in the future there might be <quote>setuid</> functions and
    other facilities to allow the current user to change temporarily.
    In Unix parlance, the session user is the <quote>real user</>
    and the current user is the <quote>effective user</>.
   </para>

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

   <note>
    <title>Deprecated</>
    <para>
     The function <function>getpgusername()</> is an obsolete equivalent
     of <function>current_user</>.
    </para>
   </note>
4240 4241 4242 4243 4244 4245 4246 4247 4248 4249

   <table>
    <title>Access Privilege Inquiry Functions</>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</> <entry>Return Type</> <entry>Description</></row>
     </thead>

     <tbody>
      <row>
4250
       <entry><function>has_table_privilege</function>(<parameter>user</parameter>,
4251 4252 4253
                                  <parameter>table</parameter>,
                                  <parameter>access</parameter>)
       </entry>
4254
       <entry><type>boolean</type></>
4255 4256 4257
       <entry>does user have access to table</>
      </row>
      <row>
4258
       <entry><function>has_table_privilege</function>(<parameter>table</parameter>,
4259 4260
                                  <parameter>access</parameter>)
       </entry>
4261
       <entry><type>boolean</type></>
4262 4263 4264 4265 4266 4267 4268 4269 4270 4271 4272 4273 4274
       <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
4275
    specified by name or by ID (<classname>pg_user</>.<structfield>usesysid</>) or if the argument is omitted
4276 4277 4278 4279 4280 4281 4282 4283 4284 4285
    <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>

4286 4287 4288 4289 4290 4291 4292 4293 4294 4295 4296 4297 4298 4299 4300 4301 4302 4303 4304 4305 4306 4307 4308 4309 4310 4311
   <table>
    <title>System Information Functions</>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</> <entry>Return Type</> <entry>Description</></row>
     </thead>

     <tbody>
      <row>
       <entry>version</>
       <entry>text</>
       <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>

4312 4313
  </sect1>

4314

4315 4316
 <sect1 id="functions-aggregate">
  <title>Aggregate Functions</title>
4317

4318 4319
  <note>
   <title>Author</title>
4320
   <para>
4321
    Written by Isaac Wilcox <email>isaac@azartmedia.com</email> on 2000-06-16
4322
   </para>
4323
  </note>
4324

4325 4326 4327 4328 4329 4330 4331
  <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>
4332

4333 4334
  <table tocentry="1">
   <title>Aggregate Functions</title>
4335

4336 4337 4338 4339 4340 4341 4342 4343 4344 4345 4346 4347 4348 4349
   <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>
4350 4351 4352 4353
       <indexterm>
        <primary>average</primary>
        <secondary>function</secondary>
       </indexterm>
4354 4355 4356 4357 4358 4359 4360 4361 4362 4363 4364
       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>
4365
      <entry><function>count</function>(*)</entry>
4366
      <entry>number of input values</entry>
4367
      <entry>The return value is of type <type>bigint</type>.</entry>
4368 4369 4370
     </row>

     <row>
4371
      <entry><function>count</function>(<replaceable class="parameter">expression</replaceable>)</entry>
4372 4373 4374 4375
      <entry>
       Counts the input values for which the value of <replaceable
       class="parameter">expression</replaceable> is not NULL.
      </entry>
4376
      <entry>The return value is of type <type>bigint</type>.</entry>
4377 4378 4379
     </row>

     <row>
4380
      <entry><function>max</function>(<replaceable class="parameter">expression</replaceable>)</entry>
4381 4382 4383 4384 4385 4386 4387 4388
      <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>
4389
      <entry><function>min</function>(<replaceable class="parameter">expression</replaceable>)</entry>
4390 4391 4392 4393 4394 4395 4396 4397
      <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>
4398
      <entry><function>stddev</function>(<replaceable class="parameter">expression</replaceable>)</entry>
4399 4400
      <entry>the sample standard deviation of the input values</entry>
      <entry>
4401 4402 4403
       <indexterm>
        <primary>standard deviation</primary>
       </indexterm>
4404 4405 4406 4407 4408 4409 4410 4411 4412 4413
       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>
4414
      <entry><function>sum</function>(<replaceable class="parameter">expression</replaceable>)</entry>
4415 4416 4417 4418 4419 4420
      <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>.
4421 4422 4423
       The result is of type <type>bigint</type> for <type>smallint</type>
       or <type>integer</type> input, <type>numeric</type> for
       <type>bigint</type> 
4424 4425 4426 4427 4428 4429
       input, <type>double precision</type> for floating point input,
       otherwise the same as the input data type.
      </entry>
     </row>

     <row>
4430
      <entry><function>variance</function>(<replaceable class="parameter">expression</replaceable>)</entry>
4431 4432
      <entry>the sample variance of the input values</entry>
      <entry>
4433 4434 4435
       <indexterm>
        <primary>variance</primary>
       </indexterm>
4436
       The variance is the square of the standard deviation.  The
4437 4438
       supported data types and result types are the same as for
       standard deviation.
4439 4440 4441 4442 4443 4444
      </entry>
     </row>

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

4446 4447 4448 4449
  <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
4450 4451
   zero as one might expect.  <function>COALESCE</function> may be
   used to substitute zero for NULL when necessary.
4452
  </para>
4453

4454
 </sect1>
4455

4456
</chapter>
4457

4458 4459
<!-- Keep this comment at the end of the file
Local variables:
T
Thomas G. Lockhart 已提交
4460
mode:sgml
4461
sgml-omittag:nil
4462 4463 4464 4465 4466 4467 4468 4469
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
T
Thomas G. Lockhart 已提交
4470
sgml-local-catalogs:("/usr/lib/sgml/catalog")
4471 4472 4473
sgml-local-ecat-files:nil
End:
-->