func.sgml 220 KB
Newer Older
1
<!--
2
$Header: /cvsroot/pgsql/doc/src/sgml/func.sgml,v 1.132 2002/11/23 04:04:43 momjian Exp $
3
PostgreSQL documentation
4
-->
5

6 7 8 9 10
 <chapter id="functions">
  <title>Functions and Operators</title>

  <indexterm zone="functions">
   <primary>functions</primary>
11 12
  </indexterm>

13 14
  <indexterm zone="functions">
   <primary>operators</primary>
15 16
  </indexterm>

17
  <para>
18 19 20
   <productname>PostgreSQL</productname> provides a large number of
   functions and operators for the built-in data types.  Users can also
   define their own functions and operators, as described in the
21
   &cite-programmer;.  The
22 23 24 25
   <application>psql</application> commands <command>\df</command> and
   <command>\do</command> can be used to show the list of all actually
   available functions and operators, respectively.
  </para>
26

27 28 29 30 31 32 33
  <para>
   If you are concerned about portability then take note that most of
   the functions and operators described in this chapter, with the
   exception of the most trivial arithmetic and comparison operators
   and some explicitly marked functions, are not specified by the
   <acronym>SQL</acronym>
   standard. Some of this extended functionality is present in other
34
   <acronym>SQL</acronym> implementations, and in many cases this
35 36
   functionality is compatible and consistent between various products.
  </para>
37

38 39 40 41 42 43 44

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

   <indexterm zone="functions-logical">
    <primary>operators</primary>
    <secondary>logical</secondary>
45 46 47
   </indexterm>

   <indexterm>
48 49 50
    <primary>Boolean</primary>
    <secondary>operators</secondary>
    <see>operators, logical</see>
51 52
   </indexterm>

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

56 57 58 59
    <indexterm>
     <primary>and</primary>
     <secondary>operator</secondary>
    </indexterm>
60

61 62 63 64
    <indexterm>
     <primary>or</primary>
     <secondary>operator</secondary>
    </indexterm>
65

66 67 68 69
    <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

77
    <acronym>SQL</acronym> uses a three-valued Boolean logic where the null value represents
78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150
    <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>

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

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

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

152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174
       <row>
        <entry>FALSE</entry>
        <entry>TRUE</entry>
       </row>

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

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

   <indexterm zone="functions-comparison">
    <primary>comparison</primary>
    <secondary>operators</secondary>
   </indexterm>

175 176 177 178 179 180
   <para>
    The usual comparison operators are available, shown in <xref
    linkend="functions-comparison-table">.
   </para>

   <table id="functions-comparison-table">
181 182 183
    <title>Comparison Operators</title>
    <tgroup cols="2">
     <thead>
184
      <row>
185 186
       <entry>Operator</entry>
       <entry>Description</entry>
187
      </row>
188
     </thead>
189

190
     <tbody>
191
      <row>
192 193
       <entry> <literal>&lt;</literal> </entry>
       <entry>less than</entry>
194
      </row>
195 196

      <row>
197 198
       <entry> <literal>&gt;</literal> </entry>
       <entry>greater than</entry>
199
      </row>
200 201

      <row>
202 203
       <entry> <literal>&lt;=</literal> </entry>
       <entry>less than or equal to</entry>
204 205 206
      </row>

      <row>
207 208
       <entry> <literal>&gt;=</literal> </entry>
       <entry>greater than or equal to</entry>
209 210 211
      </row>

      <row>
212 213
       <entry> <literal>=</literal> </entry>
       <entry>equal</entry>
214 215 216
      </row>

      <row>
217 218
       <entry> <literal>&lt;&gt;</literal> or <literal>!=</literal> </entry>
       <entry>not equal</entry>
219 220 221
      </row>
     </tbody>
    </tgroup>
222
   </table>
223

224 225 226 227 228 229 230 231
   <note>
    <para>
     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.
    </para>
   </note>
232

233
   <para>
234 235 236 237 238 239
    Comparison operators are available for all data types where this
    makes sense.  All comparison operators are binary operators that
    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
    <literal>3</literal>).
240
   </para>
241

242 243 244 245 246 247
   <para>
    <indexterm>
     <primary>between</primary>
    </indexterm>
    In addition to the comparison operators, the special
    <token>BETWEEN</token> construct is available.
248
<synopsis>
Peter Eisentraut's avatar
Peter Eisentraut committed
249
<replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
250
</synopsis>
251
    is equivalent to
252
<synopsis>
Bruce Momjian's avatar
Bruce Momjian committed
253
<replaceable>a</replaceable> &gt;= <replaceable>x</replaceable> AND <replaceable>a</replaceable> &lt;= <replaceable>y</replaceable>
254
</synopsis>
255
    Similarly,
256
<synopsis>
Peter Eisentraut's avatar
Peter Eisentraut committed
257
<replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
258
</synopsis>
259
    is equivalent to
260
<synopsis>
Bruce Momjian's avatar
Bruce Momjian committed
261
<replaceable>a</replaceable> &lt; <replaceable>x</replaceable> OR <replaceable>a</replaceable> &gt; <replaceable>y</replaceable>
262
</synopsis>
263 264 265 266
    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>
Peter Eisentraut's avatar
Peter Eisentraut committed
267

268
   <para>
269
    To check whether a value is or is not null, use the constructs
270
<synopsis>
271 272
<replaceable>expression</replaceable> IS NULL
<replaceable>expression</replaceable> IS NOT NULL
273 274 275
</synopsis>
    or the equivalent, but nonstandard, constructs
<synopsis>
276 277
<replaceable>expression</replaceable> ISNULL
<replaceable>expression</replaceable> NOTNULL
278
</synopsis>
279
   </para>
280

281 282 283
   <para>
    Do <emphasis>not</emphasis> write
    <literal><replaceable>expression</replaceable> = NULL</literal>
284 285 286
    because <literal>NULL</> is not <quote>equal to</quote>
    <literal>NULL</>.  (The null value represents an unknown value,
    and it is not known whether two unknown values are equal.)
287
   </para>
288

289 290 291 292
   <para>
    Some applications may (incorrectly) require that
    <literal><replaceable>expression</replaceable> = NULL</literal>
    returns true if <replaceable>expression</replaceable> evaluates to
293
    the null value.  To support these applications, the run-time option
294 295 296 297 298 299 300
    <varname>transform_null_equals</varname> can be turned on (e.g.,
    <literal>SET transform_null_equals TO ON;</literal>).
    <productname>PostgreSQL</productname> will 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>
301

302 303
   <para>
    Boolean values can also be tested using the constructs
304
<synopsis>
305 306 307 308 309 310
<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
311
</synopsis>
312
    These are similar to <literal>IS NULL</literal> in that they will
313 314
    always return true or false, never a null value, even when the operand is null.
    A null input is treated as the logical value <quote>unknown</>.
315 316
   </para>
  </sect1>
317

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

321 322 323 324
   <para>
    Mathematical operators are provided for many
    <productname>PostgreSQL</productname> types. For types without
    common mathematical conventions for all possible permutations 
325
    (e.g., date/time types) we
326 327
    describe the actual behavior in subsequent sections.
   </para>
328

329 330 331 332 333
   <para>
    <xref linkend="functions-math-op-table"> shows the available mathematical operators.
   </para>

   <table id="functions-math-op-table">
334
    <title>Mathematical Operators</title>
335

336
    <tgroup cols="4">
337 338
     <thead>
      <row>
339 340
       <entry>Name</entry>
       <entry>Description</entry>
341 342 343 344 345 346 347
       <entry>Example</entry>
       <entry>Result</entry>
      </row>
     </thead>

     <tbody>
      <row>
348
       <entry> <literal>+</literal> </entry>
349
       <entry>addition</entry>
350 351
       <entry>2 + 3</entry>
       <entry>5</entry>
352
      </row>
353

354
      <row>
355
       <entry> <literal>-</literal> </entry>
356
       <entry>subtraction</entry>
357 358
       <entry>2 - 3</entry>
       <entry>-1</entry>
359
      </row>
360

361
      <row>
362
       <entry> <literal>*</literal> </entry>
363
       <entry>multiplication</entry>
364 365
       <entry>2 * 3</entry>
       <entry>6</entry>
366
      </row>
367

368
      <row>
369
       <entry> <literal>/</literal> </entry>
370
       <entry>division (integer division truncates results)</entry>
371 372
       <entry>4 / 2</entry>
       <entry>2</entry>
373
      </row>
374

375
      <row>
376
       <entry> <literal>%</literal> </entry>
377
       <entry>modulo (remainder)</entry>
378 379
       <entry>5 % 4</entry>
       <entry>1</entry>
380
      </row>
381

382
      <row>
383
       <entry> <literal>^</literal> </entry>
384
       <entry>exponentiation</entry>
385 386
       <entry>2.0 ^ 3.0</entry>
       <entry>8</entry>
387 388
      </row>

389 390
      <row>
       <entry> <literal>|/</literal> </entry>
391
       <entry>square root</entry>
392 393 394
       <entry>|/ 25.0</entry>
       <entry>5</entry>
      </row>
395

396 397
      <row>
       <entry> <literal>||/</literal> </entry>
398
       <entry>cube root</entry>
399 400 401
       <entry>||/ 27.0</entry>
       <entry>3</entry>
      </row>
402

403 404
      <row>
       <entry> <literal>!</literal> </entry>
405
       <entry>factorial</entry>
406 407 408
       <entry>5 !</entry>
       <entry>120</entry>
      </row>
409

410 411
      <row>
       <entry> <literal>!!</literal> </entry>
412
       <entry>factorial (prefix operator)</entry>
413 414 415
       <entry>!! 5</entry>
       <entry>120</entry>
      </row>
416

417 418
      <row>
       <entry> <literal>@</literal> </entry>
419
       <entry>absolute value</entry>
420 421 422
       <entry>@ -5.0</entry>
       <entry>5</entry>
      </row>
423

424 425
      <row>
       <entry> <literal>&amp;</literal> </entry>
426
       <entry>binary AND</entry>
427 428 429
       <entry>91 & 15</entry>
       <entry>11</entry>
      </row>
430

431 432
      <row>
       <entry> <literal>|</literal> </entry>
433
       <entry>binary OR</entry>
434 435 436
       <entry>32 | 3</entry>
       <entry>35</entry>
      </row>
437

438 439
      <row>
       <entry> <literal>#</literal> </entry>
440
       <entry>binary XOR</entry>
441 442 443
       <entry>17 # 5</entry>
       <entry>20</entry>
      </row>
444

445 446
      <row>
       <entry> <literal>~</literal> </entry>
447
       <entry>binary NOT</entry>
448 449 450
       <entry>~1</entry>
       <entry>-2</entry>
      </row>
451

452 453
      <row>
       <entry> &lt;&lt; </entry>
454
       <entry>binary shift left</entry>
455 456 457
       <entry>1 &lt;&lt; 4</entry>
       <entry>16</entry>
      </row>
458

459 460
      <row>
       <entry> &gt;&gt; </entry>
461
       <entry>binary shift right</entry>
462 463 464
       <entry>8 &gt;&gt; 2</entry>
       <entry>2</entry>
      </row>
465

466 467 468
     </tbody>
    </tgroup>
   </table>
469

470 471
   <para>
    The <quote>binary</quote> operators are also available for the bit
472 473 474 475 476 477
    string types <type>BIT</type> and <type>BIT VARYING</type>, as
    shown in <xref linkend="functions-math-bit-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 in the table.
   </para>
478

479
    <table id="functions-math-bit-table">
480
     <title>Bit String Binary Operators</title>
481

482 483 484 485 486 487 488
     <tgroup cols="2">
      <thead>
       <row>
        <entry>Example</entry>
        <entry>Result</entry>
       </row>
      </thead>
489

490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507
      <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>
508
        <entry>B'10001' &lt;&lt; 3</entry>
509 510 511
        <entry>01000</entry>
       </row>
       <row>
512
        <entry>B'10001' &gt;&gt; 2</entry>
513 514 515 516 517
        <entry>00100</entry>
       </row>
      </tbody>
     </tgroup>
    </table>
518

519 520 521 522 523 524 525 526 527 528 529 530 531 532 533
  <para>
   <xref linkend="functions-math-func-table"> shows the available
   mathematical functions.  In the table, <literal>dp</literal>
   indicates <type>double precision</type>.  The functions
   <function>exp</function>, <function>ln</function>,
   <function>log</function>, <function>pow</function>,
   <function>round</function> (1 argument), <function>sqrt</function>,
   and <function>trunc</function> (1 argument) are also available for
   the type <type>numeric</type> in place of <type>double
   precision</type>.  Functions returning a <type>numeric</type>
   result take <type>numeric</type> input arguments, unless otherwise
   specified.  Many of these functions are implemented on top of the
   host system's C library; accuracy and behavior in boundary cases
   could therefore vary depending on the host system.
  </para>
534

535
   <table id="functions-math-func-table">
536 537 538 539 540 541 542 543 544 545 546 547 548 549 550
    <title>Mathematical Functions</title>
    <tgroup cols="5">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Return Type</entry>
       <entry>Description</entry>
       <entry>Example</entry>
       <entry>Result</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry><function>abs</function>(<replaceable>x</replaceable>)</entry>
551
       <entry>(same as <replaceable>x</>)</entry>
552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678
       <entry>absolute value</entry>
       <entry><literal>abs(-17.4)</literal></entry>
       <entry>17.4</entry>
      </row>

      <row>
       <entry><function>cbrt</function>(<type>dp</type>)</entry>
       <entry><type>dp</type></entry>
       <entry>cube root</entry>
       <entry><literal>cbrt(27.0)</literal></entry>
       <entry>3</entry>
      </row>

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

      <row>
       <entry><function>degrees</function>(<type>dp</type>)</entry>
       <entry><type>dp</type></entry>
       <entry>radians to degrees</entry>
       <entry><literal>degrees(0.5)</literal></entry>
       <entry>28.6478897565412</entry>
      </row>

      <row>
       <entry><function>exp</function>(<type>dp</type>)</entry>
       <entry><type>dp</type></entry>
       <entry>exponential</entry>
       <entry><literal>exp(1.0)</literal></entry>
       <entry>2.71828182845905</entry>
      </row>

      <row>
       <entry><function>floor</function>(<type>numeric</type>)</entry>
       <entry><type>numeric</type></entry>
       <entry>largest integer not greater than argument</entry>
       <entry><literal>floor(-42.8)</literal></entry>
       <entry>-43</entry>
      </row>

      <row>
       <entry><function>ln</function>(<type>dp</type>)</entry>
       <entry><type>dp</type></entry>
       <entry>natural logarithm</entry>
       <entry><literal>ln(2.0)</literal></entry>
       <entry>0.693147180559945</entry>
      </row>

      <row>
       <entry><function>log</function>(<type>dp</type>)</entry>
       <entry><type>dp</type></entry>
       <entry>base 10 logarithm</entry>
       <entry><literal>log(100.0)</literal></entry>
       <entry>2</entry>
      </row>

      <row>
       <entry><function>log</function>(<parameter>b</parameter> <type>numeric</type>,
        <parameter>x</parameter> <type>numeric</type>)</entry>
       <entry><type>numeric</type></entry>
       <entry>logarithm to base <parameter>b</parameter></entry>
       <entry><literal>log(2.0, 64.0)</literal></entry>
       <entry>6.0000000000</entry>
      </row>

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

      <row>
       <entry><function>pi</function>()</entry>
       <entry><type>dp</type></entry>
       <entry><quote>Pi</quote> constant</entry>
       <entry><literal>pi()</literal></entry>
       <entry>3.14159265358979</entry>
      </row>

      <row>
       <entry><function>pow</function>(<parameter>e</parameter> <type>dp</type>,
        <parameter>n</parameter> <type>dp</type>)</entry>
       <entry><type>dp</type></entry>
       <entry>raise a number to exponent <parameter>e</parameter></entry>
       <entry><literal>pow(9.0, 3.0)</literal></entry>
       <entry>729</entry>
      </row>

      <row>
       <entry><function>radians</function>(<type>dp</type>)</entry>
       <entry><type>dp</type></entry>
       <entry>degrees to radians</entry>
       <entry><literal>radians(45.0)</literal></entry>
       <entry>0.785398163397448</entry>
      </row>

      <row>
       <entry><function>random</function>()</entry>
       <entry><type>dp</type></entry>
       <entry>value between 0.0 to 1.0</entry>
       <entry><literal>random()</literal></entry>
       <entry></entry>
      </row>

      <row>
       <entry><function>round</function>(<type>dp</type>)</entry>
       <entry><type>dp</type></entry>
       <entry>round to nearest integer</entry>
       <entry><literal>round(42.4)</literal></entry>
       <entry>42</entry>
      </row>

      <row>
       <entry><function>round</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type>)</entry>
       <entry><type>numeric</type></entry>
       <entry>round to <parameter>s</parameter> decimal places</entry>
       <entry><literal>round(42.4382, 2)</literal></entry>
       <entry>42.44</entry>
      </row>
679 680
<!--
     <row>
681
      <entry><function>setseed</function>(<replaceable>new-seed</replaceable>)</entry>
682
      <entry>set seed for subsequent random() calls</entry>
683
      <entry><literal>setseed(0.54823)</literal></entry>
684 685 686
      <entry></entry>
     </row>
-->
687 688 689 690 691 692 693
      <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>
694

695 696 697 698 699 700 701
      <row>
       <entry><function>sqrt</function>(<type>dp</type>)</entry>
       <entry><type>dp</type></entry>
       <entry>square root</entry>
       <entry><literal>sqrt(2.0)</literal></entry>
       <entry>1.4142135623731</entry>
      </row>
702

703 704 705 706 707 708 709
      <row>
       <entry><function>trunc</function>(<type>dp</type>)</entry>
       <entry><type>dp</type></entry>
       <entry>truncate toward zero</entry>
       <entry><literal>trunc(42.8)</literal></entry>
       <entry>42</entry>
      </row>
710

711 712
      <row>
       <entry><function>trunc</function>(<type>numeric</type>,
713
        <parameter>r</parameter> <type>integer</type>)</entry>
714 715 716 717 718
       <entry><type>numeric</type></entry>
       <entry>truncate to <parameter>s</parameter> decimal places</entry>
       <entry><literal>trunc(42.4382, 2)</literal></entry>
       <entry>42.43</entry>
      </row>
719

720 721 722
     </tbody>
    </tgroup>
   </table>
723

724 725 726 727 728 729
  <para>
   Finally, <xref linkend="functions-math-trig-table"> shows the
   available trigonometric functions.  All trigonometric functions
   have arguments and return values of type <type>double
   precision</type>.
  </para>
730

731
   <table id="functions-math-trig-table">
732
    <title>Trigonometric Functions</title>
733

734 735 736 737 738 739 740
    <tgroup cols="2">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Description</entry>
      </row>
     </thead>
741

742 743 744 745 746
     <tbody>
      <row>
       <entry><function>acos</function>(<replaceable>x</replaceable>)</entry>
       <entry>inverse cosine</entry>
      </row>
747

748 749 750 751
      <row>
       <entry><function>asin</function>(<replaceable>x</replaceable>)</entry>
       <entry>inverse sine</entry>
      </row>
752

753 754 755 756
      <row>
       <entry><function>atan</function>(<replaceable>x</replaceable>)</entry>
       <entry>inverse tangent</entry>
      </row>
757

758 759 760 761
      <row>
       <entry><function>atan2</function>(<replaceable>x</replaceable>,
        <replaceable>y</replaceable>)</entry>
       <entry>inverse tangent of
Bruce Momjian's avatar
Bruce Momjian committed
762
        <replaceable>x</replaceable>/<replaceable>y</replaceable></entry>
763
      </row>
764

765 766 767 768
      <row>
       <entry><function>cos</function>(<replaceable>x</replaceable>)</entry>
       <entry>cosine</entry>
      </row>
769

770 771 772 773
      <row>
       <entry><function>cot</function>(<replaceable>x</replaceable>)</entry>
       <entry>cotangent</entry>
      </row>
774

775 776 777 778
      <row>
       <entry><function>sin</function>(<replaceable>x</replaceable>)</entry>
       <entry>sine</entry>
      </row>
779

780 781 782 783 784 785 786
      <row>
       <entry><function>tan</function>(<replaceable>x</replaceable>)</entry>
       <entry>tangent</entry>
      </row>
     </tbody>
    </tgroup>
   </table>
787

788
  </sect1>
789 790


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

794 795 796 797 798 799 800 801 802 803 804 805
   <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
    to a string representation first.  Some functions also exist
    natively for bit-string types.
   </para>
806

807 808
   <para>
    <acronym>SQL</acronym> defines some string functions with a special syntax where
809
    certain key words rather than commas are used to separate the
810 811 812 813
    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>
814

815 816 817 818 819 820 821 822 823 824 825 826
   <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>
827

828 829 830 831 832 833
     <tbody>
      <row>
       <entry> <parameter>string</parameter> <literal>||</literal>
        <parameter>string</parameter> </entry>
       <entry> <type>text</type> </entry>
       <entry>
834
        String concatenation
835 836 837 838 839
        <indexterm>
         <primary>character strings</primary>
         <secondary>concatenation</secondary>
        </indexterm>
       </entry>
840
       <entry><literal>'Post' || 'greSQL'</literal></entry>
841 842
       <entry><literal>PostgreSQL</literal></entry>
      </row>
843

844 845 846
      <row>
       <entry><function>bit_length</function>(<parameter>string</parameter>)</entry>
       <entry><type>integer</type></entry>
847
       <entry>Number of bits in string</entry>
848 849 850
       <entry><literal>bit_length('jose')</literal></entry>
       <entry><literal>32</literal></entry>
      </row>
Peter Eisentraut's avatar
Peter Eisentraut committed
851

852 853 854 855
      <row>
       <entry><function>char_length</function>(<parameter>string</parameter>) or <function>character_length</function>(<parameter>string</parameter>)</entry>
       <entry><type>integer</type></entry>
       <entry>
856
        Number of characters in string
857 858 859 860 861 862 863 864 865 866 867 868 869
        <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>char_length('jose')</literal></entry>
       <entry><literal>4</literal></entry>
      </row>
870

Tatsuo Ishii's avatar
Tatsuo Ishii committed
871 872 873 874
      <row>
       <entry><function>convert</function>(<parameter>string</parameter>
       using <parameter>conversion_name</parameter>)</entry>
       <entry><type>text</type></entry>
875 876 877 878 879 880 881 882
       <entry>
        Change encoding using specified conversion name.  Conversions
        can be defined by <command>CREATE CONVERSION</command>.  Also
        there are some pre-defined conversion names. See <xref
        linkend="conversion-names"> for available conversion
        names.
       </entry>
       <entry><literal>convert('PostgreSQL' using iso_8859_1_to_utf_8)</literal></entry>
883
       <entry><literal>'PostgreSQL'</literal> in Unicode (UTF-8) encoding</entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
884 885
      </row>

886 887 888
      <row>
       <entry><function>lower</function>(<parameter>string</parameter>)</entry>
       <entry><type>text</type></entry>
889
       <entry>Convert string to lower case</entry>
890 891 892
       <entry><literal>lower('TOM')</literal></entry>
       <entry><literal>tom</literal></entry>
      </row>
893

894 895 896
      <row>
       <entry><function>octet_length</function>(<parameter>string</parameter>)</entry>
       <entry><type>integer</type></entry>
897
       <entry>Number of bytes in string</entry>
898 899 900
       <entry><literal>octet_length('jose')</literal></entry>
       <entry><literal>4</literal></entry>
      </row>
901

902 903 904 905
      <row>
       <entry><function>overlay</function>(<parameter>string</parameter> placing <parameter>string</parameter> from <type>integer</type> <optional>for <type>integer</type></optional>)</entry>
       <entry><type>text</type></entry>
       <entry>
906
        Insert substring
907 908 909 910 911 912 913
        <indexterm>
         <primary>overlay</primary>
        </indexterm>
       </entry>
       <entry><literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal></entry>
       <entry><literal>Thomas</literal></entry>
      </row>
914

915 916 917
      <row>
       <entry><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</entry>
       <entry><type>integer</type></entry>
918
       <entry>Location of specified substring</entry>
919 920 921
       <entry><literal>position('om' in 'Thomas')</literal></entry>
       <entry><literal>3</literal></entry>
      </row>
922

923 924 925 926
      <row>
       <entry><function>substring</function>(<parameter>string</parameter> <optional>from <type>integer</type></optional> <optional>for <type>integer</type></optional>)</entry>
       <entry><type>text</type></entry>
       <entry>
927
        Extract substring
928 929 930 931 932 933 934
        <indexterm>
         <primary>substring</primary>
        </indexterm>
       </entry>
       <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
       <entry><literal>hom</literal></entry>
      </row>
935

936
      <row>
937
       <entry><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</entry>
938 939
       <entry><type>text</type></entry>
       <entry>
940
        Extract substring matching POSIX regular expression
941 942 943 944
        <indexterm>
         <primary>substring</primary>
        </indexterm>
       </entry>
945
       <entry><literal>substring('Thomas' from '...$')</literal></entry>
946 947
       <entry><literal>mas</literal></entry>
      </row>
948

949 950 951 952
      <row>
       <entry><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</entry>
       <entry><type>text</type></entry>
       <entry>
953
        Extract substring matching SQL regular expression
954 955 956 957 958 959 960 961
        <indexterm>
         <primary>substring</primary>
        </indexterm>
       </entry>
       <entry><literal>substring('Thomas' from '%#"o_a#"_' for '#')</literal></entry>
       <entry><literal>oma</literal></entry>
      </row>

962 963 964 965 966 967 968 969
      <row>
       <entry>
        <function>trim</function>(<optional>leading | trailing | both</optional>
        <optional><parameter>characters</parameter></optional> from
        <parameter>string</parameter>)
       </entry>
       <entry><type>text</type></entry>
       <entry>
970
        Remove the longest string containing only the
971
        <parameter>characters</parameter> (a space by default) from the
972
        beginning/end/both ends of the <parameter>string</parameter>
973 974 975 976
       </entry>
       <entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
       <entry><literal>Tom</literal></entry>
      </row>
977

978 979 980
      <row>
       <entry><function>upper</function>(<parameter>string</parameter>)</entry>
       <entry><type>text</type></entry>
981
       <entry>Convert string to upper case</entry>
982 983 984 985 986 987
       <entry><literal>upper('tom')</literal></entry>
       <entry><literal>TOM</literal></entry>
      </row>
     </tbody>
    </tgroup>
   </table>
988

989 990
   <para>
    Additional string manipulation functions are available and are
991 992
    listed in <xref linkend="functions-string-other">.  Some of them are used internally to implement the
    <acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql">.
993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011
   </para>

   <table id="functions-string-other">
    <title>Other String Functions</title>
    <tgroup cols="5">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Return Type</entry>
       <entry>Description</entry>
       <entry>Example</entry>
       <entry>Result</entry>
      </row>
     </thead>

     <tbody>
      <row>
       <entry><function>ascii</function>(<type>text</type>)</entry>
       <entry>integer</entry>
1012
       <entry><acronym>ASCII</acronym> code of the first character of the argument.</entry>
1013 1014 1015 1016 1017 1018 1019 1020 1021 1022
       <entry><literal>ascii('x')</literal></entry>
       <entry><literal>120</literal></entry>
      </row>

      <row>
       <entry><function>btrim</function>(<parameter>string</parameter> <type>text</type>, <parameter>trim</parameter> <type>text</type>)</entry>
       <entry><type>text</type></entry>
       <entry>
        Remove (trim) the longest string consisting only of characters
        in <parameter>trim</parameter> from the start and end of
1023
        <parameter>string</parameter>
1024 1025 1026 1027 1028 1029 1030 1031
       </entry>
       <entry><literal>btrim('xyxtrimyyx','xy')</literal></entry>
       <entry><literal>trim</literal></entry>
      </row>

      <row>
       <entry><function>chr</function>(<type>integer</type>)</entry>
       <entry><type>text</type></entry>
1032
       <entry>Character with the given <acronym>ASCII</acronym> code</entry>
1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045
       <entry><literal>chr(65)</literal></entry>
       <entry><literal>A</literal></entry>
      </row>

      <row>
       <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>
       <entry><type>text</type></entry>
       <entry>
1046
        Convert string to <parameter>dest_encoding</parameter>.
1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062
        The original encoding is specified by
        <parameter>src_encoding</parameter>.  If
        <parameter>src_encoding</parameter> is omitted, database
        encoding is assumed.
       </entry>
       <entry><literal>convert('text_in_unicode', 'UNICODE', 'LATIN1')</literal></entry>
       <entry><literal>text_in_unicode</literal> represented in ISO 8859-1</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>
1063 1064
        Decode binary data from <parameter>string</parameter> previously 
        encoded with <function>encode()</>.  Parameter type is same as in <function>encode()</>.
1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076
       </entry>
       <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
       <entry><literal>123\000\001</literal></entry>
      </row>       

      <row>
       <entry>
        <function>encode</function>(<parameter>data</parameter> <type>bytea</type>,
        <parameter>type</parameter> <type>text</type>)
       </entry>
       <entry><type>text</type></entry>
       <entry>
1077 1078
        Encode binary data to <acronym>ASCII</acronym>-only representation.  Supported
        types are: base64, hex, escape.
1079 1080 1081 1082 1083 1084 1085 1086
       </entry>
       <entry><literal>encode('123\\000\\001', 'base64')</literal></entry>
       <entry><literal>MTIzAAE=</literal></entry>
      </row>       

      <row>
       <entry><function>initcap</function>(<type>text</type>)</entry>
       <entry><type>text</type></entry>
1087
       <entry>Convert first letter of each word (whitespace separated) to upper case</entry>
1088 1089 1090 1091 1092 1093 1094 1095
       <entry><literal>initcap('hi thomas')</literal></entry>
       <entry><literal>Hi Thomas</literal></entry>
      </row>

      <row>
       <entry><function>length</function>(<parameter>string</parameter>)</entry>
       <entry><type>integer</type></entry>
       <entry>
1096
        Length of string
1097 1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 1118
        <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')</literal></entry>
       <entry><literal>4</literal></entry>
      </row>

      <row>
       <entry>
        <function>lpad</function>(<parameter>string</parameter> <type>text</type>,
        <parameter>length</parameter> <type>integer</type>
        <optional>, <parameter>fill</parameter> <type>text</type></optional>)
       </entry>
       <entry>text</entry>
       <entry>
1119
        Fill up the <parameter>string</parameter> to length
1120 1121 1122 1123 1124 1125 1126 1127 1128 1129 1130 1131 1132 1133
        <parameter>length</parameter> by prepending the characters
        <parameter>fill</parameter> (a space by default).  If the
        <parameter>string</parameter> is already longer than
        <parameter>length</parameter> then it is truncated (on the
        right).
       </entry>
       <entry><literal>lpad('hi', 5, 'xy')</literal></entry>
       <entry><literal>xyxhi</literal></entry>
      </row>

      <row>
       <entry><function>ltrim</function>(<parameter>string</parameter> <type>text</type>, <parameter>text</parameter> <type>text</type>)</entry>
       <entry><type>text</type></entry>
       <entry>
1134
        Remove the longest string containing only characters from
1135 1136 1137 1138 1139 1140 1141 1142 1143 1144
        <parameter>trim</parameter> from the start of the string.
       </entry>
       <entry><literal>ltrim('zzzytrim','xyz')</literal></entry>
       <entry><literal>trim</literal></entry>
      </row>

      <row>
       <entry><function>pg_client_encoding</function>()</entry>
       <entry><type>name</type></entry>
       <entry>
1145
        Current client encoding name.
1146 1147 1148 1149 1150 1151 1152 1153 1154
       </entry>
       <entry><literal>pg_client_encoding()</literal></entry>
       <entry><literal>SQL_ASCII</literal></entry>
      </row>

      <row>
       <entry><function>quote_ident</function>(<parameter>string</parameter> text)</entry>
       <entry><type>text</type></entry>
       <entry>
1155
        Return the given string suitably quoted to be used as an identifier
1156 1157 1158 1159 1160 1161 1162 1163 1164 1165 1166 1167 1168
	in an SQL query string.
	Quotes are added only if necessary (i.e., if the string contains
	non-identifier characters or would be case-folded).
	Embedded quotes are properly doubled.
       </entry>
       <entry><literal>quote_ident('Foo')</literal></entry>
       <entry><literal>"Foo"</literal></entry>
      </row>

      <row>
       <entry><function>quote_literal</function>(<parameter>string</parameter> text)</entry>
       <entry><type>text</type></entry>
       <entry>
1169
        Return the given string suitably quoted to be used as a literal
1170 1171 1172 1173 1174 1175 1176 1177 1178 1179
	in an SQL query string.
	Embedded quotes and backslashes are properly doubled.
       </entry>
       <entry><literal>quote_literal('O\'Reilly')</literal></entry>
       <entry><literal>'O''Reilly'</literal></entry>
      </row>

      <row>
       <entry><function>repeat</function>(<type>text</type>, <type>integer</type>)</entry>
       <entry><type>text</type></entry>
1180
       <entry>Repeat text a number of times</entry>
1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204
       <entry><literal>repeat('Pg', 4)</literal></entry>
       <entry><literal>PgPgPgPg</literal></entry>
      </row>

      <row>
       <entry><function>replace</function>(<parameter>string</parameter> <type>text</type>,
       <parameter>from</parameter> <type>text</type>,
       <parameter>to</parameter> <type>text</type>)</entry>
       <entry><type>text</type></entry>
       <entry>Replace all occurrences in <parameter>string</parameter> of substring
        <parameter>from</parameter> with substring <parameter>to</parameter>
       </entry>
       <entry><literal>replace('abcdefabcdef', 'cd', 'XX')</literal></entry>
       <entry><literal>abXXefabXXef</literal></entry>
      </row>

      <row>
       <entry>
        <function>rpad</function>(<parameter>string</parameter> <type>text</type>,
        <parameter>length</parameter> <type>integer</type>
        <optional>, <parameter>fill</parameter> <type>text</type></optional>)
       </entry>
       <entry><type>text</type></entry>
       <entry>
1205
        Fill up the <parameter>string</parameter> to length
1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219
        <parameter>length</parameter> by appending the characters
        <parameter>fill</parameter> (a space by default).  If the
        <parameter>string</parameter> is already longer than
        <parameter>length</parameter> then it is truncated.
       </entry>
       <entry><literal>rpad('hi', 5, 'xy')</literal></entry>
       <entry><literal>hixyx</literal></entry>
      </row>

      <row>
       <entry><function>rtrim</function>(<parameter>string</parameter>
        text, <parameter>trim</parameter> text)</entry>
       <entry><type>text</type></entry>
       <entry>
1220
        Remove the longest string containing only characters from
1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242
        <parameter>trim</parameter> from the end of the string.
       </entry>
       <entry><literal>rtrim('trimxxxx','x')</literal></entry>
       <entry><literal>trim</literal></entry>
      </row>

      <row>
       <entry><function>split_part</function>(<parameter>string</parameter> <type>text</type>,
       <parameter>delimiter</parameter> <type>text</type>,
       <parameter>column</parameter> <type>integer</type>)</entry>
       <entry><type>text</type></entry>
       <entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
        returning the resulting (one based) <parameter>column</parameter> number.
       </entry>
       <entry><literal>split_part('abc~@~def~@~ghi','~@~',2)</literal></entry>
       <entry><literal>def</literal></entry>
      </row>

      <row>
       <entry><function>strpos</function>(<parameter>string</parameter>, <parameter>substring</parameter>)</entry>
       <entry><type>text</type></entry>
       <entry>
1243
        Locate specified substring (same as
1244 1245 1246 1247 1248 1249 1250 1251 1252 1253 1254 1255
        <literal>position(<parameter>substring</parameter> in
         <parameter>string</parameter>)</literal>, but note the reversed
        argument order)
       </entry>
       <entry><literal>strpos('high','ig')</literal></entry>
       <entry><literal>2</literal></entry>
      </row>

      <row>
       <entry><function>substr</function>(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</entry>
       <entry><type>text</type></entry>
       <entry>
1256
        Extract specified substring (same as
1257 1258 1259 1260 1261 1262 1263 1264 1265 1266
        <literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
       </entry>
       <entry><literal>substr('alphabet', 3, 2)</literal></entry>
       <entry><literal>ph</literal></entry>
      </row>

      <row>
       <entry><function>to_ascii</function>(<type>text</type>
        <optional>, <parameter>encoding</parameter></optional>)</entry>
       <entry><type>text</type></entry>
1267 1268 1269 1270 1271 1272 1273 1274 1275 1276 1277

       <entry>
       Convert text to <acronym>ASCII</acronym> from other encoding
       <footnote>
        <para>
         The <function>to_ascii</function> function supports conversion from
         <literal>LATIN1</>, <literal>LATIN2</>, and <literal>WIN1250</> only.
        </para>
       </footnote>
       </entry>

1278 1279 1280 1281 1282 1283 1284 1285 1286
       <entry><literal>to_ascii('Karel')</literal></entry>
       <entry><literal>Karel</literal></entry>
      </row>

      <row>
       <entry><function>to_hex</function>(<parameter>number</parameter> <type>integer</type>
       or <type>bigint</type>)</entry>
       <entry><type>text</type></entry>
       <entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
1287
        representation
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
       </entry>
       <entry><literal>to_hex(9223372036854775807::bigint)</literal></entry>
       <entry><literal>7fffffffffffffff</literal></entry>
      </row>

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


Tatsuo Ishii's avatar
Tatsuo Ishii committed
1316
   <table id="conversion-names">
1317
    <title>Built-in Conversions</title>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1318 1319 1320
    <tgroup cols="3">
     <thead>
      <row>
1321 1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332 1333 1334
       <entry>Conversion Name
        <footnote>
         <para>
          The conversion names follow a standard naming scheme: The
          official name of the source encoding with all
          non-alphanumeric characters replaced by underscores followed
          by <literal>_to_</literal> followed by the equally processed
          destination encoding name. Therefore the names might deviate
          from the customary encoding names.
         </para>
        </footnote>
       </entry>
       <entry>Source Encoding</entry>
       <entry>Destination Encoding</entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1335 1336
      </row>
     </thead>
1337

Tatsuo Ishii's avatar
Tatsuo Ishii committed
1338 1339
     <tbody>
      <row>
1340 1341 1342
       <entry><literal>ascii_to_mic</literal></entry>
       <entry><literal>SQL_ASCII</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1343 1344 1345
      </row>

      <row>
1346 1347 1348
       <entry><literal>ascii_to_utf_8</literal></entry>
       <entry><literal>SQL_ASCII</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1349 1350 1351
      </row>

      <row>
1352 1353 1354
       <entry><literal>big5_to_euc_tw</literal></entry>
       <entry><literal>BIG5</literal></entry>
       <entry><literal>EUC_TW</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1355 1356 1357
      </row>

      <row>
1358 1359 1360
       <entry><literal>big5_to_mic</literal></entry>
       <entry><literal>BIG5</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1361 1362 1363
      </row>

      <row>
1364 1365 1366
       <entry><literal>big5_to_utf_8</literal></entry>
       <entry><literal>BIG5</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1367 1368 1369
      </row>

      <row>
1370 1371 1372
       <entry><literal>euc_cn_to_mic</literal></entry>
       <entry><literal>EUC_CN</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1373 1374 1375
      </row>

      <row>
1376 1377 1378
       <entry><literal>euc_cn_to_utf_8</literal></entry>
       <entry><literal>EUC_CN</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1379 1380 1381
      </row>

      <row>
1382 1383 1384
       <entry><literal>euc_jp_to_mic</literal></entry>
       <entry><literal>EUC_JP</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1385 1386 1387
      </row>

      <row>
1388 1389 1390
       <entry><literal>euc_jp_to_sjis</literal></entry>
       <entry><literal>EUC_JP</literal></entry>
       <entry><literal>SJIS</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1391 1392 1393
      </row>

      <row>
1394 1395 1396
       <entry><literal>euc_jp_to_utf_8</literal></entry>
       <entry><literal>EUC_JP</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1397 1398 1399
      </row>

      <row>
1400 1401 1402
       <entry><literal>euc_kr_to_mic</literal></entry>
       <entry><literal>EUC_KR</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1403 1404 1405
      </row>

      <row>
1406 1407 1408
       <entry><literal>euc_kr_to_utf_8</literal></entry>
       <entry><literal>EUC_KR</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1409 1410 1411
      </row>

      <row>
1412 1413 1414
       <entry><literal>euc_tw_to_big5</literal></entry>
       <entry><literal>EUC_TW</literal></entry>
       <entry><literal>BIG5</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1415 1416 1417
      </row>

      <row>
1418 1419 1420
       <entry><literal>euc_tw_to_mic</literal></entry>
       <entry><literal>EUC_TW</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1421 1422 1423
      </row>

      <row>
1424 1425 1426
       <entry><literal>euc_tw_to_utf_8</literal></entry>
       <entry><literal>EUC_TW</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1427 1428 1429
      </row>

      <row>
1430 1431 1432
       <entry><literal>gb18030_to_utf_8</literal></entry>
       <entry><literal>GB18030</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1433 1434 1435
      </row>

      <row>
1436 1437 1438
       <entry><literal>gbk_to_utf_8</literal></entry>
       <entry><literal>GBK</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1439 1440 1441
      </row>

      <row>
1442 1443 1444
       <entry><literal>iso_8859_10_to_utf_8</literal></entry>
       <entry><literal>LATIN6</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1445 1446 1447
      </row>

      <row>
1448 1449 1450
       <entry><literal>iso_8859_13_to_utf_8</literal></entry>
       <entry><literal>LATIN7</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1451 1452 1453
      </row>

      <row>
1454 1455 1456
       <entry><literal>iso_8859_14_to_utf_8</literal></entry>
       <entry><literal>LATIN8</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1457 1458 1459
      </row>

      <row>
1460 1461 1462
       <entry><literal>iso_8859_15_to_utf_8</literal></entry>
       <entry><literal>LATIN9</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1463 1464 1465
      </row>

      <row>
1466 1467 1468
       <entry><literal>iso_8859_16_to_utf_8</literal></entry>
       <entry><literal>LATIN10</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1469 1470 1471
      </row>

      <row>
1472 1473 1474
       <entry><literal>iso_8859_1_to_mic</literal></entry>
       <entry><literal>LATIN1</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1475 1476 1477
      </row>

      <row>
1478 1479 1480
       <entry><literal>iso_8859_1_to_utf_8</literal></entry>
       <entry><literal>LATIN1</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1481 1482 1483
      </row>

      <row>
1484 1485 1486
       <entry><literal>iso_8859_2_to_mic</literal></entry>
       <entry><literal>LATIN2</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1487 1488 1489
      </row>

      <row>
1490 1491 1492
       <entry><literal>iso_8859_2_to_utf_8</literal></entry>
       <entry><literal>LATIN2</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1493 1494 1495
      </row>

      <row>
1496
       <entry><literal>iso_8859_2_to_windows_1250</literal></entry>
1497 1498
       <entry><literal>LATIN2</literal></entry>
       <entry><literal>WIN1250</literal></entry>
1499 1500 1501
      </row>

      <row>
1502 1503 1504
       <entry><literal>iso_8859_3_to_mic</literal></entry>
       <entry><literal>LATIN3</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1505 1506 1507
      </row>

      <row>
1508 1509 1510
       <entry><literal>iso_8859_3_to_utf_8</literal></entry>
       <entry><literal>LATIN3</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1511 1512 1513
      </row>

      <row>
1514 1515 1516
       <entry><literal>iso_8859_4_to_mic</literal></entry>
       <entry><literal>LATIN4</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1517 1518 1519
      </row>

      <row>
1520 1521 1522
       <entry><literal>iso_8859_4_to_utf_8</literal></entry>
       <entry><literal>LATIN4</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1523 1524 1525
      </row>

      <row>
1526
       <entry><literal>iso_8859_5_to_koi8_r</literal></entry>
1527 1528
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>KOI8</literal></entry>
1529 1530 1531
      </row>

      <row>
1532 1533 1534
       <entry><literal>iso_8859_5_to_mic</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1535 1536 1537
      </row>

      <row>
1538 1539 1540
       <entry><literal>iso_8859_5_to_utf_8</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1541 1542 1543
      </row>

      <row>
1544
       <entry><literal>iso_8859_5_to_windows_1251</literal></entry>
1545 1546
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>WIN</literal></entry>
1547 1548 1549
      </row>

      <row>
1550
       <entry><literal>iso_8859_5_to_windows_866</literal></entry>
1551 1552
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>ALT</literal></entry>
1553 1554 1555
      </row>

      <row>
1556 1557 1558
       <entry><literal>iso_8859_6_to_utf_8</literal></entry>
       <entry><literal>ISO_8859_6</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1559 1560 1561
      </row>

      <row>
1562 1563 1564
       <entry><literal>iso_8859_7_to_utf_8</literal></entry>
       <entry><literal>ISO_8859_7</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1565 1566 1567
      </row>

      <row>
1568 1569 1570
       <entry><literal>iso_8859_8_to_utf_8</literal></entry>
       <entry><literal>ISO_8859_8</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1571 1572 1573
      </row>

      <row>
1574 1575 1576
       <entry><literal>iso_8859_9_to_utf_8</literal></entry>
       <entry><literal>LATIN5</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1577 1578 1579
      </row>

      <row>
1580 1581 1582
       <entry><literal>johab_to_utf_8</literal></entry>
       <entry><literal>JOHAB</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1583 1584
      </row>

1585
      <row>
1586
       <entry><literal>koi8_r_to_iso_8859_5</literal></entry>
1587 1588
       <entry><literal>KOI8</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
1589 1590 1591
      </row>

      <row>
1592
       <entry><literal>koi8_r_to_mic</literal></entry>
1593 1594
       <entry><literal>KOI8</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1595 1596 1597
      </row>

      <row>
1598
       <entry><literal>koi8_r_to_utf_8</literal></entry>
1599 1600
       <entry><literal>KOI8</literal></entry>
       <entry><literal>UNICODE</literal></entry>
1601 1602 1603
      </row>

      <row>
1604
       <entry><literal>koi8_r_to_windows_1251</literal></entry>
1605 1606
       <entry><literal>KOI8</literal></entry>
       <entry><literal>WIN</literal></entry>
1607 1608 1609
      </row>

      <row>
1610
       <entry><literal>koi8_r_to_windows_866</literal></entry>
1611 1612
       <entry><literal>KOI8</literal></entry>
       <entry><literal>ALT</literal></entry>
1613 1614 1615
      </row>

      <row>
1616 1617 1618
       <entry><literal>mic_to_ascii</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>SQL_ASCII</literal></entry>
1619 1620
      </row>

Tatsuo Ishii's avatar
Tatsuo Ishii committed
1621
      <row>
1622 1623 1624
       <entry><literal>mic_to_big5</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>BIG5</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1625 1626
      </row>

1627
      <row>
1628 1629 1630
       <entry><literal>mic_to_euc_cn</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>EUC_CN</literal></entry>
1631 1632
      </row>

Tatsuo Ishii's avatar
Tatsuo Ishii committed
1633
      <row>
1634 1635 1636
       <entry><literal>mic_to_euc_jp</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>EUC_JP</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1637 1638
      </row>

1639
      <row>
1640 1641 1642
       <entry><literal>mic_to_euc_kr</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>EUC_KR</literal></entry>
1643 1644
      </row>

Tatsuo Ishii's avatar
Tatsuo Ishii committed
1645
      <row>
1646 1647 1648
       <entry><literal>mic_to_euc_tw</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>EUC_TW</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1649 1650
      </row>

1651
      <row>
1652 1653 1654
       <entry><literal>mic_to_iso_8859_1</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>LATIN1</literal></entry>
1655 1656 1657
      </row>

      <row>
1658 1659 1660
       <entry><literal>mic_to_iso_8859_2</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>LATIN2</literal></entry>
1661 1662 1663
      </row>

      <row>
1664 1665 1666
       <entry><literal>mic_to_iso_8859_3</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>LATIN3</literal></entry>
1667 1668 1669
      </row>

      <row>
1670 1671 1672
       <entry><literal>mic_to_iso_8859_4</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>LATIN4</literal></entry>
1673 1674 1675
      </row>

      <row>
1676 1677 1678
       <entry><literal>mic_to_iso_8859_5</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
1679 1680 1681
      </row>

      <row>
1682
       <entry><literal>mic_to_koi8_r</literal></entry>
1683 1684
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>KOI8</literal></entry>
1685 1686
      </row>

Tatsuo Ishii's avatar
Tatsuo Ishii committed
1687
      <row>
1688 1689 1690
       <entry><literal>mic_to_sjis</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>SJIS</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1691 1692
      </row>

1693
      <row>
1694
       <entry><literal>mic_to_windows_1250</literal></entry>
1695 1696
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>WIN1250</literal></entry>
1697 1698 1699
      </row>

      <row>
1700
       <entry><literal>mic_to_windows_1251</literal></entry>
1701 1702
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>WIN</literal></entry>
1703 1704 1705
      </row>

      <row>
1706
       <entry><literal>mic_to_windows_866</literal></entry>
1707 1708
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>ALT</literal></entry>
1709 1710
      </row>

Tatsuo Ishii's avatar
Tatsuo Ishii committed
1711
      <row>
1712 1713 1714
       <entry><literal>sjis_to_euc_jp</literal></entry>
       <entry><literal>SJIS</literal></entry>
       <entry><literal>EUC_JP</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1715 1716 1717
      </row>

      <row>
1718 1719 1720
       <entry><literal>sjis_to_mic</literal></entry>
       <entry><literal>SJIS</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1721 1722 1723
      </row>

      <row>
1724 1725 1726
       <entry><literal>sjis_to_utf_8</literal></entry>
       <entry><literal>SJIS</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1727 1728 1729
      </row>

      <row>
1730 1731 1732
       <entry><literal>tcvn_to_utf_8</literal></entry>
       <entry><literal>TCVN</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1733 1734 1735
      </row>

      <row>
1736 1737 1738
       <entry><literal>uhc_to_utf_8</literal></entry>
       <entry><literal>UHC</literal></entry>
       <entry><literal>UNICODE</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1739 1740 1741
      </row>

      <row>
1742 1743 1744
       <entry><literal>utf_8_to_ascii</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>SQL_ASCII</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1745 1746 1747
      </row>

      <row>
1748 1749 1750
       <entry><literal>utf_8_to_big5</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>BIG5</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1751 1752 1753
      </row>

      <row>
1754 1755 1756
       <entry><literal>utf_8_to_euc_cn</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>EUC_CN</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1757 1758 1759
      </row>

      <row>
1760 1761 1762
       <entry><literal>utf_8_to_euc_jp</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>EUC_JP</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1763 1764 1765
      </row>

      <row>
1766 1767 1768
       <entry><literal>utf_8_to_euc_kr</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>EUC_KR</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1769 1770 1771
      </row>

      <row>
1772 1773 1774
       <entry><literal>utf_8_to_euc_tw</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>EUC_TW</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1775 1776 1777
      </row>

      <row>
1778 1779 1780
       <entry><literal>utf_8_to_gb18030</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>GB18030</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1781 1782 1783
      </row>

      <row>
1784 1785 1786
       <entry><literal>utf_8_to_gbk</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>GBK</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1787 1788 1789
      </row>

      <row>
1790 1791 1792
       <entry><literal>utf_8_to_iso_8859_1</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>LATIN1</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1793 1794 1795
      </row>

      <row>
1796 1797 1798
       <entry><literal>utf_8_to_iso_8859_10</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>LATIN6</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1799 1800 1801
      </row>

      <row>
1802 1803 1804
       <entry><literal>utf_8_to_iso_8859_13</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>LATIN7</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1805 1806 1807
      </row>

      <row>
1808 1809 1810
       <entry><literal>utf_8_to_iso_8859_14</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>LATIN8</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1811 1812 1813
      </row>

      <row>
1814 1815 1816
       <entry><literal>utf_8_to_iso_8859_15</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>LATIN9</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1817 1818 1819
      </row>

      <row>
1820 1821 1822
       <entry><literal>utf_8_to_iso_8859_16</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>LATIN10</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1823 1824 1825
      </row>

      <row>
1826 1827 1828
       <entry><literal>utf_8_to_iso_8859_2</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>LATIN2</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1829 1830 1831
      </row>

      <row>
1832 1833 1834
       <entry><literal>utf_8_to_iso_8859_3</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>LATIN3</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1835 1836 1837
      </row>

      <row>
1838 1839 1840
       <entry><literal>utf_8_to_iso_8859_4</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>LATIN4</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1841 1842 1843
      </row>

      <row>
1844 1845 1846
       <entry><literal>utf_8_to_iso_8859_5</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1847 1848 1849
      </row>

      <row>
1850 1851 1852
       <entry><literal>utf_8_to_iso_8859_6</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>ISO_8859_6</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1853 1854 1855
      </row>

      <row>
1856 1857 1858
       <entry><literal>utf_8_to_iso_8859_7</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>ISO_8859_7</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1859 1860 1861
      </row>

      <row>
1862 1863 1864
       <entry><literal>utf_8_to_iso_8859_8</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>ISO_8859_8</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1865 1866 1867
      </row>

      <row>
1868 1869 1870
       <entry><literal>utf_8_to_iso_8859_9</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>LATIN5</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1871 1872 1873
      </row>

      <row>
1874 1875 1876
       <entry><literal>utf_8_to_johab</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>JOHAB</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1877 1878 1879
      </row>

      <row>
1880
       <entry><literal>utf_8_to_koi8_r</literal></entry>
1881 1882
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>KOI8</literal></entry>
1883 1884 1885
      </row>

      <row>
1886 1887 1888
       <entry><literal>utf_8_to_sjis</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>SJIS</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1889 1890 1891
      </row>

      <row>
1892 1893 1894
       <entry><literal>utf_8_to_tcvn</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>TCVN</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1895 1896 1897
      </row>

      <row>
1898 1899 1900
       <entry><literal>utf_8_to_uhc</literal></entry>
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>UHC</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1901 1902
      </row>

1903
      <row>
1904
       <entry><literal>utf_8_to_windows_1250</literal></entry>
1905 1906
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>WIN1250</literal></entry>
1907 1908 1909
      </row>

      <row>
1910
       <entry><literal>utf_8_to_windows_1251</literal></entry>
1911 1912
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>WIN</literal></entry>
1913 1914 1915
      </row>

      <row>
1916
       <entry><literal>utf_8_to_windows_1256</literal></entry>
1917 1918
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>WIN1256</literal></entry>
1919 1920 1921
      </row>

      <row>
1922
       <entry><literal>utf_8_to_windows_866</literal></entry>
1923 1924
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>ALT</literal></entry>
1925 1926 1927
      </row>

      <row>
1928
       <entry><literal>utf_8_to_windows_874</literal></entry>
1929 1930
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>WIN874</literal></entry>
1931
      </row>
1932

1933
      <row>
1934
       <entry><literal>windows_1250_to_iso_8859_2</literal></entry>
1935 1936
       <entry><literal>WIN1250</literal></entry>
       <entry><literal>LATIN2</literal></entry>
1937
      </row>
1938

1939
      <row>
1940
       <entry><literal>windows_1250_to_mic</literal></entry>
1941 1942
       <entry><literal>WIN1250</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1943 1944 1945
      </row>

      <row>
1946
       <entry><literal>windows_1250_to_utf_8</literal></entry>
1947 1948
       <entry><literal>WIN1250</literal></entry>
       <entry><literal>UNICODE</literal></entry>
1949 1950
      </row>

1951
      <row>
1952
       <entry><literal>windows_1251_to_iso_8859_5</literal></entry>
1953 1954
       <entry><literal>WIN</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
1955
      </row>
1956

1957
      <row>
1958
       <entry><literal>windows_1251_to_koi8_r</literal></entry>
1959 1960
       <entry><literal>WIN</literal></entry>
       <entry><literal>KOI8</literal></entry>
1961 1962
      </row>

1963
      <row>
1964
       <entry><literal>windows_1251_to_mic</literal></entry>
1965 1966
       <entry><literal>WIN</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1967
      </row>
1968

1969
      <row>
1970
       <entry><literal>windows_1251_to_utf_8</literal></entry>
1971 1972
       <entry><literal>WIN</literal></entry>
       <entry><literal>UNICODE</literal></entry>
1973
      </row>
1974

1975
      <row>
1976
       <entry><literal>windows_1251_to_windows_866</literal></entry>
1977 1978
       <entry><literal>WIN</literal></entry>
       <entry><literal>ALT</literal></entry>
1979 1980
      </row>

1981
      <row>
1982
       <entry><literal>windows_1256_to_utf_8</literal></entry>
1983 1984
       <entry><literal>WIN1256</literal></entry>
       <entry><literal>UNICODE</literal></entry>
1985
      </row>
1986

1987
      <row>
1988
       <entry><literal>windows_866_to_iso_8859_5</literal></entry>
1989 1990
       <entry><literal>ALT</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
1991
      </row>
1992

1993
      <row>
1994
       <entry><literal>windows_866_to_koi8_r</literal></entry>
1995 1996
       <entry><literal>ALT</literal></entry>
       <entry><literal>KOI8</literal></entry>
1997
      </row>
1998

1999
      <row>
2000
       <entry><literal>windows_866_to_mic</literal></entry>
2001 2002
       <entry><literal>ALT</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
2003 2004
      </row>

2005
      <row>
2006
       <entry><literal>windows_866_to_utf_8</literal></entry>
2007 2008 2009 2010 2011
       <entry><literal>ALT</literal></entry>
       <entry><literal>UNICODE</literal></entry>
      </row>

      <row>
2012
       <entry><literal>windows_866_to_windows_1251</literal></entry>
2013 2014 2015 2016 2017
       <entry><literal>ALT</literal></entry>
       <entry><literal>WIN</literal></entry>
      </row>

      <row>
2018
       <entry><literal>windows_874_to_utf_8</literal></entry>
2019 2020 2021 2022
       <entry><literal>WIN874</literal></entry>
       <entry><literal>UNICODE</literal></entry>
      </row>

2023 2024 2025
     </tbody>
    </tgroup>
   </table>
2026

2027
  </sect1>
2028

2029

2030 2031
  <sect1 id="functions-binarystring">
   <title>Binary String Functions and Operators</title>
2032

2033 2034 2035 2036 2037
   <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>
2038

2039 2040 2041
   <para>
    <acronym>SQL</acronym> defines some string functions with a
    special syntax where 
2042
    certain key words rather than commas are used to separate the
2043 2044 2045 2046 2047 2048
    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>
2049

2050 2051 2052 2053 2054 2055 2056 2057 2058 2059 2060 2061
   <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>
2062

2063 2064 2065 2066 2067 2068
     <tbody>
      <row>
       <entry> <parameter>string</parameter> <literal>||</literal>
        <parameter>string</parameter> </entry>
       <entry> <type>bytea</type> </entry>
       <entry>
2069
        String concatenation
2070 2071 2072 2073 2074
        <indexterm>
         <primary>binary strings</primary>
         <secondary>concatenation</secondary>
        </indexterm>
       </entry>
2075 2076
       <entry><literal>'\\\\Post'::bytea || '\\047greSQL\\000'::bytea</literal></entry>
       <entry><literal>\\Post'greSQL\000</literal></entry>
2077
      </row>
2078

2079 2080 2081
      <row>
       <entry><function>octet_length</function>(<parameter>string</parameter>)</entry>
       <entry><type>integer</type></entry>
2082
       <entry>Number of bytes in binary string</entry>
2083 2084 2085
       <entry><literal>octet_length('jo\\000se'::bytea)</literal></entry>
       <entry><literal>5</literal></entry>
      </row>
2086

2087 2088 2089
      <row>
       <entry><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</entry>
       <entry><type>integer</type></entry>
2090
       <entry>Location of specified substring</entry>
2091 2092 2093
      <entry><literal>position('\\000om'::bytea in 'Th\\000omas'::bytea)</literal></entry>
       <entry><literal>3</literal></entry>
      </row>
2094

2095 2096 2097 2098
      <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>
2099
        Extract substring
2100 2101 2102 2103 2104 2105 2106
        <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>
2107

2108 2109 2110 2111 2112 2113 2114 2115
      <row>
       <entry>
        <function>trim</function>(<optional>both</optional>
        <parameter>characters</parameter> from
        <parameter>string</parameter>)
       </entry>
       <entry><type>bytea</type></entry>
       <entry>
2116
        Remove the longest string containing only the
2117
        <parameter>characters</parameter> from the
2118
        beginning/end/both ends of the <parameter>string</parameter>
2119 2120 2121 2122 2123 2124 2125
       </entry>
       <entry><literal>trim('\\000'::bytea from '\\000Tom\\000'::bytea)</literal></entry>
       <entry><literal>Tom</literal></entry>
      </row>
     </tbody>
    </tgroup>
   </table>
2126

2127
   <para>
2128 2129 2130 2131 2132
    Additional binary string manipulation functions are available and
    are listed in <xref linkend="functions-binarystring-other">.  Some
    of them are used internally to implement the
    <acronym>SQL</acronym>-standard string functions listed in <xref
    linkend="functions-binarystring-sql">.
2133
   </para>
2134

2135 2136 2137 2138 2139 2140 2141 2142 2143 2144 2145 2146
   <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>
2147

2148 2149 2150 2151 2152 2153 2154 2155 2156
     <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>.
2157 2158 2159 2160 2161 2162 2163 2164 2165
      </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>
2166
       Length of binary string
2167 2168 2169 2170 2171 2172 2173 2174 2175 2176
       <indexterm>
        <primary>binary strings</primary>
	<secondary>length</secondary>
       </indexterm>
       <indexterm>
        <primary>length</primary>
	<secondary>binary strings</secondary>
	<see>binary strings, length</see>
       </indexterm>
      </entry>
2177 2178
      <entry><literal>length('jo\\000se'::bytea)</literal></entry>
      <entry><literal>5</literal></entry>
2179 2180 2181 2182 2183 2184 2185 2186 2187
     </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>
2188 2189
       Encode binary string to <acronym>ASCII</acronym>-only representation.  Supported
       types are: base64, hex, escape.
2190 2191 2192 2193 2194 2195 2196 2197 2198 2199 2200 2201
      </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>
2202 2203
       Decode binary string from <parameter>string</parameter> previously 
       encoded with <literal>encode()</>.  Parameter type is same as in <literal>encode()</>.
2204 2205 2206 2207 2208 2209 2210 2211 2212 2213 2214 2215
      </entry>
      <entry><literal>decode('123\\000456', 'escape')</literal></entry>
      <entry><literal>123\000456</literal></entry>
     </row>       

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

 </sect1>


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

2219
   <para>
2220
    There are three separate approaches to pattern matching provided by
2221 2222
    <productname>PostgreSQL</productname>:  the traditional
    <acronym>SQL</acronym> 
2223
    <function>LIKE</function> operator, the more recent
2224
    <acronym>SQL99</acronym> 
2225
    <function>SIMILAR TO</function> operator, and
2226 2227
    <acronym>POSIX</acronym>-style regular expressions.
    Additionally, a pattern matching function,
2228 2229
    <function>SUBSTRING</function>, is available, using either
    <acronym>SQL99</acronym>-style or POSIX-style regular expressions.
2230 2231 2232 2233 2234 2235 2236 2237
   </para>

   <tip>
    <para>
     If you have pattern matching needs that go beyond this,
     consider writing a user-defined function in Perl or Tcl.
    </para>
   </tip>
2238

2239
  <sect2 id="functions-like">
2240
   <title><function>LIKE</function></title>
2241

2242 2243 2244 2245
   <indexterm>
    <primary>like</primary>
   </indexterm>

2246
<synopsis>
2247 2248
<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>
2249
</synopsis>
2250

2251 2252 2253 2254 2255 2256 2257 2258 2259 2260 2261
    <para>
     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>.)
    </para>
2262 2263

    <para>
2264 2265 2266 2267 2268 2269 2270 2271 2272
     If <replaceable>pattern</replaceable> does not contain percent
     signs or underscore, then the pattern only represents the string
     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
     character; a percent sign (<literal>%</literal>) matches any string
     of zero or more characters.
    </para>

2273 2274 2275
   <para>
    Some examples:
<programlisting>
2276 2277 2278 2279
'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
'abc' LIKE 'c'      <lineannotation>false</lineannotation>
2280 2281 2282
</programlisting>
   </para>
   
2283
   <para>
2284
    <function>LIKE</function> pattern matches always cover the entire
2285
    string.  To match a pattern anywhere within a string, the
2286
    pattern must therefore start and end with a percent sign.
2287
   </para>
2288 2289

   <para>
2290 2291 2292 2293
    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
2294
    character is the backslash but a different one may be selected by
2295 2296 2297 2298 2299 2300 2301
    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
2302 2303 2304
    you must write two backslashes in the query.  Thus, writing a pattern
    that actually matches a literal backslash means writing four backslashes
    in the query.  You can avoid this by selecting a different escape
Peter Eisentraut's avatar
Peter Eisentraut committed
2305
    character with <literal>ESCAPE</literal>; then backslash is not special
2306
    to <function>LIKE</function> anymore. (But it is still special to the string
2307 2308 2309 2310 2311
    literal parser, so you still need two of them.)
   </para>

   <para>
    It's also possible to select no escape character by writing
2312
    <literal>ESCAPE ''</literal>.  This effectively disables the
Bruce Momjian's avatar
Bruce Momjian committed
2313 2314
    escape mechanism, which makes it impossible to turn off the
    special meaning of underscore and percent signs in the pattern.
2315
   </para>
2316 2317

   <para>
2318 2319
    The keyword <token>ILIKE</token> can be used instead of
    <token>LIKE</token> to make the match case insensitive according
2320
    to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
2321
    <productname>PostgreSQL</productname> extension.
2322
   </para>
2323

2324 2325
   <para>
    The operator <literal>~~</literal> is equivalent to
2326 2327 2328
    <function>LIKE</function>, and <literal>~~*</literal> corresponds to
    <function>ILIKE</function>.  There are also
    <literal>!~~</literal> and <literal>!~~*</literal> operators that
2329
    represent <function>NOT LIKE</function> and <function>NOT
2330
    ILIKE</function>.  All of these operators are
2331
    <productname>PostgreSQL</productname>-specific.
2332 2333
   </para>
  </sect2>
2334

2335

2336 2337
  <sect2 id="functions-sql99-regexp">
   <title><function>SIMILAR TO</function> and <acronym>SQL99</acronym>
2338
     Regular Expressions</title>
2339

2340 2341
   <indexterm zone="functions-sql99-regexp">
    <primary>regular expressions</primary>
2342
    <!-- <seealso>pattern matching</seealso> breaks index build -->
2343 2344 2345 2346 2347 2348 2349 2350 2351 2352
   </indexterm>

   <indexterm>
    <primary>similar to</primary>
   </indexterm>

   <indexterm>
    <primary>substring</primary>
   </indexterm>

2353
<synopsis>
2354 2355
<replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
<replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
2356
</synopsis>
2357 2358 2359 2360 2361 2362 2363 2364 2365 2366 2367 2368 2369 2370 2371 2372 2373 2374 2375 2376 2377 2378 2379 2380 2381 2382 2383 2384 2385 2386 2387 2388 2389 2390 2391 2392 2393 2394 2395 2396 2397 2398 2399 2400 2401 2402 2403 2404 2405 2406 2407 2408 2409 2410 2411 2412 2413 2414 2415 2416 2417 2418 2419 2420 2421 2422 2423 2424 2425 2426 2427 2428 2429

    <para>
     The <function>SIMILAR TO</function> operator returns true or false
     depending on whether its pattern matches the given string.  It is
     much like <function>LIKE</function>, except that it interprets the
     pattern using <acronym>SQL99</acronym>'s definition of a regular
     expression.
     <acronym>SQL99</acronym>'s regular expressions are a curious cross
     between <function>LIKE</function> notation and common regular expression
     notation.
    </para>

    <para>
     Like <function>LIKE</function>, the  <function>SIMILAR TO</function>
     operator succeeds only if its pattern matches the entire string;
     this is unlike common regular expression practice, wherein the pattern
     may match any part of the string.
     Also like
     <function>LIKE</function>, <function>SIMILAR TO</function> uses
     <literal>%</> and <literal>_</> as wildcard characters denoting
     any string and any single character, respectively (these are
     comparable to <literal>.*</> and <literal>.</> in POSIX regular
     expressions).
    </para>

    <para>
     In addition to these facilities borrowed from <function>LIKE</function>,
     <function>SIMILAR TO</function> supports these pattern-matching
     metacharacters borrowed from POSIX regular expressions:

    <itemizedlist>
     <listitem>
      <para>
       <literal>|</literal> denotes alternation (either of two alternatives).
      </para>
     </listitem>
     <listitem>
      <para>
       <literal>*</literal> denotes repetition of the previous item zero
       or more times.
      </para>
     </listitem>
     <listitem>
      <para>
       <literal>+</literal> denotes repetition of the previous item one
       or more times.
      </para>
     </listitem>
     <listitem>
      <para>
       Parentheses <literal>()</literal> may be used to group items into
       a single logical item.
      </para>
     </listitem>
     <listitem>
      <para>
       A bracket expression <literal>[...]</literal> specifies a character
       class, just as in POSIX regular expressions.
      </para>
     </listitem>
    </itemizedlist>

     Notice that bounded repetition (<literal>?</> and <literal>{...}</>)
     are not provided, though they exist in POSIX.  Also, dot (<literal>.</>)
     is not a metacharacter.
    </para>

    <para>
     As with <function>LIKE</>, a backslash disables the special meaning
     of any of these metacharacters; or a different escape character can
     be specified with <literal>ESCAPE</>.
    </para>

2430 2431 2432
   <para>
    Some examples:
<programlisting>
2433 2434 2435 2436
'abc' SIMILAR TO 'abc'      <lineannotation>true</lineannotation>
'abc' SIMILAR TO 'a'        <lineannotation>false</lineannotation>
'abc' SIMILAR TO '%(b|d)%'  <lineannotation>true</lineannotation>
'abc' SIMILAR TO '(b|c)%'   <lineannotation>false</lineannotation>
2437 2438
</programlisting>
   </para>
2439 2440

    <para>
2441 2442
     The <function>SUBSTRING</> function with three parameters,
     <function>SUBSTRING(<parameter>string</parameter> FROM
2443
     <replaceable>pattern</replaceable> FOR
2444 2445 2446 2447 2448 2449 2450 2451 2452
     <replaceable>escape</replaceable>)</function>, provides
     extraction of a substring that matches a SQL99 regular expression
     pattern.  As with <literal>SIMILAR TO</>, the specified pattern
     must match to the entire data string, else the function fails and
     returns null.  To indicate the part of the pattern that should be
     returned on success, SQL99 specifies that the pattern must
     contain two occurrences of the escape character followed by
     double quote (<literal>"</>).  The text matching the portion of
     the pattern between these markers is returned.
2453 2454
    </para>

2455 2456 2457
   <para>
    Some examples:
<programlisting>
2458 2459
SUBSTRING('foobar' FROM '%#"o_b#"%' FOR '#')   <lineannotation>oob</lineannotation>
SUBSTRING('foobar' FROM '#"o_b#"%' FOR '#')    <lineannotation>NULL</lineannotation>
2460 2461
</programlisting>
   </para>
2462 2463 2464 2465 2466 2467
  </sect2>

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

   <indexterm zone="functions-posix-regexp">
2468 2469 2470 2471
    <primary>regular expressions</primary>
    <seealso>pattern matching</seealso>
   </indexterm>

2472 2473 2474 2475 2476 2477
   <para>
    <xref linkend="functions-posix-table"> lists the available
    operators for pattern matching using POSIX regular expressions.
   </para>

   <table id="functions-posix-table">
2478 2479 2480 2481 2482 2483 2484 2485 2486 2487 2488
    <title>Regular Expression Match Operators</title>

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

2489 2490 2491 2492 2493 2494
      <tbody>
       <row>
        <entry> <literal>~</literal> </entry>
        <entry>Matches regular expression, case sensitive</entry>
        <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
       </row>
2495

2496 2497 2498 2499 2500
       <row>
        <entry> <literal>~*</literal> </entry>
        <entry>Matches regular expression, case insensitive</entry>
        <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
       </row>
2501

2502 2503 2504 2505 2506 2507 2508 2509 2510 2511 2512 2513 2514 2515 2516 2517 2518 2519
       <row>
        <entry> <literal>!~</literal> </entry>
        <entry>Does not match regular expression, case sensitive</entry>
        <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
       </row>

       <row>
        <entry> <literal>!~*</literal> </entry>
        <entry>Does not match regular expression, case insensitive</entry>
        <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
       </row>
      </tbody>
     </tgroup>
    </table>

    <para>
     <acronym>POSIX</acronym> regular expressions provide a more
     powerful means for 
2520 2521
     pattern matching than the <function>LIKE</function> and
     <function>SIMILAR TO</> operators.
2522 2523 2524 2525 2526 2527 2528 2529 2530 2531 2532 2533 2534 2535 2536 2537 2538 2539 2540
     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>
2541

2542 2543 2544
   <para>
    Some examples:
<programlisting>
2545 2546 2547 2548
'abc' ~ 'abc'    <lineannotation>true</lineannotation>
'abc' ~ '^a'     <lineannotation>true</lineannotation>
'abc' ~ '(b|d)'  <lineannotation>true</lineannotation>
'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
2549 2550
</programlisting>
   </para>
2551 2552

    <para>
2553 2554 2555 2556
     The <function>SUBSTRING</> function with two parameters,
     <function>SUBSTRING(<parameter>string</parameter> FROM
     <replaceable>pattern</replaceable>)</function>, provides extraction of a substring
     that matches a POSIX regular expression pattern.  It returns null if
2557 2558 2559 2560 2561 2562 2563 2564 2565
     there is no match, otherwise the portion of the text that matched the
     pattern.  But if the pattern contains any parentheses, the portion
     of the text that matched the first parenthesized subexpression (the
     one whose left parenthesis comes first) is
     returned.  You can always put parentheses around the whole expression
     if you want to use parentheses within it without triggering this
     exception.
    </para>

2566 2567 2568
   <para>
    Some examples:
<programlisting>
2569 2570
SUBSTRING('foobar' FROM 'o.b')     <lineannotation>oob</lineannotation>
SUBSTRING('foobar' FROM 'o(.)b')   <lineannotation>o</lineannotation>
2571 2572
</programlisting>
   </para>
2573 2574

<!-- derived from the re_format.7 man page -->
2575
   <para>
2576
    Regular expressions (<acronym>RE</acronym>s), as defined in
2577
     <acronym>POSIX</acronym> 
2578
    1003.2, come in two forms: modern <acronym>RE</acronym>s (roughly those of
2579
    <command>egrep</command>; 1003.2 calls these
2580 2581
    <quote>extended</quote> <acronym>RE</acronym>s) and obsolete <acronym>RE</acronym>s (roughly those of
    <command>ed</command>; 1003.2 <quote>basic</quote> <acronym>RE</acronym>s).
2582
    <productname>PostgreSQL</productname> implements the modern form.
2583
   </para>
2584

2585
   <para>
2586 2587 2588 2589
    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.
2590
   </para>
2591

2592
   <para>
2593 2594 2595
    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.
2596
   </para>
2597

Bruce Momjian's avatar
Bruce Momjian committed
2598
   <para>
2599 2600 2601 2602 2603 2604 2605 2606
    A piece is an <firstterm>atom</firstterm> possibly followed by a
    single <literal>*</literal>, <literal>+</literal>,
    <literal>?</literal>, or <firstterm>bound</firstterm>.  An atom
    followed by <literal>*</literal> matches a sequence of 0 or more
    matches of the atom.  An atom followed by <literal>+</literal>
    matches a sequence of 1 or more matches of the atom.  An atom
    followed by <literal>?</literal> matches a sequence of 0 or 1
    matches of the atom.
Bruce Momjian's avatar
Bruce Momjian committed
2607
   </para>
2608

2609 2610 2611 2612 2613 2614 2615 2616 2617 2618 2619 2620 2621 2622 2623 2624 2625 2626 2627 2628 2629 2630 2631 2632 2633 2634 2635 2636
   <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>
2637

2638
   <para>
2639 2640 2641 2642 2643
    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),
2644 2645 2646
    <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
2647 2648 2649 2650 2651 2652 2653 2654 2655
    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>.
2656
   </para>
2657

2658 2659 2660 2661 2662 2663 2664
   <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>

2665
   <para>
2666 2667 2668 2669 2670 2671 2672 2673 2674 2675 2676 2677 2678
    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.
2679
   </para>
2680

2681
   <para>
2682 2683 2684 2685 2686 2687 2688 2689 2690 2691 2692 2693 2694 2695 2696
    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
2697
    multiple-character sequence that collates as if it were a single
2698 2699 2700 2701
    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
2702
    expression containing a multiple-character collating element can thus
2703 2704 2705 2706 2707 2708 2709 2710 2711 2712 2713 2714 2715 2716 2717 2718 2719 2720 2721 2722 2723 2724 2725 2726 2727 2728 2729 2730 2731 2732 2733 2734 2735 2736 2737 2738 2739 2740 2741
    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
2742
    expressions <literal>[[:&lt;:]]</literal> and
2743 2744 2745 2746 2747 2748
    <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
2749
    specified by <acronym>POSIX</acronym> 1003.2, and should be used with caution in
2750 2751 2752 2753 2754 2755 2756 2757 2758 2759 2760 2761 2762 2763 2764 2765 2766 2767 2768 2769 2770 2771 2772 2773 2774 2775 2776 2777 2778 2779 2780 2781 2782 2783 2784 2785 2786 2787 2788 2789 2790 2791 2792
    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>
2793
    There is no particular limit on the length of <acronym>RE</acronym>s, except insofar
2794 2795 2796 2797 2798 2799 2800
    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
2801 2802 2803 2804 2805 2806 2807 2808
    space.
    <footnote>
     <para>
      This was written in 1994, mind you.  The
      numbers have probably changed, but the problem
      persists.
     </para>
    </footnote>
2809
   </para>
2810 2811
<!-- end re_format.7 man page -->
  </sect2>
2812

2813 2814 2815 2816
 </sect1>


  <sect1 id="functions-formatting">
2817
   <title>Data Type Formatting Functions</title>
2818

2819 2820 2821 2822
   <indexterm zone="functions-formatting">
    <primary>formatting</primary>
   </indexterm>

2823
   <para>
2824
    The <productname>PostgreSQL</productname> formatting functions
2825 2826
    provide a powerful set of tools for converting various data types
    (date/time, integer, floating point, numeric) to formatted strings
2827
    and for converting from formatted strings to specific data types.
2828
    <xref linkend="functions-formatting-table"> lists them.
2829
    These functions all follow a common calling convention: the first
2830
    argument is the value to be formatted and the second argument is a
2831
    template that defines the output or input format.
2832 2833
   </para>

2834
    <table id="functions-formatting-table">
2835 2836 2837 2838 2839 2840 2841 2842 2843 2844 2845 2846
     <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>
2847 2848 2849 2850
	<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>
2851
       </row>
2852
       <row>
2853 2854
	<entry><function>to_char</function>(<type>interval</type>, <type>text</type>)</entry>
	<entry><type>text</type></entry>
2855
	<entry>convert interval to string</entry>
2856
	<entry><literal>to_char(interval '15h 2m 12s','HH24:MI:SS')</literal></entry>
2857
       </row>
2858
       <row>
2859 2860
	<entry><function>to_char</function>(<type>int</type>, <type>text</type>)</entry>
	<entry><type>text</type></entry>
2861
	<entry>convert integer to string</entry>
2862
	<entry><literal>to_char(125, '999')</literal></entry>
2863 2864
       </row>
       <row>
2865 2866
	<entry><function>to_char</function>(<type>double precision</type>,
        <type>text</type>)</entry>
2867
	<entry><type>text</type></entry>
2868
	<entry>convert real/double precision to string</entry>
2869
	<entry><literal>to_char(125.8, '999D9')</literal></entry>
2870 2871
       </row>
       <row>
2872 2873
	<entry><function>to_char</function>(<type>numeric</type>, <type>text</type>)</entry>
	<entry><type>text</type></entry>
2874
	<entry>convert numeric to string</entry>
2875
	<entry><literal>to_char(numeric '-125.8', '999D99S')</literal></entry>
2876 2877
       </row>
       <row>
2878 2879
	<entry><function>to_date</function>(<type>text</type>, <type>text</type>)</entry>
	<entry><type>date</type></entry>
2880
	<entry>convert string to date</entry>
2881
	<entry><literal>to_date('05 Dec 2000', 'DD Mon YYYY')</literal></entry>
2882 2883
       </row>
       <row>
2884 2885 2886 2887
	<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>
2888 2889
       </row>
       <row>
2890 2891
	<entry><function>to_number</function>(<type>text</type>, <type>text</type>)</entry>
	<entry><type>numeric</type></entry>
2892
	<entry>convert string to numeric</entry>
2893
	<entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
2894 2895 2896 2897 2898
       </row>
      </tbody>
     </tgroup>
    </table>

2899 2900 2901 2902
   <para>
    In an output template string, there are certain patterns that are
    recognized and replaced with appropriately-formatted data from the value
    to be formatted.  Any text that is not a template pattern is simply
Peter Eisentraut's avatar
Peter Eisentraut committed
2903
    copied verbatim.  Similarly, in an input template string, template patterns
2904 2905 2906 2907
    identify the parts of the input data string to be looked at and the
    values to be found there.
   </para>

2908 2909 2910 2911 2912 2913
  <para>
   <xref linkend="functions-formatting-datetime-table"> shows the
   template patterns available for formatting date and time values.
  </para>

    <table id="functions-formatting-datetime-table">
2914
     <title>Template patterns for date/time conversions</title>
2915 2916 2917
     <tgroup cols="2">
      <thead>
       <row>
2918
	<entry>Pattern</entry>
2919 2920 2921 2922 2923
	<entry>Description</entry>
       </row>
      </thead>
      <tbody>
       <row>
2924
	<entry><literal>HH</literal></entry>
2925
	<entry>hour of day (01-12)</entry>
2926 2927
       </row>
       <row>
2928
	<entry><literal>HH12</literal></entry>
2929
	<entry>hour of day (01-12)</entry>
2930
       </row>       
2931
       <row>
2932
	<entry><literal>HH24</literal></entry>
2933 2934
	<entry>hour of day (00-23)</entry>
       </row>       
2935
       <row>
2936
	<entry><literal>MI</literal></entry>
2937
	<entry>minute (00-59)</entry>
2938 2939
       </row>   
       <row>
2940
	<entry><literal>SS</literal></entry>
2941
	<entry>second (00-59)</entry>
2942
       </row>
2943
       <row>
2944
	<entry><literal>MS</literal></entry>
2945 2946 2947
	<entry>millisecond (000-999)</entry>
       </row>
       <row>
2948
	<entry><literal>US</literal></entry>
2949 2950
	<entry>microsecond (000000-999999)</entry>
       </row>
2951
       <row>
2952
	<entry><literal>SSSS</literal></entry>
2953
	<entry>seconds past midnight (0-86399)</entry>
2954
       </row>
2955
       <row>
2956
	<entry><literal>AM</literal> or <literal>A.M.</literal> or
2957
	<literal>PM</literal> or <literal>P.M.</literal></entry>
2958 2959 2960
	<entry>meridian indicator (upper case)</entry>
       </row>
       <row>
2961
	<entry><literal>am</literal> or <literal>a.m.</literal> or
2962
	<literal>pm</literal> or <literal>p.m.</literal></entry>
2963 2964
	<entry>meridian indicator (lower case)</entry>
       </row>
2965
       <row>
2966
	<entry><literal>Y,YYY</literal></entry>
2967
	<entry>year (4 and more digits) with comma</entry>
2968 2969
       </row>
       <row>
2970
	<entry><literal>YYYY</literal></entry>
2971
	<entry>year (4 and more digits)</entry>
2972 2973
       </row>
       <row>
2974
	<entry><literal>YYY</literal></entry>
2975
	<entry>last 3 digits of year</entry>
2976 2977
       </row>
       <row>
2978
	<entry><literal>YY</literal></entry>
2979
	<entry>last 2 digits of year</entry>
2980 2981
       </row>
       <row>
2982
	<entry><literal>Y</literal></entry>
2983
	<entry>last digit of year</entry>
2984
       </row>
2985
       <row>
2986
	<entry><literal>BC</literal> or <literal>B.C.</literal> or
2987
	<literal>AD</literal> or <literal>A.D.</literal></entry>
2988
	<entry>era indicator (upper case)</entry>
2989 2990
       </row>
       <row>
2991
	<entry><literal>bc</literal> or <literal>b.c.</literal> or
2992
	<literal>ad</literal> or <literal>a.d.</literal></entry>
2993
	<entry>era indicator (lower case)</entry>
2994
       </row>
2995
       <row>
2996
	<entry><literal>MONTH</literal></entry>
2997
	<entry>full upper case month name (blank-padded to 9 chars)</entry>
2998 2999
       </row>
       <row>
3000
	<entry><literal>Month</literal></entry>
3001
	<entry>full mixed case month name (blank-padded to 9 chars)</entry>
3002 3003
       </row>
       <row>
3004
	<entry><literal>month</literal></entry>
3005
	<entry>full lower case month name (blank-padded to 9 chars)</entry>
3006 3007
       </row>
       <row>
3008
	<entry><literal>MON</literal></entry>
3009
	<entry>abbreviated upper case month name (3 chars)</entry>
3010 3011
       </row>
       <row>
3012
	<entry><literal>Mon</literal></entry>
3013
	<entry>abbreviated mixed case month name (3 chars)</entry>
3014 3015
       </row>
       <row>
3016
	<entry><literal>mon</literal></entry>
3017
	<entry>abbreviated lower case month name (3 chars)</entry>
3018 3019
       </row>
       <row>
3020
	<entry><literal>MM</literal></entry>
3021
	<entry>month number (01-12)</entry>
3022 3023
       </row>
       <row>
3024
	<entry><literal>DAY</literal></entry>
3025
	<entry>full upper case day name (blank-padded to 9 chars)</entry>
3026 3027
       </row>
       <row>
3028
	<entry><literal>Day</literal></entry>
3029
	<entry>full mixed case day name (blank-padded to 9 chars)</entry>
3030 3031
       </row>
       <row>
3032
	<entry><literal>day</literal></entry>
3033
	<entry>full lower case day name (blank-padded to 9 chars)</entry>
3034 3035
       </row>
       <row>
3036
	<entry><literal>DY</literal></entry>
3037
	<entry>abbreviated upper case day name (3 chars)</entry>
3038 3039
       </row>
       <row>
3040
	<entry><literal>Dy</literal></entry>
3041
	<entry>abbreviated mixed case day name (3 chars)</entry>
3042 3043
       </row>
       <row>
3044
	<entry><literal>dy</literal></entry>
3045
	<entry>abbreviated lower case day name (3 chars)</entry>
3046 3047
       </row>
       <row>
3048
	<entry><literal>DDD</literal></entry>
3049
	<entry>day of year (001-366)</entry>
3050 3051
       </row>
       <row>
3052
	<entry><literal>DD</literal></entry>
3053
	<entry>day of month (01-31)</entry>
3054 3055
       </row>
       <row>
3056
	<entry><literal>D</literal></entry>
3057
	<entry>day of week (1-7; SUN=1)</entry>
3058 3059
       </row>
       <row>
3060
	<entry><literal>W</literal></entry>
3061
	<entry>week of month (1-5) where first week start on the first day of the month</entry>
3062 3063
       </row> 
       <row>
3064
	<entry><literal>WW</literal></entry>
3065
	<entry>week number of year (1-53) where first week start on the first day of the year</entry>
3066
       </row>
Bruce Momjian's avatar
Bruce Momjian committed
3067
       <row>
3068
	<entry><literal>IW</literal></entry>
3069
	<entry>ISO week number of year (The first Thursday of the new year is in week 1.)</entry>
Bruce Momjian's avatar
Bruce Momjian committed
3070
       </row>
3071
       <row>
3072
	<entry><literal>CC</literal></entry>
3073
	<entry>century (2 digits)</entry>
3074 3075
       </row>
       <row>
3076
	<entry><literal>J</literal></entry>
3077
	<entry>Julian Day (days since January 1, 4712 BC)</entry>
3078 3079
       </row>
       <row>
3080
	<entry><literal>Q</literal></entry>
3081
	<entry>quarter</entry>
3082 3083
       </row>
       <row>
3084
	<entry><literal>RM</literal></entry>
3085
	<entry>month in Roman Numerals (I-XII; I=January) - upper case</entry>
3086 3087
       </row>
       <row>
3088
	<entry><literal>rm</literal></entry>
3089
	<entry>month in Roman Numerals (I-XII; I=January) - lower case</entry>
3090
       </row>
3091
       <row>
3092
	<entry><literal>TZ</literal></entry>
3093
	<entry>time-zone name - upper case</entry>
3094 3095
       </row>
       <row>
3096
	<entry><literal>tz</literal></entry>
3097
	<entry>time-zone name - lower case</entry>
3098
       </row>
3099 3100 3101 3102 3103
      </tbody>
     </tgroup>
    </table>

   <para>
3104 3105 3106 3107
    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.
3108 3109
    <xref linkend="functions-formatting-datetimemod-table"> shows the
    modifier patterns for date/time formatting.
3110 3111
   </para>

3112
    <table id="functions-formatting-datetimemod-table">
3113
     <title>Template pattern modifiers for date/time conversions</title>
3114 3115 3116
     <tgroup cols="3">
      <thead>
       <row>
3117
	<entry>Modifier</entry>
3118 3119 3120 3121 3122 3123
	<entry>Description</entry>
	<entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
3124 3125
	<entry><literal>FM</literal> prefix</entry>
	<entry>fill mode (suppress padding blanks and zeroes)</entry>
3126
	<entry><literal>FMMonth</literal></entry>
3127 3128
       </row>
       <row>
3129 3130
	<entry><literal>TH</literal> suffix</entry>
	<entry>add upper-case ordinal number suffix</entry>
3131
	<entry><literal>DDTH</literal></entry>
3132 3133
       </row>	
       <row>
3134 3135
	<entry><literal>th</literal> suffix</entry>
	<entry>add lower-case ordinal number suffix</entry>
3136
	<entry><literal>DDth</literal></entry>
3137 3138
       </row>
       <row>
3139
	<entry><literal>FX</literal> prefix</entry>
3140
	<entry>fixed format global option (see usage notes)</entry>
3141
	<entry><literal>FX Month DD Day</literal></entry>
3142 3143
       </row>	
       <row>
3144
	<entry><literal>SP</literal> suffix</entry>
3145
	<entry>spell mode (not yet implemented)</entry>
3146
	<entry><literal>DDSP</literal></entry>
3147 3148 3149 3150 3151 3152
       </row>       
      </tbody>
     </tgroup>
    </table>

   <para>
3153
    Usage notes for the date/time formatting:
3154 3155

    <itemizedlist>
3156 3157
     <listitem>
      <para>
3158
       <literal>FM</literal> suppresses leading zeroes and trailing blanks
3159 3160 3161 3162 3163
       that would otherwise be added to make the output of a pattern be
       fixed-width.
      </para>
     </listitem>

3164 3165 3166
     <listitem>
      <para>
       <function>to_timestamp</function> and <function>to_date</function>
3167
       skip multiple blank spaces in the input string if the <literal>FX</literal> option 
3168 3169 3170
       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
3171 3172
       <literal>to_timestamp('2000    JUN','FXYYYY MON')</literal> returns an error,
       because <function>to_timestamp</function> expects one blank space only.
3173 3174 3175 3176 3177
      </para>
     </listitem>

     <listitem>
      <para>
3178 3179 3180 3181
       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
3182
       any string constant in <productname>PostgreSQL</productname>.
3183 3184 3185 3186 3187
      </para>
     </listitem>

     <listitem>
      <para>
3188
       Ordinary text is allowed in <function>to_char</function>
3189 3190 3191
       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
3192 3193
       <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
       will be replaced by the year data, but the single <literal>Y</literal> in <quote>Year</quote>
3194
       will not be.
3195 3196 3197 3198 3199
      </para>
     </listitem>

     <listitem>
      <para>
3200 3201 3202
       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 :-) -->
3203 3204
      </para>
     </listitem>
3205 3206 3207

     <listitem>
      <para>
3208 3209
       <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
       <type>date</type> is restricted if you use a year with more than 4 digits. You must
Peter Eisentraut's avatar
Peter Eisentraut committed
3210
       use some non-digit character or template after <literal>YYYY</literal>,
3211
       otherwise the year is always interpreted as 4 digits. For example
Peter Eisentraut's avatar
Peter Eisentraut committed
3212 3213
       (with year 20000):
       <literal>to_date('200001131', 'YYYYMMDD')</literal> will be 
3214
       interpreted as a 4-digit year; better is to use a non-digit 
Peter Eisentraut's avatar
Peter Eisentraut committed
3215 3216 3217
       separator after the year, like
       <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
       <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
3218 3219
      </para>
     </listitem>
3220 3221 3222

     <listitem>
      <para>
3223
       Millisecond <literal>MS</literal> and microsecond <literal>US</literal>
Peter Eisentraut's avatar
Peter Eisentraut committed
3224 3225
       values in a conversion from string to time stamp are used as part of the
       seconds after the decimal point. For example 
3226
       <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
Peter Eisentraut's avatar
Peter Eisentraut committed
3227
       but 300, because the conversion counts it as 12 + 0.3.
3228 3229
       This means for the format <literal>SS:MS</literal>, the input values
       <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
Peter Eisentraut's avatar
Peter Eisentraut committed
3230
       same number of milliseconds. To get three milliseconds, one must use
3231
       <literal>12:003</literal>, which the conversion counts as
Peter Eisentraut's avatar
Peter Eisentraut committed
3232 3233 3234 3235 3236
       12 + 0.003 = 12.003 seconds.
      </para>

      <para>
       Here is a more 
3237 3238
       complex example: 
       <literal>to_timestamp('15:12:02.020.001230','HH:MI:SS.MS.US')</literal>
Peter Eisentraut's avatar
Peter Eisentraut committed
3239 3240
       is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
       1230 microseconds = 2.021230 seconds. 
3241 3242
      </para>
     </listitem>
3243
    </itemizedlist>
3244
   </para>
3245

3246 3247 3248 3249 3250 3251
  <para>
   <xref linkend="functions-formatting-numeric-table"> shows the
   template patterns available for formatting numeric values.
  </para>

    <table id="functions-formatting-numeric-table">
3252
     <title>Template patterns for numeric conversions</title>
3253 3254 3255
     <tgroup cols="2">
      <thead>
       <row>
3256
	<entry>Pattern</entry>
3257 3258 3259 3260 3261
	<entry>Description</entry>
       </row>
      </thead>
      <tbody>
       <row>
3262
	<entry><literal>9</literal></entry>
3263
	<entry>value with the specified number of digits</entry>
3264 3265
       </row>
       <row>
3266
	<entry><literal>0</literal></entry>
3267
	<entry>value with leading zeros</entry>
3268 3269
       </row>
       <row>
3270
	<entry><literal>.</literal> (period)</entry>
3271
	<entry>decimal point</entry>
3272 3273
       </row>       
       <row>
3274
	<entry><literal>,</literal> (comma)</entry>
3275
	<entry>group (thousand) separator</entry>
3276 3277
       </row>
       <row>
3278
	<entry><literal>PR</literal></entry>
3279
	<entry>negative value in angle brackets</entry>
3280 3281
       </row>
       <row>
3282
	<entry><literal>S</literal></entry>
3283
	<entry>negative value with minus sign (uses locale)</entry>
3284 3285
       </row>
       <row>
3286
	<entry><literal>L</literal></entry>
3287
	<entry>currency symbol (uses locale)</entry>
3288 3289
       </row>
       <row>
3290
	<entry><literal>D</literal></entry>
3291
	<entry>decimal point (uses locale)</entry>
3292 3293
       </row>
       <row>
3294
	<entry><literal>G</literal></entry>
3295
	<entry>group separator (uses locale)</entry>
3296 3297
       </row>
       <row>
3298
	<entry><literal>MI</literal></entry>
3299
	<entry>minus sign in specified position (if number &lt; 0)</entry>
3300 3301
       </row>
       <row>
3302
	<entry><literal>PL</literal></entry>
3303
	<entry>plus sign in specified position (if number &gt; 0)</entry>
3304 3305
       </row>
       <row>
3306
	<entry><literal>SG</literal></entry>
3307
	<entry>plus/minus sign in specified position</entry>
3308 3309
       </row>
       <row>
3310
	<entry><literal>RN</literal></entry>
3311
	<entry>roman numeral (input between 1 and 3999)</entry>
3312 3313
       </row>
       <row>
3314
	<entry><literal>TH</literal> or <literal>th</literal></entry>
3315
	<entry>convert to ordinal number</entry>
3316 3317
       </row>
       <row>
3318
	<entry><literal>V</literal></entry>
3319
	<entry>shift <replaceable>n</replaceable> digits (see
3320
	 notes)</entry>
3321 3322
       </row>
       <row>
3323
	<entry><literal>EEEE</literal></entry>
Peter Eisentraut's avatar
Peter Eisentraut committed
3324
	<entry>scientific notation (not implemented yet)</entry>
3325 3326 3327 3328 3329 3330
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
3331
    Usage notes for the numeric formatting:
3332 3333 3334 3335

    <itemizedlist>
     <listitem>
      <para>
3336 3337
       A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
       <literal>MI</literal> is not an anchor in
3338
       the number; for example,
3339 3340
       <literal>to_char(-12, 'S9999')</literal> produces <literal>'  -12'</literal>,
       but <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-  12'</literal>.
3341 3342
       The Oracle implementation does not allow the use of
       <literal>MI</literal> ahead of <literal>9</literal>, but rather
3343
       requires that <literal>9</literal> precede
3344 3345 3346 3347 3348 3349
       <literal>MI</literal>.
      </para>
     </listitem>

     <listitem>
      <para>
3350 3351
       <literal>9</literal> specifies a value with the same number of 
       digits as there are <literal>9</literal>s. If a digit is
3352
       not available it outputs a space.
3353 3354 3355 3356 3357
      </para>
     </listitem>

     <listitem>
      <para>
3358 3359
       <literal>TH</literal> does not convert values less than zero
       and does not convert decimal numbers.
3360 3361 3362 3363 3364
      </para>
     </listitem>

     <listitem>
      <para>
3365
       <literal>PL</literal>, <literal>SG</literal>, and
3366
       <literal>TH</literal> are <productname>PostgreSQL</productname>
3367
       extensions. 
3368 3369 3370 3371 3372 3373 3374 3375 3376 3377 3378
      </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
3379 3380
       <literal>V</literal> combined with a decimal point.
       (E.g., <literal>99.9V99</literal> is not allowed.)
3381 3382 3383
      </para>
     </listitem>
    </itemizedlist>
3384
   </para>   
3385

3386 3387 3388 3389 3390 3391
  <para>
   <xref linkend="functions-formatting-examples-table"> shows some
   examples of the use of the <function>to_char</function> function.
  </para>

    <table id="functions-formatting-examples-table">
3392
     <title><function>to_char</function> Examples</title>
3393 3394 3395 3396 3397 3398 3399 3400 3401
     <tgroup cols="2">
      <thead>
       <row>
	<entry>Input</entry>
	<entry>Output</entry>
       </row>
      </thead>
      <tbody>
       <row>
3402
        <entry><literal>to_char(now(),'Day, DD  HH12:MI:SS')</literal></entry>
3403
        <entry><literal>'Tuesday  , 06  05:39:18'</literal></entry>
3404
       </row>
3405
       <row>
3406
        <entry><literal>to_char(now(),'FMDay, FMDD  HH12:MI:SS')</literal></entry>
3407
        <entry><literal>'Tuesday, 6  05:39:18'</literal></entry>
3408 3409
       </row>          
       <row>
3410
        <entry><literal>to_char(-0.1,'99.99')</literal></entry>
3411
        <entry><literal>' -.10'</literal></entry>
3412 3413
       </row>
       <row>
3414
        <entry><literal>to_char(-0.1,'FM9.99')</literal></entry>
3415
        <entry><literal>'-.1'</literal></entry>
3416 3417
       </row>
       <row>
3418
        <entry><literal>to_char(0.1,'0.9')</literal></entry>
3419
        <entry><literal>' 0.1'</literal></entry>
3420 3421
       </row>
       <row>
3422
        <entry><literal>to_char(12,'9990999.9')</literal></entry>
3423
        <entry><literal>'    0012.0'</literal></entry>
3424 3425
       </row>
       <row>
3426
        <entry><literal>to_char(12,'FM9990999.9')</literal></entry>
3427
        <entry><literal>'0012'</literal></entry>
3428 3429
       </row>
       <row>
3430
        <entry><literal>to_char(485,'999')</literal></entry>
3431
        <entry><literal>' 485'</literal></entry>
3432 3433
       </row>
       <row>
3434
        <entry><literal>to_char(-485,'999')</literal></entry>
3435
        <entry><literal>'-485'</literal></entry>
3436 3437
       </row>
       <row>
3438
        <entry><literal>to_char(485,'9 9 9')</literal></entry>
3439
        <entry><literal>' 4 8 5'</literal></entry>
3440 3441
       </row>
       <row>
3442
        <entry><literal>to_char(1485,'9,999')</literal></entry>
3443
        <entry><literal>' 1,485'</literal></entry>
3444 3445
       </row>
       <row>
3446
        <entry><literal>to_char(1485,'9G999')</literal></entry>
3447
        <entry><literal>' 1 485'</literal></entry>
3448 3449
       </row>
       <row>
3450
        <entry><literal>to_char(148.5,'999.999')</literal></entry>
3451
        <entry><literal>' 148.500'</literal></entry>
3452 3453
       </row>
       <row>
3454
        <entry><literal>to_char(148.5,'999D999')</literal></entry>
3455
        <entry><literal>' 148,500'</literal></entry>	 
3456 3457
       </row>
       <row>
3458
        <entry><literal>to_char(3148.5,'9G999D999')</literal></entry>
3459
        <entry><literal>' 3 148,500'</literal></entry>
3460 3461
       </row>
       <row>
3462
        <entry><literal>to_char(-485,'999S')</literal></entry>
3463
        <entry><literal>'485-'</literal></entry>
3464 3465
       </row>
       <row>		
3466
        <entry><literal>to_char(-485,'999MI')</literal></entry>
3467
        <entry><literal>'485-'</literal></entry>	
3468 3469
       </row>
       <row>
3470
        <entry><literal>to_char(485,'999MI')</literal></entry>
3471
        <entry><literal>'485'</literal></entry>		
3472 3473
       </row>
       <row>
3474
        <entry><literal>to_char(485,'PL999')</literal></entry>
3475
        <entry><literal>'+485'</literal></entry>	
3476 3477
       </row>
       <row>		
3478
        <entry><literal>to_char(485,'SG999')</literal></entry>
3479
        <entry><literal>'+485'</literal></entry>	
3480 3481
       </row>
       <row>
3482
        <entry><literal>to_char(-485,'SG999')</literal></entry>
3483
        <entry><literal>'-485'</literal></entry>	
3484 3485
       </row>
       <row>
3486
        <entry><literal>to_char(-485,'9SG99')</literal></entry>
3487
        <entry><literal>'4-85'</literal></entry>	
3488 3489
       </row>
       <row>
3490
        <entry><literal>to_char(-485,'999PR')</literal></entry>
3491
        <entry><literal>'&lt;485&gt;'</literal></entry>		
3492 3493
       </row>
       <row>
3494
        <entry><literal>to_char(485,'L999')</literal></entry>
3495
        <entry><literal>'DM 485</literal></entry>	 
3496 3497
       </row>
       <row>
3498
        <entry><literal>to_char(485,'RN')</literal></entry>		
3499
        <entry><literal>'        CDLXXXV'</literal></entry>
3500 3501
       </row>
       <row>
3502
        <entry><literal>to_char(485,'FMRN')</literal></entry>	
3503
        <entry><literal>'CDLXXXV'</literal></entry>
3504 3505
       </row>
       <row>
3506
        <entry><literal>to_char(5.2,'FMRN')</literal></entry>
3507
        <entry><literal>V</literal></entry>		
3508 3509
       </row>
       <row>
3510
        <entry><literal>to_char(482,'999th')</literal></entry>
3511
        <entry><literal>' 482nd'</literal></entry>				
3512 3513
       </row>
       <row>
3514
        <entry><literal>to_char(485, '"Good number:"999')</literal></entry>
3515
        <entry><literal>'Good number: 485'</literal></entry>
3516 3517
       </row>
       <row>
3518
        <entry><literal>to_char(485.8,'"Pre:"999" Post:" .999')</literal></entry>
3519
        <entry><literal>'Pre: 485 Post: .800'</literal></entry>
3520 3521
       </row>
       <row>
3522
        <entry><literal>to_char(12,'99V999')</literal></entry>		
3523
        <entry><literal>' 12000'</literal></entry>
3524 3525
       </row>
       <row>
3526
        <entry><literal>to_char(12.4,'99V999')</literal></entry>
3527
        <entry><literal>' 12400'</literal></entry>
3528 3529
       </row>
       <row>		
3530
        <entry><literal>to_char(12.45, '99V9')</literal></entry>
3531
        <entry><literal>' 125'</literal></entry>
3532 3533 3534 3535
       </row>
      </tbody>
     </tgroup>
    </table>
3536

3537 3538 3539
  </sect1>


3540
  <sect1 id="functions-datetime">
3541
   <title>Date/Time Functions and Operators</title>
3542

3543 3544 3545 3546 3547 3548 3549 3550 3551
  <para>
   <xref linkend="functions-datetime-table"> shows the available
   functions for date/time value processing, with details appearing in
   the following subsections.  <xref
   linkend="operators-datetime-table"> illustrates the behaviors of
   the basic arithmetic operators (<literal>+</literal>,
   <literal>*</literal>, etc.).  For formatting functions, refer to
   <xref linkend="functions-formatting">.  You should be familiar with
   the background information on date/time data types (see <xref
3552 3553 3554 3555 3556 3557 3558 3559
   linkend="datatype-datetime">).
  </para>

  <para>
   All the functions and operators described below that take time or timestamp
   inputs actually come in two variants: one that takes time or timestamp
   with time zone, and one that takes time or timestamp without time zone.
   For brevity, these variants are not shown separately.
3560
  </para>
3561 3562 3563 3564

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

3565
     <tgroup cols="3">
3566 3567 3568 3569 3570 3571 3572 3573 3574 3575
      <thead>
       <row>
        <entry>Name</entry>
        <entry>Example</entry>
        <entry>Result</entry>
       </row>
      </thead>

      <tbody>
       <row>
3576
        <entry> <literal>+</literal> </entry>
3577 3578
        <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
        <entry><literal>timestamp '2001-09-29 00:00'</literal></entry>
3579 3580 3581
       </row>

       <row>
3582
        <entry> <literal>+</literal> </entry>
3583 3584
        <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
        <entry><literal>timestamp '2001-09-28 01:00'</literal></entry>
3585 3586 3587
       </row>

       <row>
3588
        <entry> <literal>+</literal> </entry>
3589 3590
        <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
        <entry><literal>time '04:00'</literal></entry>
3591 3592 3593
       </row>

       <row>
3594
        <entry> <literal>-</literal> </entry>
3595 3596
        <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
        <entry><literal>timestamp '2001-09-28'</literal></entry>
3597 3598 3599
       </row>

       <row>
3600
        <entry> <literal>-</literal> </entry>
3601 3602
        <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
        <entry><literal>timestamp '2001-09-27 23:00'</literal></entry>
3603 3604 3605
       </row>

       <row>
3606
        <entry> <literal>-</literal> </entry>
3607 3608
        <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
        <entry><literal>time '03:00'</literal></entry>
3609 3610 3611
       </row>

       <row>
3612
        <entry> <literal>-</literal> </entry>
3613 3614
        <entry><literal>interval '2 hours' - time '05:00'</literal></entry>
        <entry><literal>time '03:00:00'</literal></entry>
3615 3616 3617 3618
       </row>

       <row>
        <entry> <literal>*</literal> </entry>
3619 3620
        <entry><literal>interval '1 hour' * int '3'</literal></entry>
        <entry><literal>interval '03:00'</literal></entry>
3621 3622 3623 3624
       </row>

       <row>
        <entry> <literal>/</literal> </entry>
3625 3626
        <entry><literal>interval '1 hour' / int '3'</literal></entry>
        <entry><literal>interval '00:20'</literal></entry>
3627 3628 3629 3630 3631
       </row>
      </tbody>
     </tgroup>
    </table>

3632
    <table id="functions-datetime-table">
3633
     <title>Date/Time Functions</title>
3634
     <tgroup cols="5">
3635 3636
      <thead>
       <row>
3637 3638
	<entry>Name</entry>
	<entry>Return Type</entry>
3639 3640
	<entry>Description</entry>
	<entry>Example</entry>
3641
	<entry>Result</entry>
3642 3643
       </row>
      </thead>
3644

3645 3646
      <tbody>
       <row>
3647 3648
	<entry><function>age</function>(<type>timestamp</type>)</entry>
	<entry><type>interval</type></entry>
3649
	<entry>Subtract from today</entry>
3650 3651
	<entry><literal>age(timestamp '1957-06-13')</literal></entry>
	<entry><literal>43 years 8 mons 3 days</literal></entry>
3652
       </row>
3653

3654
       <row>
3655 3656
	<entry><function>age</function>(<type>timestamp</type>, <type>timestamp</type>)</entry>
	<entry><type>interval</type></entry>
3657
	<entry>Subtract arguments</entry>
3658 3659
	<entry><literal>age('2001-04-10', timestamp '1957-06-13')</literal></entry>
	<entry><literal>43 years 9 mons 27 days</literal></entry>
3660 3661 3662
       </row>

       <row>
3663 3664
	<entry><function>current_date</function></entry>
	<entry><type>date</type></entry>
3665
	<entry>Today's date; see <xref linkend="functions-datetime-current">
3666 3667 3668
	</entry>
	<entry></entry>
	<entry></entry>
3669
       </row>
3670 3671

       <row>
3672 3673
        <entry><function>current_time</function></entry>
        <entry><type>time with time zone</type></entry>
3674
        <entry>Time of day; see <xref linkend="functions-datetime-current">
3675 3676 3677
        </entry>
        <entry></entry>
        <entry></entry>
3678 3679
       </row>

3680
       <row>
3681
	<entry><function>current_timestamp</function></entry>
3682
	<entry><type>timestamp with time zone</type></entry>
3683
	<entry>Date and time; see <xref linkend="functions-datetime-current">
3684 3685 3686 3687 3688 3689
	</entry>
	<entry></entry>
	<entry></entry>
       </row>

       <row>
3690 3691
	<entry><function>date_part</function>(<type>text</type>, <type>timestamp</type>)</entry>
	<entry><type>double precision</type></entry>
3692
	<entry>Get subfield (equivalent to
3693
	 <function>extract</function>); see also <link
3694
                                                linkend="functions-datetime-datepart">below</link>
3695
        </entry>
3696 3697
	<entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
	<entry><literal>20</literal></entry>
3698
       </row>
3699

3700
       <row>
3701 3702
	<entry><function>date_part</function>(<type>text</type>, <type>interval</type>)</entry>
	<entry><type>double precision</type></entry>
3703
	<entry>Get subfield (equivalent to
3704
	 <function>extract</function>); see also <link
3705
                                                linkend="functions-datetime-datepart">below</link>
3706
        </entry>
3707 3708
	<entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
	<entry><literal>3</literal></entry>
3709
       </row>
3710

3711
       <row>
3712 3713
	<entry><function>date_trunc</function>(<type>text</type>, <type>timestamp</type>)</entry>
	<entry><type>timestamp</type></entry>
3714 3715
	<entry>Truncate to specified precision; see also <xref
                                                        linkend="functions-datetime-trunc">
3716
        </entry>
3717 3718
	<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>
3719
       </row>
3720

3721
       <row>
3722 3723
	<entry><function>extract</function>(<parameter>field</parameter> from
         <type>timestamp</type>)</entry>
3724
	<entry><type>double precision</type></entry>
3725 3726
	<entry>Get subfield; see also <xref
                                     linkend="functions-datetime-extract">
3727
        </entry>
3728 3729
	<entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
	<entry><literal>20</literal></entry>
3730
       </row>
3731 3732

       <row>
3733 3734
	<entry><function>extract</function>(<parameter>field</parameter> from
         <type>interval</type>)</entry>
3735
	<entry><type>double precision</type></entry>
3736 3737
	<entry>Get subfield; see also <xref
                                     linkend="functions-datetime-extract">
3738
        </entry>
3739 3740
	<entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
	<entry><literal>3</literal></entry>
3741 3742
       </row>

3743
       <row>
3744 3745
	<entry><function>isfinite</function>(<type>timestamp</type>)</entry>
	<entry><type>boolean</type></entry>
3746
	<entry>Test for finite time stamp (neither invalid nor infinity)</entry>
3747 3748
	<entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
	<entry><literal>true</literal></entry>
3749
       </row>
3750

3751
       <row>
3752 3753
	<entry><function>isfinite</function>(<type>interval</type>)</entry>
	<entry><type>boolean</type></entry>
3754
	<entry>Test for finite interval</entry>
3755 3756
	<entry><literal>isfinite(interval '4 hours')</literal></entry>
	<entry><literal>true</literal></entry>
3757
       </row>
3758

3759 3760 3761
       <row>
        <entry><function>localtime</function></entry>
        <entry><type>time</type></entry>
3762
        <entry>Time of day; see <xref linkend="functions-datetime-current">
3763 3764 3765 3766 3767 3768 3769 3770
        </entry>
        <entry></entry>
        <entry></entry>
       </row>

       <row>
        <entry><function>localtimestamp</function></entry>
        <entry><type>timestamp</type></entry>
3771
        <entry>Date and time; see <xref linkend="functions-datetime-current">
3772 3773 3774 3775 3776
        </entry>
        <entry></entry>
        <entry></entry>
       </row>

3777
       <row>
3778
	<entry><function>now</function>()</entry>
3779
	<entry><type>timestamp with time zone</type></entry>
3780
	<entry>Current date and time (equivalent to
3781 3782
	 <function>current_timestamp</function>); see <xref
                                                     linkend="functions-datetime-current">
3783 3784 3785
	</entry>
	<entry></entry>
	<entry></entry>
3786
       </row>
3787

3788
       <row>
3789 3790
	<entry><function>timeofday()</function></entry>
	<entry><type>text</type></entry>
3791 3792
	<entry>Current date and time; see <xref
                                         linkend="functions-datetime-current">
3793
	</entry>
3794 3795
	<entry><literal>timeofday()</literal></entry>
	<entry><literal>Wed Feb 21 17:01:13.000126 2001 EST</literal></entry>
3796 3797
       </row>

3798 3799 3800
      </tbody>
     </tgroup>
    </table>
3801 3802 3803 3804 3805 3806 3807 3808 3809

  <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>
3810
    The <function>extract</function> function retrieves subfields
3811 3812 3813 3814 3815
    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
3816 3817
    well.)  <replaceable>field</replaceable> is an identifier or
    string that selects what field to extract from the source value.
3818 3819 3820 3821 3822 3823 3824
    The <function>extract</function> function returns values of type
    <type>double precision</type>.
    The following are valid values:

    <!-- alphabetical -->
    <variablelist>
     <varlistentry>
3825
      <term><literal>century</literal></term>
3826 3827 3828 3829 3830 3831 3832 3833 3834 3835 3836
      <listitem>
       <para>
        The year field divided by 100
       </para>

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

       <para>
3837 3838 3839
        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.
3840 3841 3842 3843 3844
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
3845
      <term><literal>day</literal></term>
3846 3847 3848 3849 3850 3851 3852 3853 3854 3855 3856 3857 3858
      <listitem>
       <para>
        The day (of the month) field (1 - 31)
       </para>

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

     <varlistentry>
3859
      <term><literal>decade</literal></term>
3860 3861 3862 3863 3864 3865 3866 3867 3868 3869 3870 3871 3872
      <listitem>
       <para>
        The year field divided by 10
       </para>

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

     <varlistentry>
3873
      <term><literal>dow</literal></term>
3874 3875 3876 3877 3878 3879 3880 3881 3882 3883 3884 3885 3886 3887
      <listitem>
       <para>
        The day of the week (0 - 6; Sunday is 0) (for
        <type>timestamp</type> values only)
       </para>

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

     <varlistentry>
3888
      <term><literal>doy</literal></term>
3889 3890 3891 3892
      <listitem>
       <para>
        The day of the year (1 - 365/366) (for <type>timestamp</type> values only)
       </para>
3893

3894 3895 3896 3897 3898 3899 3900 3901
<screen>
SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
</screen>
      </listitem>
     </varlistentry>

     <varlistentry>
3902
      <term><literal>epoch</literal></term>
3903 3904 3905
      <listitem>
       <para>
        For <type>date</type> and <type>timestamp</type> values, the
3906 3907
        number of seconds since 1970-01-01 00:00:00-00 (can be negative);
	for <type>interval</type> values, the total number
3908 3909 3910 3911 3912 3913 3914 3915 3916 3917 3918 3919 3920 3921
        of seconds in the interval
       </para>

<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>
      </listitem>
     </varlistentry>

     <varlistentry>
3922
      <term><literal>hour</literal></term>
3923 3924 3925 3926 3927 3928 3929 3930 3931 3932 3933 3934 3935
      <listitem>
       <para>
        The hour field (0 - 23)
       </para>

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

     <varlistentry>
3936
      <term><literal>microseconds</literal></term>
3937 3938 3939 3940 3941 3942 3943 3944 3945 3946 3947 3948 3949 3950
      <listitem>
       <para>
        The seconds field, including fractional parts, multiplied by 1
        000 000.  Note that this includes full seconds.
       </para>

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

     <varlistentry>
3951
      <term><literal>millennium</literal></term>
3952 3953 3954 3955 3956 3957 3958 3959 3960 3961 3962
      <listitem>
       <para>
        The year field divided by 1000
       </para>

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

       <para>
3963 3964 3965
        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.
3966 3967 3968 3969 3970
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
3971
      <term><literal>milliseconds</literal></term>
3972 3973 3974 3975 3976 3977 3978 3979 3980 3981 3982 3983 3984 3985
      <listitem>
       <para>
        The seconds field, including fractional parts, multiplied by
        1000.  Note that this includes full seconds.
       </para>

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

     <varlistentry>
3986
      <term><literal>minute</literal></term>
3987 3988 3989 3990 3991 3992 3993 3994 3995 3996 3997 3998 3999
      <listitem>
       <para>
        The minutes field (0 - 59)
       </para>

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

     <varlistentry>
4000
      <term><literal>month</literal></term>
4001 4002 4003 4004 4005 4006 4007 4008 4009 4010 4011 4012 4013 4014 4015 4016 4017 4018 4019 4020 4021
      <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>

<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>
      </listitem>
     </varlistentry>

     <varlistentry>
4022
      <term><literal>quarter</literal></term>
4023 4024 4025 4026 4027 4028 4029 4030 4031 4032 4033 4034 4035 4036
      <listitem>
       <para>
        The quarter of the year (1 - 4) that the day is in (for
        <type>timestamp</type> values only)
       </para>

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

     <varlistentry>
4037
      <term><literal>second</literal></term>
4038 4039 4040 4041 4042 4043 4044 4045 4046 4047 4048 4049 4050 4051 4052 4053
      <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>

<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>
      </listitem>
     </varlistentry>
4054 4055 4056 4057 4058 4059 4060 4061 4062 4063 4064 4065 4066 4067 4068 4069 4070 4071 4072 4073 4074 4075 4076 4077 4078 4079 4080 4081
<!--
     <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>
4082 4083

     <varlistentry>
4084
      <term><literal>week</literal></term>
4085 4086 4087 4088 4089 4090 4091 4092 4093 4094 4095 4096 4097 4098 4099 4100 4101 4102
      <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>

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

     <varlistentry>
4103
      <term><literal>year</literal></term>
4104 4105 4106 4107 4108 4109 4110 4111 4112 4113 4114 4115 4116 4117
      <listitem>
       <para>
        The year field
       </para>

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

    </variablelist>

4118 4119 4120
   </para>

   <para>
4121 4122 4123
    The <function>extract</function> function is primarily intended
    for computational processing.  For formatting date/time values for
    display, see <xref linkend="functions-formatting">.
4124
   </para>
4125 4126 4127

   <anchor id="functions-datetime-datepart">
   <para>
4128 4129
    The <function>date_part</function> function is modeled on the traditional
    <productname>Ingres</productname> equivalent to the
4130
    <acronym>SQL</acronym>-standard function <function>extract</function>:
4131 4132 4133
<synopsis>
date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
</synopsis>
4134 4135
    Note that here the <replaceable>field</replaceable> parameter needs to
    be a string value, not a name.  The valid field values for
4136 4137 4138 4139 4140 4141 4142 4143
    <function>date_part</function> are the same as for
    <function>extract</function>.
   </para>

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

Tatsuo Ishii's avatar
Tatsuo Ishii committed
4144
SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
4145 4146 4147 4148 4149 4150 4151 4152 4153 4154 4155 4156 4157 4158 4159 4160 4161 4162 4163 4164 4165 4166 4167 4168 4169 4170 4171 4172 4173 4174 4175 4176 4177 4178 4179 4180 4181 4182 4183 4184 4185 4186 4187
<lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
</screen>

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

4188 4189
   <para>
    Examples:
4190 4191 4192 4193 4194 4195 4196
<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>
4197
   </para>
4198 4199
  </sect2>

4200 4201 4202 4203 4204 4205 4206 4207 4208 4209 4210 4211 4212 4213 4214 4215 4216 4217 4218 4219 4220 4221 4222 4223 4224 4225 4226 4227 4228 4229 4230 4231 4232 4233 4234 4235 4236 4237 4238 4239 4240 4241 4242 4243 4244 4245 4246 4247 4248 4249 4250 4251 4252 4253 4254 4255 4256 4257 4258 4259 4260 4261 4262 4263 4264 4265 4266 4267 4268 4269 4270 4271 4272 4273 4274 4275 4276 4277 4278 4279 4280 4281 4282 4283 4284 4285 4286 4287 4288
  <sect2 id="functions-datetime-zoneconvert">
   <title><function>AT TIME ZONE</function></title>

   <indexterm>
    <primary>timezone</primary>
    <secondary>conversion</secondary>
   </indexterm>

   <para>
    The <function>AT TIME ZONE</function> construct allows conversions
    of timestamps to different timezones.
   </para>

    <table id="functions-datetime-zoneconvert-table">
     <title>AT TIME ZONE Variants</title>
     <tgroup cols="3">
      <thead>
       <row>
	<entry>Expression</entry>
	<entry>Returns</entry>
	<entry>Description</entry>
       </row>
      </thead>

      <tbody>

       <row>
	<entry>
	 <type>timestamp without time zone</type>
	 <literal>AT TIME ZONE</literal>
	 <replaceable>zone</>
	</entry>
	<entry><type>timestamp with time zone</type></entry>
	<entry>Convert local time in given timezone to UTC</entry>
       </row>

       <row>
	<entry>
	 <type>timestamp with time zone</type>
	 <literal>AT TIME ZONE</literal>
	 <replaceable>zone</>
	</entry>
	<entry><type>timestamp without time zone</type></entry>
	<entry>Convert UTC to local time in given timezone</entry>
       </row>

       <row>
	<entry>
	 <type>time with time zone</type>
	 <literal>AT TIME ZONE</literal>
	 <replaceable>zone</>
	</entry>
	<entry><type>time with time zone</type></entry>
	<entry>Convert local time across timezones</entry>
       </row>

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

   <para>
    In these expressions, the desired time <replaceable>zone</> can be
    specified either as a text string (e.g., <literal>'PST'</literal>)
    or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
   </para>

   <para>
    Examples (supposing that <varname>TimeZone</> is <literal>PST8PDT</>):
<screen>
SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>

SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
</screen>
    The first example takes a zone-less timestamp and interprets it as MST time
    (GMT-7) to produce a UTC timestamp, which is then rotated to PST (GMT-8)
    for display.  The second example takes a timestamp specified in EST
    (GMT-5) and converts it to local time in MST (GMT-7).
   </para>

   <para>
    The function <function>timezone</function>(<replaceable>zone</>,
    <replaceable>timestamp</>) is equivalent to the SQL-compliant construct
    <replaceable>timestamp</> <literal>AT TIME ZONE</literal>
    <replaceable>zone</>. 
   </para>
  </sect2>

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

4292 4293 4294 4295 4296 4297 4298 4299 4300 4301
   <indexterm>
    <primary>date</primary>
    <secondary>current</secondary>
   </indexterm>

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

4302
   <para>
4303 4304
    The following functions are available to obtain the current date and/or
    time:
4305
<synopsis>
4306
CURRENT_DATE
4307
CURRENT_TIME
4308
CURRENT_TIMESTAMP
4309 4310
CURRENT_TIME ( <replaceable>precision</replaceable> )
CURRENT_TIMESTAMP ( <replaceable>precision</replaceable> )
4311 4312 4313 4314
LOCALTIME
LOCALTIMESTAMP
LOCALTIME ( <replaceable>precision</replaceable> )
LOCALTIMESTAMP ( <replaceable>precision</replaceable> )
4315
</synopsis>
4316 4317 4318 4319 4320 4321 4322 4323 4324 4325
    </para>

    <para>
     <function>CURRENT_TIME</function> and
     <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
     <function>LOCALTIME</function> and
     <function>LOCALTIMESTAMP</function> deliver values without time zone.
    </para>

    <para>
4326 4327 4328 4329 4330 4331 4332 4333
     <function>CURRENT_TIME</function>,
     <function>CURRENT_TIMESTAMP</function>,
     <function>LOCALTIME</function>, and
     <function>LOCALTIMESTAMP</function>
     can optionally be given
     a precision parameter, which causes the result to be rounded
     to that many fractional digits.  Without a precision parameter,
     the result is given to the full available precision.
4334 4335
    </para>

4336 4337 4338 4339 4340 4341 4342
    <note>
     <para>
      Prior to <productname>PostgreSQL</productname> 7.2, the precision
      parameters were unimplemented, and the result was always given
      in integer seconds.
     </para>
    </note>
4343

4344 4345 4346
   <para>
    Some examples:
<screen>
4347
SELECT CURRENT_TIME;
4348
<computeroutput>14:39:53.662522-05</computeroutput>
4349 4350

SELECT CURRENT_DATE;
4351
<computeroutput>2001-12-23</computeroutput>
4352 4353

SELECT CURRENT_TIMESTAMP;
4354 4355 4356 4357
<computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>

SELECT CURRENT_TIMESTAMP(2);
<computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
4358 4359 4360

SELECT LOCALTIMESTAMP;
<computeroutput>2001-12-23 14:39:53.662522</computeroutput>
4361
</screen>
4362
   </para>
4363 4364 4365

   <para>
    The function <function>now()</function> is the traditional
4366
    <productname>PostgreSQL</productname> equivalent to
4367
    <function>CURRENT_TIMESTAMP</function>.
4368 4369 4370
   </para>

   <para>
4371 4372
    There is also <function>timeofday()</function>, which for historical
    reasons returns a text string rather than a <type>timestamp</type> value:
4373 4374 4375 4376
<screen>
SELECT timeofday();
 Sat Feb 17 19:07:32.000126 2001 EST
</screen>
4377
   </para>
4378 4379

   <para>
4380 4381 4382 4383 4384
    It is important to realize that
    <function>CURRENT_TIMESTAMP</function> and related functions return
    the start time of the current transaction; their values do not
    change during the transaction. <function>timeofday()</function>
    returns the wall clock time and does advance during transactions.
4385 4386
   </para>

Bruce Momjian's avatar
Bruce Momjian committed
4387 4388 4389 4390 4391
   <note>
    <para>  
     Many other database systems advance these values more
     frequently.
    </para>
4392 4393
   </note>

4394
   <para>
4395
    All the date/time data types also accept the special literal value
4396
    <literal>now</literal> to specify the current date and time.  Thus,
4397
    the following three all return the same result:
4398 4399 4400 4401 4402
<programlisting>
SELECT CURRENT_TIMESTAMP;
SELECT now();
SELECT TIMESTAMP 'now';
</programlisting>
4403 4404
   </para>

4405 4406
    <note>
     <para>
4407 4408
      You do not want to use the third form when specifying a <literal>DEFAULT</>
      clause while creating a table.  The system will convert <literal>now</literal>
4409
      to a <type>timestamp</type> as soon as the constant is parsed, so that when
4410
      the default value is needed,
4411 4412
      the time of the table creation would be used!  The first two
      forms will not be evaluated until the default value is used,
4413 4414
      because they are function calls.  Thus they will give the desired
      behavior of defaulting to the time of row insertion.
4415 4416 4417 4418
     </para>
    </note>
  </sect2>
 </sect1>
4419 4420 4421

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

   <para>
4425 4426 4427
    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
4428 4429 4430 4431
    native support functions and operators, shown in <xref
    linkend="functions-geometry-op-table">, <xref
    linkend="functions-geometry-func-table">, and <xref
    linkend="functions-geometry-conv-table">.
4432 4433
   </para>

4434
   <table id="functions-geometry-op-table">
4435 4436 4437 4438 4439 4440 4441 4442 4443 4444 4445 4446 4447 4448 4449 4450 4451 4452 4453 4454 4455 4456 4457 4458 4459 4460 4461 4462 4463 4464 4465 4466 4467 4468 4469 4470 4471
     <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>
	<entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
       </row>
       <row>
	<entry> - </entry>
	<entry>Translation</entry>
	<entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
       </row>
       <row>
	<entry> * </entry>
	<entry>Scaling/rotation</entry>
	<entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
       </row>
       <row>
	<entry> / </entry>
	<entry>Scaling/rotation</entry>
	<entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
       </row>
       <row>
	<entry> # </entry>
	<entry>Intersection</entry>
	<entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
       </row>
       <row>
	<entry> # </entry>
4472
	<entry>Number of points in path or polygon</entry>
4473 4474 4475 4476 4477 4478 4479 4480 4481 4482 4483 4484 4485 4486 4487 4488 4489 4490 4491 4492 4493 4494 4495 4496 4497 4498 4499 4500 4501 4502 4503 4504 4505 4506 4507 4508 4509 4510 4511 4512 4513 4514 4515 4516 4517 4518 4519 4520 4521 4522 4523 4524 4525 4526 4527 4528 4529 4530 4531 4532 4533 4534 4535 4536 4537 4538 4539 4540 4541 4542 4543 4544 4545 4546 4547 4548 4549 4550 4551 4552 4553 4554 4555 4556 4557 4558 4559 4560 4561 4562 4563 4564 4565 4566 4567
	<entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
       </row>
       <row>
	<entry> ## </entry>
	<entry>Point of closest proximity</entry>
	<entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
       </row>
       <row>
	<entry> &amp;&amp; </entry>
	<entry>Overlaps?</entry>
	<entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
       </row>
       <row>
	<entry> &amp;&lt; </entry>
	<entry>Overlaps to left?</entry>
	<entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
       </row>
       <row>
	<entry> &amp;&gt; </entry>
	<entry>Overlaps to right?</entry>
	<entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
       </row>
       <row>
	<entry> &lt;-&gt; </entry>
	<entry>Distance between</entry>
	<entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
       </row>
       <row>
	<entry> &lt;&lt; </entry>
	<entry>Left of?</entry>
	<entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
       </row>
       <row>
	<entry> &lt;^ </entry>
	<entry>Is below?</entry>
	<entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
       </row>
       <row>
	<entry> &gt;&gt; </entry>
	<entry>Is right of?</entry>
	<entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
       </row>
       <row>
	<entry> &gt;^ </entry>
	<entry>Is above?</entry>
	<entry><literal>circle '((0,5),1)' >^ circle '((0,0),1)'</literal></entry>
       </row>
       <row>
	<entry> ?# </entry>
	<entry>Intersects or overlaps</entry>
	<entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
       </row>
       <row>
	<entry> ?- </entry>
	<entry>Is horizontal?</entry>
	<entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
       </row>
       <row>
	<entry> ?-| </entry>
	<entry>Is perpendicular?</entry>
	<entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
       </row>
       <row>
	<entry> @-@  </entry>
	<entry>Length or circumference</entry>
	<entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
       </row>
       <row>
	<entry> ?| </entry>
	<entry>Is vertical?</entry>
	<entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
       </row>
       <row>
	<entry> ?|| </entry>
	<entry>Is parallel?</entry>
	<entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
       </row>
       <row>
	<entry> @ </entry>
	<entry>Contained or on</entry>
	<entry><literal>point '(1,1)' @ circle '((0,0),2)'</literal></entry>
       </row>
       <row>
	<entry> @@ </entry>
	<entry>Center of</entry>
	<entry><literal>@@ circle '((0,0),10)'</literal></entry>
       </row>
       <row>
	<entry> ~= </entry>
	<entry>Same as</entry>
	<entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
       </row>
      </tbody>
     </tgroup>
   </table>
4568

4569 4570

   <table id="functions-geometry-func-table">
4571 4572 4573 4574 4575 4576 4577 4578 4579 4580 4581 4582
     <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>
4583 4584
	<entry><function>area</function>(object)</entry>
	<entry><type>double precision</type></entry>
4585
	<entry>area of item</entry>
4586
	<entry><literal>area(box '((0,0),(1,1))')</literal></entry>
4587 4588
       </row>
       <row>
4589 4590
	<entry><function>box</function>(box, box)</entry>
	<entry><type>box</type></entry>
4591
	<entry>intersection box</entry>
4592
	<entry><literal>box(box '((0,0),(1,1))',box '((0.5,0.5),(2,2))')</literal></entry>
4593 4594
       </row>
       <row>
4595 4596
	<entry><function>center</function>(object)</entry>
	<entry><type>point</type></entry>
4597
	<entry>center of item</entry>
4598
	<entry><literal>center(box '((0,0),(1,2))')</literal></entry>
4599 4600
       </row>
       <row>
4601 4602
	<entry><function>diameter</function>(circle)</entry>
	<entry><type>double precision</type></entry>
4603
	<entry>diameter of circle</entry>
4604
	<entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
4605 4606
       </row>
       <row>
4607 4608
	<entry><function>height</function>(box)</entry>
	<entry><type>double precision</type></entry>
4609
	<entry>vertical size of box</entry>
4610
	<entry><literal>height(box '((0,0),(1,1))')</literal></entry>
4611 4612
       </row>
       <row>
4613 4614
	<entry><function>isclosed</function>(path)</entry>
	<entry><type>boolean</type></entry>
4615
	<entry>a closed path?</entry>
4616
	<entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
4617 4618
       </row>
       <row>
4619 4620
	<entry><function>isopen</function>(path)</entry>
	<entry><type>boolean</type></entry>
4621
	<entry>an open path?</entry>
4622
	<entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
4623 4624
       </row>
       <row>
4625 4626
	<entry><function>length</function>(object)</entry>
	<entry><type>double precision</type></entry>
4627
	<entry>length of item</entry>
4628
	<entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
4629
       </row>
4630 4631 4632 4633 4634 4635 4636 4637 4638 4639 4640 4641
       <row>
	<entry><function>npoints</function>(path)</entry>
	<entry><type>integer</type></entry>
	<entry>number of points</entry>
	<entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
       </row>
       <row>
	<entry><function>npoints</function>(polygon)</entry>
	<entry><type>integer</type></entry>
	<entry>number of points</entry>
	<entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
       </row>
4642
       <row>
4643 4644
	<entry><function>pclose</function>(path)</entry>
	<entry><type>path</type></entry>
4645
	<entry>convert path to closed</entry>
4646
	<entry><literal>popen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
4647
       </row>
4648 4649
<![IGNORE[
<!-- Not defined by this name. Implements the intersection operator '#' -->
4650
       <row>
4651 4652
	<entry><function>point</function>(lseg,lseg)</entry>
	<entry><type>point</type></entry>
4653
	<entry>intersection</entry>
4654
	<entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
4655
       </row>
4656
]]>
4657
       <row>
4658 4659
	<entry><function>popen</function>(path)</entry>
	<entry><type>path</type></entry>
4660
	<entry>convert path to open path</entry>
4661
	<entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
4662 4663
       </row>
       <row>
4664 4665
	<entry><function>radius</function>(circle)</entry>
	<entry><type>double precision</type></entry>
4666
	<entry>radius of circle</entry>
4667
	<entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
4668 4669
       </row>
       <row>
4670 4671
	<entry><function>width</function>(box)</entry>
	<entry><type>double precision</type></entry>
4672
	<entry>horizontal size</entry>
4673
	<entry><literal>width(box '((0,0),(1,1))')</literal></entry>
4674 4675 4676
       </row>
      </tbody>
     </tgroup>
4677
   </table>
4678

4679

4680
   <table id="functions-geometry-conv-table">
4681 4682 4683 4684 4685 4686 4687 4688 4689 4690 4691 4692
     <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>
4693 4694
	<entry><function>box</function>(<type>circle</type>)</entry>
	<entry><type>box</type></entry>
4695
	<entry>circle to box</entry>
4696
	<entry><literal>box(circle '((0,0),2.0)')</literal></entry>
4697 4698
       </row>
       <row>
4699 4700
	<entry><function>box</function>(<type>point</type>, <type>point</type>)</entry>
	<entry><type>box</type></entry>
4701
	<entry>points to box</entry>
4702
	<entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
4703 4704
       </row>
       <row>
4705 4706
	<entry><function>box</function>(<type>polygon</type>)</entry>
	<entry><type>box</type></entry>
4707
	<entry>polygon to box</entry>
4708
	<entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
4709 4710
       </row>
       <row>
4711 4712
	<entry><function>circle</function>(<type>box</type>)</entry>
	<entry><type>circle</type></entry>
4713
	<entry>to circle</entry>
4714
	<entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
4715 4716
       </row>
       <row>
4717 4718
	<entry><function>circle</function>(<type>point</type>, <type>double precision</type>)</entry>
	<entry><type>circle</type></entry>
4719
	<entry>point to circle</entry>
4720
	<entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
4721 4722
       </row>
       <row>
4723 4724
	<entry><function>lseg</function>(<type>box</type>)</entry>
	<entry><type>lseg</type></entry>
4725
	<entry>box diagonal to <type>lseg</type></entry>
4726
	<entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
4727 4728
       </row>
       <row>
4729 4730
	<entry><function>lseg</function>(<type>point</type>, <type>point</type>)</entry>
	<entry><type>lseg</type></entry>
4731
	<entry>points to <type>lseg</type></entry>
4732
	<entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
4733 4734
       </row>
       <row>
4735 4736
	<entry><function>path</function>(<type>polygon</type>)</entry>
	<entry><type>point</type></entry>
4737
	<entry>polygon to path</entry>
4738
	<entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
4739 4740
       </row>
       <row>
4741 4742
	<entry><function>point</function>(<type>circle</type>)</entry>
	<entry><type>point</type></entry>
4743
	<entry>center</entry>
4744
	<entry><literal>point(circle '((0,0),2.0)')</literal></entry>
4745 4746
       </row>
       <row>
4747 4748
	<entry><function>point</function>(<type>lseg</type>, <type>lseg</type>)</entry>
	<entry><type>point</type></entry>
4749
	<entry>intersection</entry>
4750
	<entry><literal>point(lseg '((-1,0),(1,0))', lseg '((-2,-2),(2,2))')</literal></entry>
4751 4752
       </row>
       <row>
4753 4754
	<entry><function>point</function>(<type>polygon</type>)</entry>
	<entry><type>point</type></entry>
4755
	<entry>center</entry>
4756
	<entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
4757 4758
       </row>
       <row>
4759 4760
	<entry><function>polygon</function>(<type>box</type>)</entry>
	<entry><type>polygon</type></entry>
4761
	<entry>4-point polygon</entry>
4762
	<entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
4763 4764
       </row>
       <row>
4765 4766
	<entry><function>polygon</function>(<type>circle</type>)</entry>
	<entry><type>polygon</type></entry>
4767
	<entry>12-point polygon</entry>
4768
	<entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
4769 4770
       </row>
       <row>
4771 4772
	<entry><function>polygon</function>(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</entry>
	<entry><type>polygon</type></entry>
4773
	<entry><replaceable class="parameter">npts</replaceable> polygon</entry>
4774
	<entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
4775 4776
       </row>
       <row>
4777 4778
	<entry><function>polygon</function>(<type>path</type>)</entry>
	<entry><type>polygon</type></entry>
4779
	<entry>path to polygon</entry>
4780
	<entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
4781 4782 4783
       </row>
      </tbody>
     </tgroup>
4784 4785
   </table>

4786 4787
    <para>
     It is possible to access the two component numbers of a <type>point</>
4788
     as though it were an array with subscripts 0, 1.  For example, if
4789 4790 4791 4792 4793 4794 4795
     <literal>t.p</> is a <type>point</> column then
     <literal>SELECT p[0] FROM t</> retrieves the X coordinate;
     <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
     In the same way, a <type>box</> or an <type>lseg</> may be treated
     as an array of two <type>point</>s.
    </para>

4796
  </sect1>
4797

4798

4799 4800
 <sect1 id="functions-net">
  <title>Network Address Type Functions</title>
4801

4802 4803 4804 4805 4806 4807 4808 4809 4810 4811
  <para>
   <xref linkend="cidr-inet-operators-table"> shows the operators
   available for the <type>inet</type> and <type>cidr</type> types.
   The operators <literal>&lt;&lt;</literal>,
   <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>,
   <literal>&gt;&gt;=</literal> 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>
4812 4813

    <table tocentry="1" id="cidr-inet-operators-table">
4814 4815 4816 4817 4818 4819 4820 4821 4822 4823 4824 4825 4826 4827 4828 4829 4830 4831 4832 4833 4834 4835 4836 4837 4838 4839 4840 4841 4842 4843 4844 4845 4846 4847 4848 4849 4850 4851 4852 4853 4854 4855 4856 4857 4858 4859 4860 4861 4862 4863 4864 4865 4866 4867 4868 4869 4870 4871 4872 4873 4874 4875 4876
     <title><type>cidr</type> and <type>inet</type> Operators</title>
     <tgroup cols="3">
      <thead>
       <row>
	<entry>Operator</entry>
	<entry>Description</entry>
	<entry>Usage</entry>
       </row>
      </thead>
      <tbody>
       <row>
	<entry> &lt; </entry>
	<entry>Less than</entry>
	<entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
       </row>
       <row>
	<entry> &lt;= </entry>
	<entry>Less than or equal</entry>
	<entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
       </row>
       <row>
	<entry> = </entry>
	<entry>Equals</entry>
	<entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
       </row>
       <row>
	<entry> &gt;= </entry>
	<entry>Greater or equal</entry>
	<entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
       </row>
       <row>
	<entry> &gt; </entry>
	<entry>Greater</entry>
	<entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
       </row>
       <row>
	<entry> &lt;&gt; </entry>
	<entry>Not equal</entry>
	<entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
       </row>
       <row>
	<entry> &lt;&lt; </entry>
	<entry>is contained within</entry>
	<entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
       </row>
       <row>
	<entry> &lt;&lt;= </entry>
	<entry>is contained within or equals</entry>
	<entry><literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal></entry>
       </row>
       <row>
	<entry> &gt;&gt; </entry>
	<entry>contains</entry>
	<entry><literal>inet'192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
       </row>
       <row>
	<entry> &gt;&gt;= </entry>
	<entry>contains or equals</entry>
	<entry><literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal></entry>
       </row>
      </tbody>
     </tgroup>
    </table>
4877

4878 4879 4880 4881 4882 4883 4884 4885 4886 4887
  <para>
   <xref linkend="cidr-inet-functions-table"> shows the functions
   available for use with the <type>inet</type> and <type>cidr</type>
   types.  The <function>host()</function>,
   <function>text()</function>, and <function>abbrev()</function>
   functions are primarily intended to offer alternative display
   formats. You can cast a text field to inet using normal casting
   syntax: <literal>inet(expression)</literal> or
   <literal>colname::inet</literal>.
  </para>
4888

4889
    <table tocentry="1" id="cidr-inet-functions-table">
4890
     <title><type>cidr</type> and <type>inet</type> Functions</title>
4891
     <tgroup cols="5">
4892 4893 4894 4895 4896 4897
      <thead>
       <row>
	<entry>Function</entry>
	<entry>Returns</entry>
	<entry>Description</entry>
	<entry>Example</entry>
4898
	<entry>Result</entry>
4899 4900 4901 4902
       </row>
      </thead>
      <tbody>
       <row>
4903 4904
	<entry><function>broadcast</function>(<type>inet</type>)</entry>
	<entry><type>inet</type></entry>
4905
	<entry>broadcast address for network</entry>
4906 4907
	<entry><literal>broadcast('192.168.1.5/24')</literal></entry>
	<entry><literal>192.168.1.255/24</literal></entry>
4908 4909
       </row>
       <row>
4910 4911
	<entry><function>host</function>(<type>inet</type>)</entry>
	<entry><type>text</type></entry>
4912
	<entry>extract IP address as text</entry>
4913 4914
	<entry><literal>host('192.168.1.5/24')</literal></entry>
	<entry><literal>192.168.1.5</literal></entry>
4915 4916
       </row>
       <row>
4917 4918
	<entry><function>masklen</function>(<type>inet</type>)</entry>
	<entry><type>integer</type></entry>
4919
	<entry>extract netmask length</entry>
4920 4921
	<entry><literal>masklen('192.168.1.5/24')</literal></entry>
	<entry><literal>24</literal></entry>
4922
       </row>
Bruce Momjian's avatar
Bruce Momjian committed
4923
       <row>
4924 4925
	<entry><function>set_masklen</function>(<type>inet</type>,<type>integer</type>)</entry>
	<entry><type>inet</type></entry>
4926
	<entry>set netmask length for <type>inet</type> value</entry>
4927 4928
	<entry><literal>set_masklen('192.168.1.5/24',16)</literal></entry>
	<entry><literal>192.168.1.5/16</literal></entry>
Bruce Momjian's avatar
Bruce Momjian committed
4929
       </row>
4930
       <row>
4931 4932
	<entry><function>netmask</function>(<type>inet</type>)</entry>
	<entry><type>inet</type></entry>
4933
	<entry>construct netmask for network</entry>
4934 4935
	<entry><literal>netmask('192.168.1.5/24')</literal></entry>
	<entry><literal>255.255.255.0</literal></entry>
4936 4937
       </row>
       <row>
4938 4939
	<entry><function>network</function>(<type>inet</type>)</entry>
	<entry><type>cidr</type></entry>
4940
	<entry>extract network part of address</entry>
4941 4942
	<entry><literal>network('192.168.1.5/24')</literal></entry>
	<entry><literal>192.168.1.0/24</literal></entry>
4943 4944
       </row>
       <row>
4945 4946
	<entry><function>text</function>(<type>inet</type>)</entry>
	<entry><type>text</type></entry>
4947
	<entry>extract IP address and masklen as text</entry>
4948 4949
	<entry><literal>text(inet '192.168.1.5')</literal></entry>
	<entry><literal>192.168.1.5/32</literal></entry>
4950
       </row>
4951
       <row>
4952 4953
	<entry><function>abbrev</function>(<type>inet</type>)</entry>
	<entry><type>text</type></entry>
4954
	<entry>extract abbreviated display as text</entry>
4955 4956
	<entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
	<entry><literal>10.1/16</literal></entry>
4957
       </row>
4958 4959 4960 4961
      </tbody>
     </tgroup>
    </table>

4962 4963 4964 4965 4966 4967 4968 4969 4970 4971
  <para>
   <xref linkend="macaddr-functions-table"> shows the functions
   available for use with the <type>mac</type> type.  The function
   <function>trunc</function>(<type>macaddr</type>) 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</filename> in the source distribution
   contains some utilities to create and maintain such an association
   table.
  </para>
4972

4973
    <table tocentry="1" id="macaddr-functions-table">
4974
     <title><type>macaddr</type> Functions</title>
4975 4976 4977 4978 4979 4980 4981 4982
     <tgroup cols="5">
      <thead>
       <row>
	<entry>Function</entry>
	<entry>Returns</entry>
	<entry>Description</entry>
	<entry>Example</entry>
	<entry>Result</entry>
4983
       </row>
4984 4985
      </thead>
      <tbody>
4986
       <row>
4987 4988
	<entry><function>trunc</function>(<type>macaddr</type>)</entry>
	<entry><type>macaddr</type></entry>
4989
	<entry>set last 3 bytes to zero</entry>
4990 4991
	<entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
	<entry><literal>12:34:56:00:00:00</literal></entry>
4992
       </row>
4993 4994 4995
      </tbody>
     </tgroup>
    </table>
4996

4997
   <para>
4998 4999
    The <type>macaddr</type> type also supports the standard relational
    operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
5000 5001 5002
    lexicographical ordering.
   </para>

5003
  </sect1>
5004

5005

5006 5007 5008 5009 5010 5011 5012 5013 5014 5015 5016 5017 5018 5019 5020 5021
 <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>

5022 5023 5024 5025 5026 5027 5028 5029 5030 5031 5032 5033 5034
  <para>
   This section describes <productname>PostgreSQL</productname>'s functions
   for operating on <firstterm>sequence objects</firstterm>.
   Sequence objects (also called sequence generators or
   just sequences) are special single-row tables created with
   <command>CREATE SEQUENCE</command>.  A sequence object is usually used to
   generate unique identifiers for rows of a table.  The sequence functions,
   listed in <xref linkend="functions-sequence-table">,
   provide simple, multiuser-safe methods for obtaining successive
   sequence values from sequence objects.
  </para>

   <table id="functions-sequence-table">
5035
    <title>Sequence Functions</title>
5036 5037
    <tgroup cols="3">
     <thead>
5038
      <row><entry>Function</entry> <entry>Returns</entry> <entry>Description</entry></row>
5039 5040 5041 5042 5043 5044
     </thead>

     <tbody>
      <row>
	<entry><function>nextval</function>(<type>text</type>)</entry>
	<entry><type>bigint</type></entry>
5045
	<entry>Advance sequence and return new value</entry>
5046 5047 5048 5049
      </row>
      <row>
	<entry><function>currval</function>(<type>text</type>)</entry>
	<entry><type>bigint</type></entry>
5050
	<entry>Return value most recently obtained with <function>nextval</function></entry>
5051 5052 5053 5054
      </row>
      <row>
	<entry><function>setval</function>(<type>text</type>,<type>bigint</type>)</entry>
	<entry><type>bigint</type></entry>
5055
	<entry>Set sequence's current value</entry>
5056 5057
      </row>
      <row>
5058
	<entry><function>setval</function>(<type>text</type>,<type>bigint</type>,<type>boolean</type>)</entry>
5059
	<entry><type>bigint</type></entry>
5060
	<entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
5061 5062 5063 5064 5065 5066 5067 5068 5069 5070 5071 5072
      </row>
     </tbody>
    </tgroup>
   </table>

  <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>
5073 5074 5075
nextval('foo')      <lineannotation>operates on sequence <literal>foo</literal></>
nextval('FOO')      <lineannotation>operates on sequence <literal>foo</literal></>
nextval('"Foo"')    <lineannotation>operates on sequence <literal>Foo</literal></>
5076 5077 5078
</programlisting>
   The sequence name can be schema-qualified if necessary:
<programlisting>
5079 5080 5081
nextval('myschema.foo')     <lineannotation>operates on <literal>myschema.foo</literal></>
nextval('"myschema".foo')   <lineannotation>same as above</lineannotation>
nextval('foo')              <lineannotation>searches search path for <literal>foo</literal></>
5082 5083 5084 5085 5086 5087 5088 5089 5090 5091
</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>
5092
      <term><function>nextval</function></term>
5093 5094 5095
      <listitem>
       <para>
        Advance the sequence object to its next value and return that
5096
	value.  This is done atomically: even if multiple sessions
5097
	execute <function>nextval</function> concurrently, each will safely receive
5098 5099 5100 5101 5102 5103
	a distinct sequence value.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
5104
      <term><function>currval</function></term>
5105 5106
      <listitem>
       <para>
5107
        Return the value most recently obtained by <function>nextval</function>
5108
	for this sequence in the current session.  (An error is
5109
	reported if <function>nextval</function> has never been called for this
5110 5111 5112
	sequence in this session.)  Notice that because this is returning
	a session-local value, it gives a predictable answer even if other
	sessions are executing <function>nextval</function> meanwhile.
5113 5114 5115 5116 5117
       </para>
      </listitem>
     </varlistentry>

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

<screen>
5133
SELECT setval('foo', 42);           <lineannotation>Next <function>nextval()</> will return 43</lineannotation>
5134
SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
5135
SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval()</> will return 42</lineannotation>
5136 5137
</screen>

5138
        The result returned by <function>setval</function> is just the value of its
5139 5140 5141 5142 5143 5144 5145 5146 5147 5148
	second argument.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
  </para>

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

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

 </sect1>


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

5172 5173 5174 5175 5176 5177 5178 5179
  <indexterm>
   <primary>case</primary>
  </indexterm>

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

5180
  <para>
5181
   This section describes the <acronym>SQL</acronym>-compliant conditional expressions
5182
   available in <productname>PostgreSQL</productname>.
5183 5184 5185 5186 5187 5188 5189 5190 5191 5192
  </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>

5193 5194
  <sect2>
   <title>CASE</title>
5195 5196 5197 5198 5199 5200 5201 5202 5203 5204 5205

<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
5206
   other languages.  <token>CASE</token> clauses can be used wherever
5207
   an expression is valid.  <replaceable>condition</replaceable> is an
5208
   expression that returns a <type>boolean</type> result.  If the result is true
5209 5210 5211 5212 5213 5214 5215
   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
5216
   omitted and no condition matches, the result is null.
5217 5218 5219 5220 5221 5222 5223 5224 5225 5226 5227 5228 5229 5230
  </para>

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

5231 5232 5233 5234 5235 5236
<prompt>=&gt;</prompt> <userinput>SELECT a,
          CASE WHEN a=1 THEN 'one'
               WHEN a=2 THEN 'two'
               ELSE 'other'
          END
    FROM test;</userinput>
5237 5238 5239 5240 5241 5242 5243 5244 5245 5246 5247
<computeroutput>
 a | case
---+-------
 1 | one
 2 | two
 3 | other
</computeroutput>
</screen>
   </para>

  <para>
5248 5249 5250
   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.
5251 5252 5253 5254 5255 5256 5257 5258 5259 5260 5261 5262 5263 5264 5265 5266 5267
  </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
5268
   <token>ELSE</token> clause (or a null value) is returned.  This is similar
5269 5270 5271 5272 5273 5274 5275
   to the <function>switch</function> statement in C.
  </para>

   <para>
    The example above can be written using the simple
    <token>CASE</token> syntax:
<screen>
5276 5277 5278 5279 5280 5281
<prompt>=&gt;</prompt> <userinput>SELECT a,
          CASE a WHEN 1 THEN 'one'
                 WHEN 2 THEN 'two'
                 ELSE 'other'
          END
    FROM test;</userinput>
5282 5283 5284 5285 5286 5287 5288 5289 5290
<computeroutput>
 a | case
---+-------
 1 | one
 2 | two
 3 | other
</computeroutput>
</screen>
    </para>
5291
  </sect2>
5292

5293 5294
  <sect2>
   <title>COALESCE</title>
5295 5296

<synopsis>
5297
<function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
5298 5299 5300 5301
</synopsis>

  <para>
   The <function>COALESCE</function> function returns the first of its
5302 5303
   arguments that is not null.  This is often useful to substitute a
   default value for null values when data is retrieved for display,
5304 5305 5306 5307 5308
   for example:
<programlisting>
SELECT COALESCE(description, short_description, '(none)') ...
</programlisting>
  </para>
5309
  </sect2>
5310

5311 5312
  <sect2>
   <title>NULLIF</title>
5313

5314 5315 5316 5317
  <indexterm>
   <primary>nullif</primary>
  </indexterm>

5318
<synopsis>
5319
<function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
5320 5321 5322
</synopsis>

  <para>
5323
   The <function>NULLIF</function> function returns a null value if and only
5324 5325 5326 5327 5328 5329 5330 5331 5332
   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>
5333 5334 5335 5336 5337 5338 5339 5340 5341 5342 5343 5344

  <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>
5345
  </sect2>
5346

5347 5348 5349
 </sect1>


5350 5351
 <sect1 id="functions-misc">
  <title>Miscellaneous Functions</title>
5352

5353 5354 5355 5356 5357 5358
  <para>
   <xref linkend="functions-misc-session-table"> shows several
   functions that extract session and system information.
  </para>

   <table id="functions-misc-session-table">
5359
    <title>Session Information Functions</title>
5360 5361
    <tgroup cols="3">
     <thead>
5362
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
5363 5364 5365
     </thead>

     <tbody>
5366 5367 5368 5369 5370 5371 5372 5373 5374 5375 5376 5377 5378 5379 5380 5381 5382 5383
      <row>
       <entry><function>current_database()</function></entry>
       <entry><type>name</type></entry>
       <entry>name of current database</entry>
      </row>

      <row>
       <entry><function>current_schema()</function></entry>
       <entry><type>name</type></entry>
       <entry>name of current schema</entry>
      </row>

      <row>
       <entry><function>current_schemas(boolean)</function></entry>
       <entry><type>name[]</type></entry>
       <entry>names of schemas in search path optionally including implicit schemas</entry>
      </row>

5384
      <row>
5385 5386
       <entry><function>current_user</function></entry>
       <entry><type>name</type></entry>
5387
       <entry>user name of current execution context</entry>
5388
      </row>
5389

5390
      <row>
5391 5392
       <entry><function>session_user</function></entry>
       <entry><type>name</type></entry>
5393
       <entry>session user name</entry>
5394
      </row>
5395

5396
      <row>
5397 5398 5399
       <entry><function>user</function></entry>
       <entry><type>name</type></entry>
       <entry>equivalent to <function>current_user</function></entry>
5400
      </row>
5401

5402
      <row>
5403
       <entry><function>version()</function></entry>
5404 5405
       <entry><type>text</type></entry>
       <entry>PostgreSQL version information</entry>
Bruce Momjian's avatar
Bruce Momjian committed
5406
      </row>
5407 5408 5409 5410
     </tbody>
    </tgroup>
   </table>

5411 5412 5413 5414 5415
   <indexterm zone="functions-misc">
    <primary>user</primary>
    <secondary>current</secondary>
   </indexterm>

5416 5417 5418 5419 5420 5421 5422 5423 5424 5425
   <indexterm zone="functions-misc">
    <primary>schema</primary>
    <secondary>current</secondary>
   </indexterm>

   <indexterm zone="functions-misc">
    <primary>search path</primary>
    <secondary>current</secondary>
   </indexterm>

5426
   <para>
5427
    The <function>session_user</function> is the user that initiated a
5428
    database connection; it is fixed for the duration of that
5429
    connection. The <function>current_user</function> is the user identifier
5430 5431 5432
    that is applicable for permission checking. Normally, it is equal
    to the session user, but it changes during the execution of
    functions with the attribute <literal>SECURITY DEFINER</literal>.
5433 5434
    In Unix parlance, the session user is the <quote>real user</quote> and
    the current user is the <quote>effective user</quote>.
5435 5436
   </para>

5437 5438
   <note>
    <para>
5439 5440
     <function>current_user</function>, <function>session_user</function>, and
     <function>user</function> have special syntactic status in <acronym>SQL</acronym>:
5441 5442 5443
     they must be called without trailing parentheses.
    </para>
   </note>
5444

5445
   <para>
5446
    <function>current_schema</function> returns the name of the schema that is
5447
    at the front of the search path (or a null value if the search path is
5448 5449
    empty).  This is the schema that will be used for any tables or
    other named objects that are created without specifying a target schema.
5450 5451 5452 5453
    <function>current_schemas(boolean)</function> returns an array of the names of all
    schemas presently in the search path.  The boolean option determines whether or not
    implicitly included system schemas such as pg_catalog are included in the search 
    path returned.
5454 5455
   </para>

5456
   <para>
5457 5458 5459 5460
    <indexterm>
     <primary>search path</primary>
     <secondary>changing at runtime</secondary>
    </indexterm>
5461
    The search path may be altered by a run-time setting.  The
5462 5463 5464 5465 5466
    command to use is <command>
     SET SEARCH_PATH '<varname>schema</varname>'[,'<varname>schema</varname>']...
    </command>
   </para>

5467 5468 5469 5470 5471
   <indexterm zone="functions-misc">
    <primary>version</primary>
   </indexterm>

   <para>
5472 5473
    <function>version()</function> returns a string describing the
    <productname>PostgreSQL</productname> server's version.
5474 5475
   </para>

5476 5477 5478 5479 5480 5481
  <para>
   <xref linkend="functions-misc-set-table"> shows the functions
   available to query and alter run-time configuration parameters.
  </para>

   <table id="functions-misc-set-table">
5482 5483 5484 5485 5486 5487 5488 5489 5490 5491 5492 5493 5494 5495 5496 5497 5498 5499 5500 5501 5502 5503 5504 5505 5506 5507 5508 5509 5510 5511 5512 5513 5514 5515 5516 5517 5518 5519 5520 5521 5522 5523 5524 5525 5526 5527 5528 5529 5530 5531 5532 5533 5534 5535 5536 5537 5538 5539 5540 5541
    <title>Configuration Settings Information Functions</title>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
     </thead>

     <tbody>
      <row>
       <entry>
        <function>current_setting</function>(<parameter>setting_name</parameter>)
       </entry>
       <entry><type>text</type></entry>
       <entry>value of current setting</entry>
      </row>
      <row>
       <entry>
        <function>set_config(<parameter>setting_name</parameter>,
                             <parameter>new_value</parameter>,
                             <parameter>is_local</parameter>)</function>
       </entry>
       <entry><type>text</type></entry>
       <entry>new value of current setting</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-misc">
    <primary>setting</primary>
    <secondary>current</secondary>
   </indexterm>

   <indexterm zone="functions-misc">
    <primary>setting</primary>
    <secondary>set</secondary>
   </indexterm>

   <para>
    The <function>current_setting</function> is used to obtain the current
    value of the <parameter>setting_name</parameter> setting, as a query
    result. It is the equivalent to the SQL <command>SHOW</command> command.
    For example:
<programlisting>
select current_setting('DateStyle');
            current_setting
---------------------------------------
 ISO with US (NonEuropean) conventions
(1 row)
</programlisting>
   </para>

   <para>
    <function>set_config</function> allows the <parameter>setting_name
    </parameter> setting to be changed to <parameter>new_value</parameter>.
    If <parameter>is_local</parameter> is set to <literal>true</literal>,
    the new value will only apply to the current transaction. If you want
    the new value to apply for the current session, use
    <literal>false</literal> instead. It is the equivalent to the SQL
    <command>SET</command> command. For example:
<programlisting>
5542
select set_config('show_statement_stats','off','f');
5543 5544 5545 5546 5547 5548 5549
 set_config
------------
 off
(1 row)
</programlisting>
   </para>

5550 5551 5552 5553 5554 5555 5556 5557
  <para>
   <xref linkend="functions-misc-access-table"> lists functions that
   allow the user to query object access privileges programmatically.
   See <xref linkend="ddl-priv"> for more information about
   privileges.
  </para>

   <table id="functions-misc-access-table">
5558
    <title>Access Privilege Inquiry Functions</title>
5559 5560
    <tgroup cols="3">
     <thead>
5561
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
5562 5563 5564 5565
     </thead>

     <tbody>
      <row>
5566
       <entry><function>has_table_privilege</function>(<parameter>user</parameter>,
5567 5568 5569
                                  <parameter>table</parameter>,
                                  <parameter>access</parameter>)
       </entry>
5570 5571
       <entry><type>boolean</type></entry>
       <entry>does user have access to table</entry>
5572 5573
      </row>
      <row>
5574
       <entry><function>has_table_privilege</function>(<parameter>table</parameter>,
5575 5576
                                  <parameter>access</parameter>)
       </entry>
5577 5578
       <entry><type>boolean</type></entry>
       <entry>does current user have access to table</entry>
5579
      </row>
5580 5581 5582 5583 5584 5585 5586 5587 5588 5589 5590 5591 5592 5593 5594 5595 5596 5597 5598 5599 5600 5601 5602 5603 5604 5605 5606 5607 5608 5609 5610 5611 5612 5613 5614 5615 5616 5617 5618 5619 5620 5621 5622 5623 5624 5625 5626 5627 5628 5629 5630 5631 5632 5633 5634 5635 5636 5637 5638 5639
      <row>
       <entry><function>has_database_privilege</function>(<parameter>user</parameter>,
                                  <parameter>database</parameter>,
                                  <parameter>access</parameter>)
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does user have access to database</entry>
      </row>
      <row>
       <entry><function>has_database_privilege</function>(<parameter>database</parameter>,
                                  <parameter>access</parameter>)
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does current user have access to database</entry>
      </row>
      <row>
       <entry><function>has_function_privilege</function>(<parameter>user</parameter>,
                                  <parameter>function</parameter>,
                                  <parameter>access</parameter>)
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does user have access to function</entry>
      </row>
      <row>
       <entry><function>has_function_privilege</function>(<parameter>function</parameter>,
                                  <parameter>access</parameter>)
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does current user have access to function</entry>
      </row>
      <row>
       <entry><function>has_language_privilege</function>(<parameter>user</parameter>,
                                  <parameter>language</parameter>,
                                  <parameter>access</parameter>)
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does user have access to language</entry>
      </row>
      <row>
       <entry><function>has_language_privilege</function>(<parameter>language</parameter>,
                                  <parameter>access</parameter>)
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does current user have access to language</entry>
      </row>
      <row>
       <entry><function>has_schema_privilege</function>(<parameter>user</parameter>,
                                  <parameter>schema</parameter>,
                                  <parameter>access</parameter>)
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does user have access to schema</entry>
      </row>
      <row>
       <entry><function>has_schema_privilege</function>(<parameter>schema</parameter>,
                                  <parameter>access</parameter>)
       </entry>
       <entry><type>boolean</type></entry>
       <entry>does current user have access to schema</entry>
      </row>
5640 5641 5642 5643 5644 5645 5646
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-misc">
    <primary>has_table_privilege</primary>
   </indexterm>
5647 5648 5649 5650 5651 5652 5653 5654 5655 5656 5657 5658
   <indexterm zone="functions-misc">
    <primary>has_database_privilege</primary>
   </indexterm>
   <indexterm zone="functions-misc">
    <primary>has_function_privilege</primary>
   </indexterm>
   <indexterm zone="functions-misc">
    <primary>has_language_privilege</primary>
   </indexterm>
   <indexterm zone="functions-misc">
    <primary>has_schema_privilege</primary>
   </indexterm>
5659 5660

   <para>
5661
    <function>has_table_privilege</function> checks whether a user
5662
    can access a table in a particular way.  The user can be
5663
    specified by name or by ID
5664
    (<classname>pg_user</classname>.<structfield>usesysid</structfield>), or if the argument is
5665
    omitted
5666
    <function>current_user</function> is assumed.  The table can be specified
5667
    by name or by OID.  (Thus, there are actually six variants of
5668
    <function>has_table_privilege</function>, which can be distinguished by
5669 5670 5671
    the number and types of their arguments.)  When specifying by name,
    the name can be schema-qualified if necessary.
    The desired access type
5672
    is specified by a text string, which must evaluate to one of the
5673 5674 5675
    values <literal>SELECT</literal>, <literal>INSERT</literal>, <literal>UPDATE</literal>,
    <literal>DELETE</literal>, <literal>RULE</literal>, <literal>REFERENCES</literal>, or
    <literal>TRIGGER</literal>.  (Case of the string is not significant, however.)
5676 5677 5678 5679
    An example is:
<programlisting>
SELECT has_table_privilege('myschema.mytable', 'select');
</programlisting>
5680 5681
   </para>

5682 5683 5684 5685 5686 5687 5688 5689 5690 5691 5692 5693 5694 5695 5696 5697
   <para>
    <function>has_database_privilege</function> checks whether a user
    can access a database in a particular way.  The possibilities for its
    arguments are analogous to <function>has_table_privilege</function>.
    The desired access type must evaluate to
    <literal>CREATE</literal>,
    <literal>TEMPORARY</literal>, or
    <literal>TEMP</literal> (which is equivalent to
    <literal>TEMPORARY</literal>).
   </para>

   <para>
    <function>has_function_privilege</function> checks whether a user
    can access a function in a particular way.  The possibilities for its
    arguments are analogous to <function>has_table_privilege</function>.
    When specifying a function by a text string rather than by OID,
5698
    the allowed input is the same as for the <type>regprocedure</> data type.
5699 5700 5701 5702 5703 5704 5705 5706 5707 5708 5709 5710 5711 5712 5713 5714 5715 5716 5717 5718 5719
    The desired access type must currently evaluate to
    <literal>EXECUTE</literal>.
   </para>

   <para>
    <function>has_language_privilege</function> checks whether a user
    can access a procedural language in a particular way.  The possibilities
    for its arguments are analogous to <function>has_table_privilege</function>.
    The desired access type must currently evaluate to
    <literal>USAGE</literal>.
   </para>

   <para>
    <function>has_schema_privilege</function> checks whether a user
    can access a schema in a particular way.  The possibilities for its
    arguments are analogous to <function>has_table_privilege</function>.
    The desired access type must evaluate to
    <literal>CREATE</literal> or
    <literal>USAGE</literal>.
   </para>

5720 5721 5722 5723 5724 5725 5726 5727 5728 5729 5730 5731 5732 5733 5734
  <para>
   <xref linkend="functions-misc-schema-table"> shows functions that
   determine whether a certain object is <firstterm>visible</> in the
   current schema search path.  A table is said to be visible if its
   containing schema is in the search path and no table of the same
   name appears earlier in the search path.  This is equivalent to the
   statement that the table can be referenced by name without explicit
   schema qualification.  For example, to list the names of all
   visible tables:
<programlisting>
SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
</programlisting>
  </para>

   <table id="functions-misc-schema-table">
5735 5736 5737 5738 5739 5740 5741 5742 5743 5744 5745 5746 5747 5748 5749 5750 5751 5752 5753 5754 5755 5756 5757 5758 5759 5760 5761 5762 5763 5764 5765 5766 5767 5768 5769 5770 5771 5772 5773 5774 5775 5776 5777 5778 5779 5780 5781 5782 5783 5784 5785 5786 5787 5788 5789 5790 5791 5792
    <title>Schema Visibility Inquiry Functions</title>
    <tgroup cols="3">
     <thead>
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
     </thead>

     <tbody>
      <row>
       <entry><function>pg_table_is_visible</function>(<parameter>tableOID</parameter>)
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is table visible in search path</entry>
      </row>
      <row>
       <entry><function>pg_type_is_visible</function>(<parameter>typeOID</parameter>)
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is type visible in search path</entry>
      </row>
      <row>
       <entry><function>pg_function_is_visible</function>(<parameter>functionOID</parameter>)
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is function visible in search path</entry>
      </row>
      <row>
       <entry><function>pg_operator_is_visible</function>(<parameter>operatorOID</parameter>)
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is operator visible in search path</entry>
      </row>
      <row>
       <entry><function>pg_opclass_is_visible</function>(<parameter>opclassOID</parameter>)
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is operator class visible in search path</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-misc">
    <primary>pg_table_is_visible</primary>
   </indexterm>
   <indexterm zone="functions-misc">
    <primary>pg_type_is_visible</primary>
   </indexterm>
   <indexterm zone="functions-misc">
    <primary>pg_function_is_visible</primary>
   </indexterm>
   <indexterm zone="functions-misc">
    <primary>pg_operator_is_visible</primary>
   </indexterm>
   <indexterm zone="functions-misc">
    <primary>pg_opclass_is_visible</primary>
   </indexterm>

   <para>
5793 5794 5795 5796 5797 5798 5799 5800 5801 5802 5803 5804
   <function>pg_table_is_visible</function> performs the check for
   tables (or views, or any other kind of <literal>pg_class</> entry).
   <function>pg_type_is_visible</function>,
   <function>pg_function_is_visible</function>,
   <function>pg_operator_is_visible</function>, and
   <function>pg_opclass_is_visible</function> perform the same sort of
   visibility check for types, functions, operators, and operator
   classes, respectively.  For functions and operators, an object in
   the search path is visible if there is no object of the same name
   <emphasis>and argument data type(s)</> earlier in the path.  For
   operator classes, both name and associated index access method are
   considered.
5805 5806 5807 5808 5809 5810 5811 5812 5813 5814 5815 5816 5817 5818
   </para>

   <para>
    All these functions require object OIDs to identify the object to be
    checked.  If you want to test an object by name, it is convenient to use
    the OID alias types (<type>regclass</>, <type>regtype</>,
    <type>regprocedure</>, or <type>regoperator</>), for example
<programlisting>
SELECT pg_type_is_visible('myschema.widget'::regtype);
</programlisting>
    Note that it would not make much sense to test an unqualified name in
    this way --- if the name can be recognized at all, it must be visible.
   </para>

5819 5820 5821 5822 5823 5824 5825 5826 5827 5828 5829 5830 5831 5832 5833 5834 5835 5836 5837 5838 5839 5840 5841 5842 5843 5844 5845 5846 5847 5848 5849 5850 5851 5852 5853 5854 5855
   <indexterm zone="functions-misc">
    <primary>pg_get_viewdef</primary>
   </indexterm>

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

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

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

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

  <para>
   <xref linkend="functions-misc-catalog-table"> lists functions that
   extract information from the system catalogs.
   <function>pg_get_viewdef()</function>,
   <function>pg_get_ruledef()</function>,
   <function>pg_get_indexdef()</function>, and
   <function>pg_get_constraintdef()</function> respectively
   reconstruct the creating command for a view, rule, index, or
   constraint.  (Note that this is a decompiled reconstruction, not
   the verbatim text of the command.)  At present
   <function>pg_get_constraintdef()</function> only works for
   foreign-key constraints.  <function>pg_get_userbyid()</function>
   extracts a user's name given a <structfield>usesysid</structfield>
   value.
  </para>

   <table id="functions-misc-catalog-table">
5856
    <title>Catalog Information Functions</title>
5857 5858
    <tgroup cols="3">
     <thead>
5859
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
5860 5861 5862 5863
     </thead>

     <tbody>
      <row>
5864 5865
       <entry><function>pg_get_viewdef</function>(<parameter>viewname</parameter>)</entry>
       <entry><type>text</type></entry>
5866
       <entry>Get <command>CREATE VIEW</> command for view (<emphasis>deprecated</emphasis>)</entry>
5867 5868
      </row>
      <row>
5869 5870
       <entry><function>pg_get_viewdef</function>(<parameter>viewOID</parameter>)</entry>
       <entry><type>text</type></entry>
5871
       <entry>Get <command>CREATE VIEW</> command for view</entry>
5872 5873
      </row>
      <row>
5874 5875
       <entry><function>pg_get_ruledef</function>(<parameter>ruleOID</parameter>)</entry>
       <entry><type>text</type></entry>
5876
       <entry>Get <command>CREATE RULE</> command for rule</entry>
5877 5878
      </row>
      <row>
5879 5880
       <entry><function>pg_get_indexdef</function>(<parameter>indexOID</parameter>)</entry>
       <entry><type>text</type></entry>
5881
       <entry>Get <command>CREATE INDEX</> command for index</entry>
5882
      </row>
5883 5884 5885 5886 5887
      <row>
       <entry><function>pg_get_constraintdef</function>(<parameter>constraintOID</parameter>)</entry>
       <entry><type>text</type></entry>
       <entry>Get definition of a constraint</entry>
      </row>
5888
      <row>
5889 5890
       <entry><function>pg_get_userbyid</function>(<parameter>userid</parameter>)</entry>
       <entry><type>name</type></entry>
5891
       <entry>Get user name with given ID</entry>
5892 5893 5894 5895 5896 5897
      </row>
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-misc">
5898
    <primary>obj_description</primary>
5899 5900
   </indexterm>

5901
   <indexterm zone="functions-misc">
5902
    <primary>col_description</primary>
5903 5904 5905
   </indexterm>

   <para>
5906 5907 5908 5909 5910
    The function shown in <xref
    linkend="functions-misc-comment-table"> extract comments
    previously stored with the <command>COMMENT</command> command.  A
    null value is returned if no comment can be found matching the
    specified parameters.
5911 5912
   </para>

5913
   <table id="functions-misc-comment-table">
5914
    <title>Comment Information Functions</title>
5915 5916
    <tgroup cols="3">
     <thead>
5917
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
5918 5919 5920 5921
     </thead>

     <tbody>
      <row>
5922 5923 5924
       <entry><function>obj_description</function>(<parameter>objectOID</parameter>, <parameter>tablename</parameter>)</entry>
       <entry><type>text</type></entry>
       <entry>Get comment for a database object</entry>
5925 5926
      </row>
      <row>
5927 5928 5929
       <entry><function>obj_description</function>(<parameter>objectOID</parameter>)</entry>
       <entry><type>text</type></entry>
       <entry>Get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
5930 5931
      </row>
      <row>
5932 5933 5934
       <entry><function>col_description</function>(<parameter>tableOID</parameter>, <parameter>columnnumber</parameter>)</entry>
       <entry><type>text</type></entry>
       <entry>Get comment for a table column</entry>
5935 5936 5937 5938 5939 5940
      </row>
     </tbody>
    </tgroup>
   </table>

   <para>
5941
    The two-parameter form of <function>obj_description()</function> returns the
5942 5943
    comment for a database object specified by its OID and the name of the
    containing system catalog.  For example,
5944
    <literal>obj_description(123456,'pg_class')</literal>
5945
    would retrieve the comment for a table with OID 123456.
5946
    The one-parameter form of <function>obj_description()</function> requires only
5947 5948 5949 5950 5951 5952
    the object OID.  It is now deprecated since there is no guarantee that
    OIDs are unique across different system catalogs; therefore, the wrong
    comment could be returned.
   </para>

   <para>
5953
    <function>col_description()</function> returns the comment for a table column,
5954
    which is specified by the OID of its table and its column number.
5955
    <function>obj_description()</function> cannot be used for table columns since
5956 5957 5958
    columns do not have OIDs of their own.
   </para>

5959 5960
  </sect1>

5961

5962 5963
 <sect1 id="functions-aggregate">
  <title>Aggregate Functions</title>
5964

5965 5966
  <para>
   <firstterm>Aggregate functions</firstterm> compute a single result
5967 5968 5969 5970 5971 5972
   value from a set of input values.  <xref
   linkend="functions-aggregate-table"> show the built-in aggregate
   functions.  The special syntax considerations for aggregate
   functions are explained in <xref linkend="syntax-aggregates">.
   Consult the &cite-tutorial; for additional introductory
   information.
5973
  </para>
5974

5975
  <table id="functions-aggregate-table">
5976
   <title>Aggregate Functions</title>
5977

5978
   <tgroup cols="5">
5979 5980 5981
    <thead>
     <row>
      <entry>Function</entry>
5982 5983
      <entry>Argument Type</entry>
      <entry>Return Type</entry>
5984 5985 5986 5987 5988 5989 5990
      <entry>Description</entry>
     </row>
    </thead>

    <tbody>
     <row>
      <entry>
5991 5992 5993 5994
       <indexterm>
        <primary>average</primary>
        <secondary>function</secondary>
       </indexterm>
5995 5996 5997 5998
       <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
      </entry>
      <entry>
       <type>smallint</type>, <type>integer</type>,
5999
       <type>bigint</type>, <type>real</type>, <type>double
6000 6001 6002 6003 6004 6005
       precision</type>, <type>numeric</type>, or <type>interval</type>.
      </entry>
      <entry>
       <type>numeric</type> for any integer type argument,
       <type>double precision</type> for a floating-point argument,
       otherwise the same as the argument data type
6006
      </entry>
6007
      <entry>the average (arithmetic mean) of all input values</entry>
6008 6009 6010
     </row>

     <row>
6011 6012 6013
      <entry><function>count(*)</function></entry>
      <entry></entry>
      <entry><type>bigint</type></entry>
6014 6015 6016 6017
      <entry>number of input values</entry>
     </row>

     <row>
6018 6019 6020
      <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
      <entry>any</entry>
      <entry><type>bigint</type></entry>
6021
      <entry>
6022 6023
       number of input values for which the value of <replaceable
       class="parameter">expression</replaceable> is not null
6024 6025 6026 6027
      </entry>
     </row>

     <row>
6028 6029 6030
      <entry><function>max(<replaceable class="parameter">expression</replaceable>)</function></entry>
      <entry>any numeric, string, or date/time type</entry>
      <entry>same as argument type</entry>
6031
      <entry>
6032 6033 6034
       maximum value of <replaceable
       class="parameter">expression</replaceable> across all input
       values
6035 6036 6037 6038
      </entry>
     </row>

     <row>
6039 6040 6041
      <entry><function>min(<replaceable class="parameter">expression</replaceable>)</function></entry>
      <entry>any numeric, string, or date/time type</entry>
      <entry>same as argument type</entry>
6042
      <entry>
6043 6044 6045
       minimum value of <replaceable
       class="parameter">expression</replaceable> across all input
       values
6046 6047 6048 6049 6050
      </entry>
     </row>

     <row>
      <entry>
6051 6052 6053
       <indexterm>
        <primary>standard deviation</primary>
       </indexterm>
6054 6055 6056 6057
       <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
      </entry>
      <entry>
       <type>smallint</type>, <type>integer</type>,
6058
       <type>bigint</type>, <type>real</type>, <type>double
6059 6060 6061 6062
       precision</type>, or <type>numeric</type>.
      </entry>
      <entry>
       <type>double precision</type> for floating-point arguments,
6063 6064
       otherwise <type>numeric</type>.
      </entry>
6065
      <entry>sample standard deviation of the input values</entry>
6066 6067 6068
     </row>

     <row>
6069
      <entry><function>sum(<replaceable class="parameter">expression</replaceable>)</function></entry>
6070 6071 6072
      <entry>
       <type>smallint</type>, <type>integer</type>,
       <type>bigint</type>, <type>real</type>, <type>double
6073 6074 6075 6076 6077 6078 6079 6080 6081
       precision</type>, <type>numeric</type>, or
       <type>interval</type>
      </entry>
      <entry>
       <type>bigint</type> for <type>smallint</type> or
       <type>integer</type> arguments, <type>numeric</type> for
       <type>bigint</type> arguments, <type>double precision</type>
       for floating-point arguments, otherwise the same as the
       argument data type
6082
      </entry>
6083
      <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
6084 6085 6086 6087
     </row>

     <row>
      <entry>
6088 6089 6090
       <indexterm>
        <primary>variance</primary>
       </indexterm>
6091 6092 6093 6094 6095 6096 6097 6098 6099 6100
       <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
      </entry>
      <entry>
       <type>smallint</type>, <type>integer</type>,
       <type>bigint</type>, <type>real</type>, <type>double
       precision</type>, or <type>numeric</type>.
      </entry>
      <entry>
       <type>double precision</type> for floating-point arguments,
       otherwise <type>numeric</type>.
6101
      </entry>
6102
      <entry>sample variance of the input values (square of the sample standard deviation)</entry>
6103 6104 6105 6106 6107
     </row>

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

6109
  <para>
6110
   It should be noted that except for <function>count</function>,
6111
   these functions return a null value when no rows are selected.  In
6112 6113
   particular, <function>sum</function> of no rows returns null, not
   zero as one might expect.  The function <function>coalesce</function> may be
6114
   used to substitute zero for null when necessary.
6115
  </para>
6116

6117
 </sect1>
6118

6119 6120 6121 6122 6123 6124 6125 6126 6127 6128 6129 6130 6131 6132 6133 6134 6135 6136 6137 6138 6139 6140 6141 6142 6143 6144 6145 6146 6147 6148 6149 6150 6151 6152 6153 6154 6155 6156 6157

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

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

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

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

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

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

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

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

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

6158 6159
  <sect2>
   <title>EXISTS</title>
6160 6161 6162 6163 6164 6165

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

  <para>
6166
   The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
6167
   or <firstterm>subquery</firstterm>.  The
6168
   subquery is evaluated to determine whether it returns any rows.
6169
   If it returns at least one row, the result of <token>EXISTS</token> is
6170 6171
   <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token> 
   is <quote>false</>.
6172 6173 6174 6175 6176 6177 6178 6179 6180 6181
  </para>

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

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

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

  <para>
6197 6198 6199
   This simple example is like an inner join on <literal>col2</>, but
   it produces at most one output row for each <literal>tab1</> row,
   even if there are multiple matching <literal>tab2</> rows:
6200 6201 6202 6203 6204
<screen>
SELECT col1 FROM tab1
    WHERE EXISTS(SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
</screen>
  </para>
6205
  </sect2>
6206

6207 6208
  <sect2>
   <title>IN (scalar form)</title>
6209 6210

<synopsis>
6211
<replaceable>expression</replaceable> IN (<replaceable>value</replaceable><optional>, ...</optional>)
6212 6213 6214
</synopsis>

  <para>
6215
   The right-hand side of this form of <token>IN</token> is a parenthesized list
6216
   of scalar expressions.  The result is <quote>true</> if the left-hand expression's
6217 6218 6219 6220 6221 6222 6223 6224 6225 6226 6227
   result is equal to any of the right-hand expressions.  This is a shorthand
   notation for

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

6228
   Note that if the left-hand expression yields null, or if there are
6229
   no equal right-hand values and at least one right-hand expression yields
6230
   null, the result of the <token>IN</token> construct will be null, not false.
6231
   This is in accordance with SQL's normal rules for Boolean combinations
6232
   of null values.
6233 6234 6235 6236
  </para>

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

6243 6244
  <sect2>
   <title>IN (subquery form)</title>
6245 6246 6247 6248 6249 6250

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

  <para>
6251
   The right-hand side of this form of <token>IN</token> is a parenthesized
6252 6253
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result.
6254 6255
   The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
   The result is <quote>false</> if no equal row is found (including the special
6256 6257 6258 6259
   case where the subquery returns no rows).
  </para>

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

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

<synopsis>
6273
(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) IN (<replaceable>subquery</replaceable>)
6274 6275 6276
</synopsis>

  <para>
6277
   The right-hand side of this form of <token>IN</token> is a parenthesized
6278 6279 6280
   subquery, which must return exactly as many columns as there are
   expressions in the left-hand list.  The left-hand expressions are
   evaluated and compared row-wise to each row of the subquery result.
6281 6282
   The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
   The result is <quote>false</> if no equal row is found (including the special
6283 6284 6285 6286
   case where the subquery returns no rows).
  </para>

  <para>
6287
   As usual, null values in the expressions or subquery rows are combined per
6288
   the normal rules of SQL Boolean expressions.  Two rows are considered
6289 6290
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
6291 6292 6293
   otherwise the result of that row comparison is unknown (null).
   If all the row results are either unequal or null, with at least one null,
   then the result of <token>IN</token> is null.
6294
  </para>
6295
  </sect2>
6296

6297 6298
  <sect2>
   <title>NOT IN (scalar form)</title>
6299 6300

<synopsis>
6301
<replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable><optional>, ...</optional>)
6302 6303 6304
</synopsis>

  <para>
6305
   The right-hand side of this form of <token>NOT IN</token> is a parenthesized list
6306
   of scalar expressions.  The result is <quote>true</quote> if the left-hand expression's
6307 6308 6309 6310 6311 6312 6313 6314 6315 6316 6317
   result is unequal to all of the right-hand expressions.  This is a shorthand
   notation for

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

6318
   Note that if the left-hand expression yields null, or if there are
6319
   no equal right-hand values and at least one right-hand expression yields
6320
   null, the result of the <token>NOT IN</token> construct will be null, not true
6321 6322
   as one might naively expect.
   This is in accordance with SQL's normal rules for Boolean combinations
6323
   of null values.
6324 6325 6326 6327
  </para>

  <tip>
  <para>
6328
   <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
6329
   cases.  However, null values are much more likely to trip up the novice when
6330
   working with <token>NOT IN</token> than when working with <token>IN</token>.
6331 6332 6333
   It's best to express your condition positively if possible.
  </para>
  </tip>
6334
  </sect2>
6335

6336 6337
  <sect2>
   <title>NOT IN (subquery form)</title>
6338 6339 6340 6341 6342 6343

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

  <para>
6344
   The right-hand side of this form of <token>NOT IN</token> is a parenthesized
6345 6346
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result.
6347
   The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
6348
   are found (including the special case where the subquery returns no rows).
6349
   The result is <quote>false</> if any equal row is found.
6350 6351 6352
  </para>

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

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

<synopsis>
6366
(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) NOT IN (<replaceable>subquery</replaceable>)
6367 6368 6369
</synopsis>

  <para>
6370
   The right-hand side of this form of <token>NOT IN</token> is a parenthesized
6371 6372 6373
   subquery, which must return exactly as many columns as there are
   expressions in the left-hand list.  The left-hand expressions are
   evaluated and compared row-wise to each row of the subquery result.
6374
   The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
6375
   are found (including the special case where the subquery returns no rows).
6376
   The result is <quote>false</> if any equal row is found.
6377 6378 6379
  </para>

  <para>
6380
   As usual, null values in the expressions or subquery rows are combined per
6381
   the normal rules of SQL Boolean expressions.  Two rows are considered
6382 6383
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
6384 6385 6386
   otherwise the result of that row comparison is unknown (null).
   If all the row results are either unequal or null, with at least one null,
   then the result of <token>NOT IN</token> is null.
6387
  </para>
6388
  </sect2>
6389

6390 6391
  <sect2>
   <title>ANY/SOME</title>
6392 6393

<synopsis>
6394 6395
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
<replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
6396 6397 6398
</synopsis>

  <para>
6399
   The right-hand side of this form of <token>ANY</token> is a parenthesized
6400 6401
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result using the
6402
   given <replaceable>operator</replaceable>, which must yield a Boolean
6403
   result.
6404 6405
   The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
   The result is <quote>false</> if no true result is found (including the special
6406 6407 6408 6409
   case where the subquery returns no rows).
  </para>

  <para>
6410 6411
   <token>SOME</token> is a synonym for <token>ANY</token>.
   <token>IN</token> is equivalent to <literal>= ANY</literal>.
6412 6413 6414 6415
  </para>

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

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

<synopsis>
6428 6429
(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
6430 6431 6432
</synopsis>

  <para>
6433
   The right-hand side of this form of <token>ANY</token> is a parenthesized
6434 6435 6436 6437
   subquery, which must return exactly as many columns as there are
   expressions in the left-hand list.  The left-hand expressions are
   evaluated and compared row-wise to each row of the subquery result,
   using the given <replaceable>operator</replaceable>.  Presently,
6438 6439
   only <literal>=</literal> and <literal>&lt;&gt;</literal> operators are allowed
   in row-wise <token>ANY</token> queries.
6440
   The result of <token>ANY</token> is <quote>true</> if any equal or unequal row is
6441
   found, respectively.
6442
   The result is <quote>false</> if no such row is found (including the special
6443 6444 6445 6446
   case where the subquery returns no rows).
  </para>

  <para>
6447
   As usual, null values in the expressions or subquery rows are combined per
6448
   the normal rules of SQL Boolean expressions.  Two rows are considered
6449 6450
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
6451 6452 6453
   otherwise the result of that row comparison is unknown (null).
   If there is at least one null row result, then the result of <token>ANY</token>
   cannot be false; it will be true or null. 
6454
  </para>
6455
  </sect2>
6456

6457 6458
  <sect2>
   <title>ALL</title>
6459 6460

<synopsis>
6461
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
6462 6463 6464
</synopsis>

  <para>
6465
   The right-hand side of this form of <token>ALL</token> is a parenthesized
6466 6467
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result using the
6468
   given <replaceable>operator</replaceable>, which must yield a Boolean
6469
   result.
6470
   The result of <token>ALL</token> is <quote>true</> if all rows yield true
6471
   (including the special case where the subquery returns no rows).
6472
   The result is <quote>false</> if any false result is found.
6473 6474 6475
  </para>

  <para>
6476
   <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
6477 6478 6479 6480
  </para>

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

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

6492
   <synopsis>
6493
(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
6494
   </synopsis>
6495 6496

  <para>
6497
   The right-hand side of this form of <token>ALL</token> is a parenthesized
6498 6499 6500 6501
   subquery, which must return exactly as many columns as there are
   expressions in the left-hand list.  The left-hand expressions are
   evaluated and compared row-wise to each row of the subquery result,
   using the given <replaceable>operator</replaceable>.  Presently,
6502 6503
   only <literal>=</literal> and <literal>&lt;&gt;</literal> operators are allowed
   in row-wise <token>ALL</token> queries.
6504
   The result of <token>ALL</token> is <quote>true</> if all subquery rows are equal
6505 6506
   or unequal, respectively (including the special
   case where the subquery returns no rows).
6507
   The result is <quote>false</> if any row is found to be unequal or equal,
6508 6509 6510 6511
   respectively.
  </para>

  <para>
6512
   As usual, null values in the expressions or subquery rows are combined per
6513
   the normal rules of SQL Boolean expressions.  Two rows are considered
6514 6515
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
6516 6517 6518
   otherwise the result of that row comparison is unknown (null).
   If there is at least one null row result, then the result of <token>ALL</token>
   cannot be true; it will be false or null. 
6519
  </para>
6520
  </sect2>
6521

6522 6523
  <sect2>
   <title>Row-wise Comparison</title>
6524

6525
   <synopsis>
6526 6527
(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) <replaceable>operator</replaceable> (<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>)
6528
   </synopsis>
6529 6530 6531 6532 6533 6534 6535

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

  <para>
6544
   As usual, null values in the expressions or subquery rows are combined per
6545
   the normal rules of SQL Boolean expressions.  Two rows are considered
6546 6547
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
6548
   otherwise the result of the row comparison is unknown (null).
6549
  </para>
6550
  </sect2>
6551 6552
 </sect1>

6553
</chapter>
6554

6555 6556
<!-- Keep this comment at the end of the file
Local variables:
Thomas G. Lockhart's avatar
Thomas G. Lockhart committed
6557
mode:sgml
6558
sgml-omittag:nil
6559 6560 6561 6562 6563 6564 6565 6566
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"./reference.ced"
sgml-exposed-tags:nil
Thomas G. Lockhart's avatar
Thomas G. Lockhart committed
6567
sgml-local-catalogs:("/usr/lib/sgml/catalog")
6568 6569 6570
sgml-local-ecat-files:nil
End:
-->