func.sgml 269 KB
Newer Older
1
<!--
2
$Header: /cvsroot/pgsql/doc/src/sgml/func.sgml,v 1.160 2003/07/17 00:55:36 tgl 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
   <productname>PostgreSQL</productname> provides a large number of
   functions and operators for the built-in data types.  Users can also
20 21
   define their own functions and operators, as described in
   <xref linkend="server-programming">.  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
  <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>
33
   standard. Some of the 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
    <simplelist>
72 73 74
     <member><literal>AND</></member>
     <member><literal>OR</></member>
     <member><literal>NOT</></member>
75
    </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
       <entry>Operator</entry>
340
       <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><literal>2 + 3</literal></entry>
       <entry><literal>5</literal></entry>
352
      </row>
353

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

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

470
   <para>
471 472
    The bitwise operators are also available for the bit
    string types <type>bit</type> and <type>bit varying</type>, as
473
    shown in <xref linkend="functions-math-bit-table">.
474
    Bit string operands of <literal>&amp;</literal>, <literal>|</literal>,
475
    and <literal>#</literal> must be of equal length.  When bit
476 477
    shifting, the original length of the string is preserved, as shown
    in the table.
478
   </para>
479

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

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

491 492
      <tbody>
       <row>
493 494
        <entry><literal>B'10001' &amp; B'01101'</literal></entry>
        <entry><literal>00001</literal></entry>
495 496
       </row>
       <row>
497 498
        <entry><literal>B'10001' | B'01101'</literal></entry>
        <entry><literal>11101</literal></entry>
499 500
       </row>
       <row>
501 502
        <entry><literal>B'10001' # B'01101'</literal></entry>
        <entry><literal>11110</literal></entry>
503 504
       </row>
       <row>
505 506
        <entry><literal>~ B'10001'</literal></entry>
        <entry><literal>01110</literal></entry>
507 508
       </row>
       <row>
509 510
        <entry><literal>B'10001' &lt;&lt; 3</literal></entry>
        <entry><literal>01000</literal></entry>
511 512
       </row>
       <row>
513 514
        <entry><literal>B'10001' &gt;&gt; 2</literal></entry>
        <entry><literal>00100</literal></entry>
515 516 517 518
       </row>
      </tbody>
     </tgroup>
    </table>
519

520 521 522
  <para>
   <xref linkend="functions-math-func-table"> shows the available
   mathematical functions.  In the table, <literal>dp</literal>
523 524 525 526 527 528 529
   indicates <type>double precision</type>.  Many of these functions
   are provided in multiple forms with different argument types.
   Except where noted, any given form of a function returns the same
   datatype as its argument.
   The functions working with <type>double precision</type> data are mostly
   implemented on top of the host system's C library; accuracy and behavior in
   boundary cases may therefore vary depending on the host system.
530
  </para>
531

532
   <table id="functions-math-func-table">
533 534 535 536 537 538 539 540 541 542 543 544 545 546
    <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>
547
       <entry><literal><function>abs</>(<replaceable>x</replaceable>)</literal></entry>
548
       <entry>(same as <replaceable>x</>)</entry>
549 550
       <entry>absolute value</entry>
       <entry><literal>abs(-17.4)</literal></entry>
551
       <entry><literal>17.4</literal></entry>
552 553 554
      </row>

      <row>
555
       <entry><literal><function>cbrt</function>(<type>dp</type>)</literal></entry>
556 557 558
       <entry><type>dp</type></entry>
       <entry>cube root</entry>
       <entry><literal>cbrt(27.0)</literal></entry>
559
       <entry><literal>3</literal></entry>
560 561 562
      </row>

      <row>
563
       <entry><literal><function>ceil</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
564
       <entry>(same as input)</entry>
565 566
       <entry>smallest integer not less than argument</entry>
       <entry><literal>ceil(-42.8)</literal></entry>
567
       <entry><literal>-42</literal></entry>
568 569 570
      </row>

      <row>
571
       <entry><literal><function>degrees</function>(<type>dp</type>)</literal></entry>
572 573 574
       <entry><type>dp</type></entry>
       <entry>radians to degrees</entry>
       <entry><literal>degrees(0.5)</literal></entry>
575
       <entry><literal>28.6478897565412</literal></entry>
576 577 578
      </row>

      <row>
579
       <entry><literal><function>exp</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
580
       <entry>(same as input)</entry>
581 582
       <entry>exponential</entry>
       <entry><literal>exp(1.0)</literal></entry>
583
       <entry><literal>2.71828182845905</literal></entry>
584 585 586
      </row>

      <row>
587
       <entry><literal><function>floor</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
588
       <entry>(same as input)</entry>
589 590
       <entry>largest integer not greater than argument</entry>
       <entry><literal>floor(-42.8)</literal></entry>
591
       <entry><literal>-43</literal></entry>
592 593 594
      </row>

      <row>
595
       <entry><literal><function>ln</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
596
       <entry>(same as input)</entry>
597 598
       <entry>natural logarithm</entry>
       <entry><literal>ln(2.0)</literal></entry>
599
       <entry><literal>0.693147180559945</literal></entry>
600 601 602
      </row>

      <row>
603
       <entry><literal><function>log</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
604
       <entry>(same as input)</entry>
605 606
       <entry>base 10 logarithm</entry>
       <entry><literal>log(100.0)</literal></entry>
607
       <entry><literal>2</literal></entry>
608 609 610
      </row>

      <row>
611 612
       <entry><literal><function>log</function>(<parameter>b</parameter> <type>numeric</type>,
        <parameter>x</parameter> <type>numeric</type>)</literal></entry>
613 614 615
       <entry><type>numeric</type></entry>
       <entry>logarithm to base <parameter>b</parameter></entry>
       <entry><literal>log(2.0, 64.0)</literal></entry>
616
       <entry><literal>6.0000000000</literal></entry>
617 618 619
      </row>

      <row>
620 621
       <entry><literal><function>mod</function>(<parameter>y</parameter>,
        <parameter>x</parameter>)</literal></entry>
622 623 624
       <entry>(same as argument types)</entry>
       <entry>remainder of <parameter>y</parameter>/<parameter>x</parameter></entry>
       <entry><literal>mod(9,4)</literal></entry>
625
       <entry><literal>1</literal></entry>
626 627 628
      </row>

      <row>
629
       <entry><literal><function>pi</function>()</literal></entry>
630
       <entry><type>dp</type></entry>
631
       <entry><quote>&pi;</quote> constant</entry>
632
       <entry><literal>pi()</literal></entry>
633
       <entry><literal>3.14159265358979</literal></entry>
634 635 636
      </row>

      <row>
637 638
       <entry><literal><function>pow</function>(<parameter>a</parameter> <type>dp</type>,
        <parameter>b</parameter> <type>dp</type>)</literal></entry>
639
       <entry><type>dp</type></entry>
640
       <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
641
       <entry><literal>pow(9.0, 3.0)</literal></entry>
642
       <entry><literal>729</literal></entry>
643 644
      </row>

645
      <row>
646 647
       <entry><literal><function>pow</function>(<parameter>a</parameter> <type>numeric</type>,
        <parameter>b</parameter> <type>numeric</type>)</literal></entry>
648
       <entry><type>numeric</type></entry>
649
       <entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
650
       <entry><literal>pow(9.0, 3.0)</literal></entry>
651
       <entry><literal>729</literal></entry>
652 653
      </row>

654
      <row>
655
       <entry><literal><function>radians</function>(<type>dp</type>)</literal></entry>
656 657 658
       <entry><type>dp</type></entry>
       <entry>degrees to radians</entry>
       <entry><literal>radians(45.0)</literal></entry>
659
       <entry><literal>0.785398163397448</literal></entry>
660 661 662
      </row>

      <row>
663
       <entry><literal><function>random</function>()</literal></entry>
664
       <entry><type>dp</type></entry>
665
       <entry>random value between 0.0 and 1.0</entry>
666 667 668 669 670
       <entry><literal>random()</literal></entry>
       <entry></entry>
      </row>

      <row>
671
       <entry><literal><function>round</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
672
       <entry>(same as input)</entry>
673 674
       <entry>round to nearest integer</entry>
       <entry><literal>round(42.4)</literal></entry>
675
       <entry><literal>42</literal></entry>
676 677 678
      </row>

      <row>
679
       <entry><literal><function>round</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type>)</literal></entry>
680 681 682
       <entry><type>numeric</type></entry>
       <entry>round to <parameter>s</parameter> decimal places</entry>
       <entry><literal>round(42.4382, 2)</literal></entry>
683
       <entry><literal>42.44</literal></entry>
684
      </row>
685 686

      <row>
687
       <entry><literal><function>setseed</function>(<type>dp</type>)</literal></entry>
688
       <entry><type>int32</type></entry>
689
       <entry>set seed for subsequent <literal>random()</literal> calls</entry>
690
       <entry><literal>setseed(0.54823)</literal></entry>
691
       <entry><literal>1177314959</literal></entry>
692 693
      </row>

694
      <row>
695
       <entry><literal><function>sign</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
696
       <entry>(same as input)</entry>
697 698
       <entry>sign of the argument (-1, 0, +1)</entry>
       <entry><literal>sign(-8.4)</literal></entry>
699
       <entry><literal>-1</literal></entry>
700
      </row>
701

702
      <row>
703
       <entry><literal><function>sqrt</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
704
       <entry>(same as input)</entry>
705 706
       <entry>square root</entry>
       <entry><literal>sqrt(2.0)</literal></entry>
707
       <entry><literal>1.4142135623731</literal></entry>
708
      </row>
709

710
      <row>
711
       <entry><literal><function>trunc</function>(<type>dp</type> or <type>numeric</type>)</literal></entry>
712
       <entry>(same as input)</entry>
713 714
       <entry>truncate toward zero</entry>
       <entry><literal>trunc(42.8)</literal></entry>
715
       <entry><literal>42</literal></entry>
716
      </row>
717

718
      <row>
719
       <entry><literal><function>trunc</function>(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type>)</literal></entry>
720 721 722
       <entry><type>numeric</type></entry>
       <entry>truncate to <parameter>s</parameter> decimal places</entry>
       <entry><literal>trunc(42.4382, 2)</literal></entry>
723
       <entry><literal>42.43</literal></entry>
724
      </row>
725

726 727 728
     </tbody>
    </tgroup>
   </table>
729

730 731 732
  <para>
   Finally, <xref linkend="functions-math-trig-table"> shows the
   available trigonometric functions.  All trigonometric functions
733
   take arguments and return values of type <type>double
734 735
   precision</type>.
  </para>
736

737
   <table id="functions-math-trig-table">
738
    <title>Trigonometric Functions</title>
739

740 741 742 743 744 745 746
    <tgroup cols="2">
     <thead>
      <row>
       <entry>Function</entry>
       <entry>Description</entry>
      </row>
     </thead>
747

748 749
     <tbody>
      <row>
750
       <entry><literal><function>acos</function>(<replaceable>x</replaceable>)</literal></entry>
751 752
       <entry>inverse cosine</entry>
      </row>
753

754
      <row>
755
       <entry><literal><function>asin</function>(<replaceable>x</replaceable>)</literal></entry>
756 757
       <entry>inverse sine</entry>
      </row>
758

759
      <row>
760
       <entry><literal><function>atan</function>(<replaceable>x</replaceable>)</literal></entry>
761 762
       <entry>inverse tangent</entry>
      </row>
763

764
      <row>
765 766
       <entry><literal><function>atan2</function>(<replaceable>x</replaceable>,
        <replaceable>y</replaceable>)</literal></entry>
767
       <entry>inverse tangent of
768
        <literal><replaceable>x</replaceable>/<replaceable>y</replaceable></literal></entry>
769
      </row>
770

771
      <row>
772
       <entry><literal><function>cos</function>(<replaceable>x</replaceable>)</literal></entry>
773 774
       <entry>cosine</entry>
      </row>
775

776
      <row>
777
       <entry><literal><function>cot</function>(<replaceable>x</replaceable>)</literal></entry>
778 779
       <entry>cotangent</entry>
      </row>
780

781
      <row>
782
       <entry><literal><function>sin</function>(<replaceable>x</replaceable>)</literal></entry>
783 784
       <entry>sine</entry>
      </row>
785

786
      <row>
787
       <entry><literal><function>tan</function>(<replaceable>x</replaceable>)</literal></entry>
788 789 790 791 792
       <entry>tangent</entry>
      </row>
     </tbody>
    </tgroup>
   </table>
793

794
  </sect1>
795 796


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

800 801 802
   <para>
    This section describes functions and operators for examining and
    manipulating string values.  Strings in this context include values
803 804
    of all the types <type>character</type>, <type>character
     varying</type>, and <type>text</type>.  Unless otherwise noted, all
805 806
    of the functions listed below work on all of these types, but be
    wary of potential effects of the automatic padding when using the
807
    <type>character</type> type.  Generally, the functions described
808 809
    here also work on data of non-string types by converting that data
    to a string representation first.  Some functions also exist
810
    natively for the bit-string types.
811
   </para>
812

813 814
   <para>
    <acronym>SQL</acronym> defines some string functions with a special syntax where
815
    certain key words rather than commas are used to separate the
816 817 818 819
    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>
820

821 822 823 824 825 826 827 828 829 830 831 832
   <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>
833

834 835
     <tbody>
      <row>
836 837
       <entry><literal><parameter>string</parameter> <literal>||</literal>
        <parameter>string</parameter></literal></entry>
838 839
       <entry> <type>text</type> </entry>
       <entry>
840
        String concatenation
841 842 843 844 845
        <indexterm>
         <primary>character strings</primary>
         <secondary>concatenation</secondary>
        </indexterm>
       </entry>
846
       <entry><literal>'Post' || 'greSQL'</literal></entry>
847 848
       <entry><literal>PostgreSQL</literal></entry>
      </row>
849

850
      <row>
851
       <entry><literal><function>bit_length</function>(<parameter>string</parameter>)</literal></entry>
852
       <entry><type>integer</type></entry>
853
       <entry>Number of bits in string</entry>
854 855 856
       <entry><literal>bit_length('jose')</literal></entry>
       <entry><literal>32</literal></entry>
      </row>
Peter Eisentraut's avatar
Peter Eisentraut committed
857

858
      <row>
859
       <entry><literal><function>char_length</function>(<parameter>string</parameter>)</literal> or <literal><function>character_length</function>(<parameter>string</parameter>)</literal></entry>
860 861
       <entry><type>integer</type></entry>
       <entry>
862
        Number of characters in string
863 864 865 866 867 868 869 870 871 872 873 874 875
        <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>
876

Tatsuo Ishii's avatar
Tatsuo Ishii committed
877
      <row>
878 879
       <entry><literal><function>convert</function>(<parameter>string</parameter>
       using <parameter>conversion_name</parameter>)</literal></entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
880
       <entry><type>text</type></entry>
881 882 883 884 885 886 887 888
       <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>
889
       <entry><literal>'PostgreSQL'</literal> in Unicode (UTF-8) encoding</entry>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
890 891
      </row>

892
      <row>
893
       <entry><literal><function>lower</function>(<parameter>string</parameter>)</literal></entry>
894
       <entry><type>text</type></entry>
895
       <entry>Convert string to lower case</entry>
896 897 898
       <entry><literal>lower('TOM')</literal></entry>
       <entry><literal>tom</literal></entry>
      </row>
899

900
      <row>
901
       <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
902
       <entry><type>integer</type></entry>
903
       <entry>Number of bytes in string</entry>
904 905 906
       <entry><literal>octet_length('jose')</literal></entry>
       <entry><literal>4</literal></entry>
      </row>
907

908
      <row>
909
       <entry><literal><function>overlay</function>(<parameter>string</parameter> placing <parameter>string</parameter> from <type>integer</type> <optional>for <type>integer</type></optional>)</literal></entry>
910 911
       <entry><type>text</type></entry>
       <entry>
912
        Replace substring
913 914 915 916 917 918 919
        <indexterm>
         <primary>overlay</primary>
        </indexterm>
       </entry>
       <entry><literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal></entry>
       <entry><literal>Thomas</literal></entry>
      </row>
920

921
      <row>
922
       <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
923
       <entry><type>integer</type></entry>
924
       <entry>Location of specified substring</entry>
925 926 927
       <entry><literal>position('om' in 'Thomas')</literal></entry>
       <entry><literal>3</literal></entry>
      </row>
928

929
      <row>
930
       <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>integer</type></optional> <optional>for <type>integer</type></optional>)</literal></entry>
931 932
       <entry><type>text</type></entry>
       <entry>
933
        Extract substring
934 935 936 937 938 939 940
        <indexterm>
         <primary>substring</primary>
        </indexterm>
       </entry>
       <entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
       <entry><literal>hom</literal></entry>
      </row>
941

942
      <row>
943
       <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</literal></entry>
944 945
       <entry><type>text</type></entry>
       <entry>
946
        Extract substring matching POSIX regular expression
947 948 949 950
        <indexterm>
         <primary>substring</primary>
        </indexterm>
       </entry>
951
       <entry><literal>substring('Thomas' from '...$')</literal></entry>
952 953
       <entry><literal>mas</literal></entry>
      </row>
954

955
      <row>
956
       <entry><literal><function>substring</function>(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</literal></entry>
957 958
       <entry><type>text</type></entry>
       <entry>
959 960
        Extract substring matching <acronym>SQL</acronym> regular
        expression
961 962 963 964 965 966 967 968
        <indexterm>
         <primary>substring</primary>
        </indexterm>
       </entry>
       <entry><literal>substring('Thomas' from '%#"o_a#"_' for '#')</literal></entry>
       <entry><literal>oma</literal></entry>
      </row>

969 970
      <row>
       <entry>
971
        <literal><function>trim</function>(<optional>leading | trailing | both</optional>
972
        <optional><parameter>characters</parameter></optional> from
973
        <parameter>string</parameter>)</literal>
974 975 976
       </entry>
       <entry><type>text</type></entry>
       <entry>
977
        Remove the longest string containing only the
978
        <parameter>characters</parameter> (a space by default) from the
979
        start/end/both ends of the <parameter>string</parameter>.
980 981 982 983
       </entry>
       <entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
       <entry><literal>Tom</literal></entry>
      </row>
984

985
      <row>
986
       <entry><literal><function>upper</function>(<parameter>string</parameter>)</literal></entry>
987
       <entry><type>text</type></entry>
988
       <entry>Convert string to upper case</entry>
989 990 991 992 993 994
       <entry><literal>upper('tom')</literal></entry>
       <entry><literal>TOM</literal></entry>
      </row>
     </tbody>
    </tgroup>
   </table>
995

996 997
   <para>
    Additional string manipulation functions are available and are
998 999
    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">.
1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016
   </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>
1017
       <entry><literal><function>ascii</function>(<type>text</type>)</literal></entry>
1018
       <entry>integer</entry>
1019
       <entry><acronym>ASCII</acronym> code of the first character of the argument</entry>
1020 1021 1022 1023 1024
       <entry><literal>ascii('x')</literal></entry>
       <entry><literal>120</literal></entry>
      </row>

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

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

      <row>
       <entry>
1046
        <literal><function>convert</function>(<parameter>string</parameter>
1047 1048
        <type>text</type>,
        <optional><parameter>src_encoding</parameter> <type>name</type>,</optional>
1049
        <parameter>dest_encoding</parameter> <type>name</type>)</literal>
1050 1051 1052
       </entry>
       <entry><type>text</type></entry>
       <entry>
1053
        Convert string to <parameter>dest_encoding</parameter>.
1054 1055 1056 1057 1058 1059
        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>
1060
       <entry><literal>text_in_unicode</literal> represented in ISO 8859-1 encoding</entry>
1061 1062 1063 1064
      </row>

      <row>
       <entry>
1065 1066
        <literal><function>decode</function>(<parameter>string</parameter> <type>text</type>,
        <parameter>type</parameter> <type>text</type>)</literal>
1067 1068 1069
       </entry>
       <entry><type>bytea</type></entry>
       <entry>
1070
        Decode binary data from <parameter>string</parameter> previously 
1071
        encoded with <function>encode</>.  Parameter type is same as in <function>encode</>.
1072 1073 1074 1075 1076 1077 1078
       </entry>
       <entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
       <entry><literal>123\000\001</literal></entry>
      </row>       

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

      <row>
1092
       <entry><literal><function>initcap</function>(<type>text</type>)</literal></entry>
1093
       <entry><type>text</type></entry>
1094
       <entry>Convert first letter of each word (whitespace-separated) to upper case</entry>
1095 1096 1097 1098 1099
       <entry><literal>initcap('hi thomas')</literal></entry>
       <entry><literal>Hi Thomas</literal></entry>
      </row>

      <row>
1100
       <entry><literal><function>length</function>(<parameter>string</parameter>)</literal></entry>
1101 1102
       <entry><type>integer</type></entry>
       <entry>
1103
        Number of characters in string
1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 1118 1119
        <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>
1120
        <literal><function>lpad</function>(<parameter>string</parameter> <type>text</type>,
1121
        <parameter>length</parameter> <type>integer</type>
1122
        <optional>, <parameter>fill</parameter> <type>text</type></optional>)</literal>
1123 1124 1125
       </entry>
       <entry>text</entry>
       <entry>
1126
        Fill up the <parameter>string</parameter> to length
1127 1128 1129 1130 1131 1132 1133 1134 1135 1136 1137
        <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>
1138
       <entry><literal><function>ltrim</function>(<parameter>string</parameter> <type>text</type>, <parameter>characters</parameter> <type>text</type>)</literal></entry>
1139 1140
       <entry><type>text</type></entry>
       <entry>
1141
        Remove the longest string containing only characters from
1142
        <parameter>characters</parameter> from the start of the string.
1143 1144 1145 1146 1147
       </entry>
       <entry><literal>ltrim('zzzytrim','xyz')</literal></entry>
       <entry><literal>trim</literal></entry>
      </row>

1148
      <row>
1149
       <entry><literal><function>md5</function>(<parameter>string</parameter> <type>text</type>)</literal></entry>
1150 1151
       <entry><type>text</type></entry>
       <entry>
1152
        Calculates the MD5 hash of given string, returning the result in hexadecimal.
1153 1154 1155 1156 1157
       </entry>
       <entry><literal>md5('abc')</literal></entry>
       <entry><literal>900150983cd24fb0d6963f7d28e17f72</literal></entry>
      </row>

1158
      <row>
1159
       <entry><literal><function>pg_client_encoding</function>()</literal></entry>
1160 1161
       <entry><type>name</type></entry>
       <entry>
1162
        Current client encoding name
1163 1164 1165 1166 1167 1168
       </entry>
       <entry><literal>pg_client_encoding()</literal></entry>
       <entry><literal>SQL_ASCII</literal></entry>
      </row>

      <row>
1169
       <entry><literal><function>quote_ident</function>(<parameter>string</parameter> text)</literal></entry>
1170 1171
       <entry><type>text</type></entry>
       <entry>
1172
        Return the given string suitably quoted to be used as an identifier
1173
	in an <acronym>SQL</acronym> statement string.
1174 1175 1176 1177 1178 1179 1180 1181 1182
	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>
1183
       <entry><literal><function>quote_literal</function>(<parameter>string</parameter> text)</literal></entry>
1184 1185
       <entry><type>text</type></entry>
       <entry>
1186 1187
        Return the given string suitably quoted to be used as a string literal
	in an <acronym>SQL</acronym> statement string.
1188 1189 1190 1191 1192 1193 1194
	Embedded quotes and backslashes are properly doubled.
       </entry>
       <entry><literal>quote_literal('O\'Reilly')</literal></entry>
       <entry><literal>'O''Reilly'</literal></entry>
      </row>

      <row>
1195
       <entry><literal><function>repeat</function>(<type>text</type>, <type>integer</type>)</literal></entry>
1196
       <entry><type>text</type></entry>
1197
       <entry>Repeat text a number of times</entry>
1198 1199 1200 1201 1202
       <entry><literal>repeat('Pg', 4)</literal></entry>
       <entry><literal>PgPgPgPg</literal></entry>
      </row>

      <row>
1203
       <entry><literal><function>replace</function>(<parameter>string</parameter> <type>text</type>,
1204
       <parameter>from</parameter> <type>text</type>,
1205
       <parameter>to</parameter> <type>text</type>)</literal></entry>
1206 1207
       <entry><type>text</type></entry>
       <entry>Replace all occurrences in <parameter>string</parameter> of substring
1208
        <parameter>from</parameter> with substring <parameter>to</parameter>.
1209 1210 1211 1212 1213 1214 1215
       </entry>
       <entry><literal>replace('abcdefabcdef', 'cd', 'XX')</literal></entry>
       <entry><literal>abXXefabXXef</literal></entry>
      </row>

      <row>
       <entry>
1216
        <literal><function>rpad</function>(<parameter>string</parameter> <type>text</type>,
1217
        <parameter>length</parameter> <type>integer</type>
1218
        <optional>, <parameter>fill</parameter> <type>text</type></optional>)</literal>
1219 1220 1221
       </entry>
       <entry><type>text</type></entry>
       <entry>
1222
        Fill up the <parameter>string</parameter> to length
1223 1224 1225 1226 1227 1228 1229 1230 1231 1232
        <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>
1233 1234
       <entry><literal><function>rtrim</function>(<parameter>string</parameter>
        text, <parameter>characters</parameter> text)</literal></entry>
1235 1236
       <entry><type>text</type></entry>
       <entry>
1237
        Remove the longest string containing only characters from
1238
        <parameter>characters</parameter> from the end of the string.
1239 1240 1241 1242 1243 1244
       </entry>
       <entry><literal>rtrim('trimxxxx','x')</literal></entry>
       <entry><literal>trim</literal></entry>
      </row>

      <row>
1245
       <entry><literal><function>split_part</function>(<parameter>string</parameter> <type>text</type>,
1246
       <parameter>delimiter</parameter> <type>text</type>,
1247
       <parameter>field</parameter> <type>integer</type>)</literal></entry>
1248 1249
       <entry><type>text</type></entry>
       <entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
1250
        and return the given field (counting from one)
1251 1252 1253 1254 1255 1256
       </entry>
       <entry><literal>split_part('abc~@~def~@~ghi','~@~',2)</literal></entry>
       <entry><literal>def</literal></entry>
      </row>

      <row>
1257
       <entry><literal><function>strpos</function>(<parameter>string</parameter>, <parameter>substring</parameter>)</literal></entry>
1258 1259
       <entry><type>text</type></entry>
       <entry>
1260
        Location of specified substring (same as
1261 1262 1263 1264 1265 1266 1267 1268 1269
        <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>
1270
       <entry><literal><function>substr</function>(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</literal></entry>
1271 1272
       <entry><type>text</type></entry>
       <entry>
1273
        Extract substring (same as
1274 1275 1276 1277 1278 1279 1280
        <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>
1281 1282
       <entry><literal><function>to_ascii</function>(<type>text</type>
        <optional>, <parameter>encoding</parameter></optional>)</literal></entry>
1283
       <entry><type>text</type></entry>
1284 1285 1286 1287 1288 1289 1290 1291 1292 1293 1294

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

1295 1296 1297 1298 1299
       <entry><literal>to_ascii('Karel')</literal></entry>
       <entry><literal>Karel</literal></entry>
      </row>

      <row>
1300 1301
       <entry><literal><function>to_hex</function>(<parameter>number</parameter> <type>integer</type>
       or <type>bigint</type>)</literal></entry>
1302 1303
       <entry><type>text</type></entry>
       <entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
1304
        representation
1305
       </entry>
1306
       <entry><literal>to_hex(9223372036854775807)</literal></entry>
1307 1308 1309 1310 1311
       <entry><literal>7fffffffffffffff</literal></entry>
      </row>

      <row>
       <entry>
1312
        <literal><function>translate</function>(<parameter>string</parameter>
1313 1314
        <type>text</type>,
        <parameter>from</parameter> <type>text</type>,
1315
        <parameter>to</parameter> <type>text</type>)</literal>
1316 1317 1318 1319 1320 1321 1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332
       </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
1333
   <table id="conversion-names">
1334
    <title>Built-in Conversions</title>
Tatsuo Ishii's avatar
Tatsuo Ishii committed
1335 1336 1337
    <tgroup cols="3">
     <thead>
      <row>
1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 1348 1349 1350 1351
       <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
1352 1353
      </row>
     </thead>
1354

Tatsuo Ishii's avatar
Tatsuo Ishii committed
1355 1356
     <tbody>
      <row>
1357 1358 1359
       <entry><literal>ascii_to_mic</literal></entry>
       <entry><literal>SQL_ASCII</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1360 1361 1362
      </row>

      <row>
1363 1364 1365
       <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
1366 1367 1368
      </row>

      <row>
1369 1370 1371
       <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
1372 1373 1374
      </row>

      <row>
1375 1376 1377
       <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
1378 1379 1380
      </row>

      <row>
1381 1382 1383
       <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
1384 1385 1386
      </row>

      <row>
1387 1388 1389
       <entry><literal>euc_cn_to_mic</literal></entry>
       <entry><literal>EUC_CN</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1390 1391 1392
      </row>

      <row>
1393 1394 1395
       <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
1396 1397 1398
      </row>

      <row>
1399 1400 1401
       <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
1402 1403 1404
      </row>

      <row>
1405 1406 1407
       <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
1408 1409 1410
      </row>

      <row>
1411 1412 1413
       <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
1414 1415 1416
      </row>

      <row>
1417 1418 1419
       <entry><literal>euc_kr_to_mic</literal></entry>
       <entry><literal>EUC_KR</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1420 1421 1422
      </row>

      <row>
1423 1424 1425
       <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
1426 1427 1428
      </row>

      <row>
1429 1430 1431
       <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
1432 1433 1434
      </row>

      <row>
1435 1436 1437
       <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
1438 1439 1440
      </row>

      <row>
1441 1442 1443
       <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
1444 1445 1446
      </row>

      <row>
1447 1448 1449
       <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
1450 1451 1452
      </row>

      <row>
1453 1454 1455
       <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
1456 1457 1458
      </row>

      <row>
1459 1460 1461
       <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
1462 1463 1464
      </row>

      <row>
1465 1466 1467
       <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
1468 1469 1470
      </row>

      <row>
1471 1472 1473
       <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
1474 1475 1476
      </row>

      <row>
1477 1478 1479
       <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
1480 1481 1482
      </row>

      <row>
1483 1484 1485
       <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
1486 1487 1488
      </row>

      <row>
1489 1490 1491
       <entry><literal>iso_8859_1_to_mic</literal></entry>
       <entry><literal>LATIN1</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1492 1493 1494
      </row>

      <row>
1495 1496 1497
       <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
1498 1499 1500
      </row>

      <row>
1501 1502 1503
       <entry><literal>iso_8859_2_to_mic</literal></entry>
       <entry><literal>LATIN2</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1504 1505 1506
      </row>

      <row>
1507 1508 1509
       <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
1510 1511 1512
      </row>

      <row>
1513
       <entry><literal>iso_8859_2_to_windows_1250</literal></entry>
1514 1515
       <entry><literal>LATIN2</literal></entry>
       <entry><literal>WIN1250</literal></entry>
1516 1517 1518
      </row>

      <row>
1519 1520 1521
       <entry><literal>iso_8859_3_to_mic</literal></entry>
       <entry><literal>LATIN3</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1522 1523 1524
      </row>

      <row>
1525 1526 1527
       <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
1528 1529 1530
      </row>

      <row>
1531 1532 1533
       <entry><literal>iso_8859_4_to_mic</literal></entry>
       <entry><literal>LATIN4</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1534 1535 1536
      </row>

      <row>
1537 1538 1539
       <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
1540 1541 1542
      </row>

      <row>
1543
       <entry><literal>iso_8859_5_to_koi8_r</literal></entry>
1544 1545
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>KOI8</literal></entry>
1546 1547 1548
      </row>

      <row>
1549 1550 1551
       <entry><literal>iso_8859_5_to_mic</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1552 1553 1554
      </row>

      <row>
1555 1556 1557
       <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
1558 1559 1560
      </row>

      <row>
1561
       <entry><literal>iso_8859_5_to_windows_1251</literal></entry>
1562 1563
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>WIN</literal></entry>
1564 1565 1566
      </row>

      <row>
1567
       <entry><literal>iso_8859_5_to_windows_866</literal></entry>
1568 1569
       <entry><literal>ISO_8859_5</literal></entry>
       <entry><literal>ALT</literal></entry>
1570 1571 1572
      </row>

      <row>
1573 1574 1575
       <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
1576 1577 1578
      </row>

      <row>
1579 1580 1581
       <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
1582 1583 1584
      </row>

      <row>
1585 1586 1587
       <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
1588 1589 1590
      </row>

      <row>
1591 1592 1593
       <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
1594 1595 1596
      </row>

      <row>
1597 1598 1599
       <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
1600 1601
      </row>

1602
      <row>
1603
       <entry><literal>koi8_r_to_iso_8859_5</literal></entry>
1604 1605
       <entry><literal>KOI8</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
1606 1607 1608
      </row>

      <row>
1609
       <entry><literal>koi8_r_to_mic</literal></entry>
1610 1611
       <entry><literal>KOI8</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1612 1613 1614
      </row>

      <row>
1615
       <entry><literal>koi8_r_to_utf_8</literal></entry>
1616 1617
       <entry><literal>KOI8</literal></entry>
       <entry><literal>UNICODE</literal></entry>
1618 1619 1620
      </row>

      <row>
1621
       <entry><literal>koi8_r_to_windows_1251</literal></entry>
1622 1623
       <entry><literal>KOI8</literal></entry>
       <entry><literal>WIN</literal></entry>
1624 1625 1626
      </row>

      <row>
1627
       <entry><literal>koi8_r_to_windows_866</literal></entry>
1628 1629
       <entry><literal>KOI8</literal></entry>
       <entry><literal>ALT</literal></entry>
1630 1631 1632
      </row>

      <row>
1633 1634 1635
       <entry><literal>mic_to_ascii</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>SQL_ASCII</literal></entry>
1636 1637
      </row>

Tatsuo Ishii's avatar
Tatsuo Ishii committed
1638
      <row>
1639 1640 1641
       <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
1642 1643
      </row>

1644
      <row>
1645 1646 1647
       <entry><literal>mic_to_euc_cn</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>EUC_CN</literal></entry>
1648 1649
      </row>

Tatsuo Ishii's avatar
Tatsuo Ishii committed
1650
      <row>
1651 1652 1653
       <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
1654 1655
      </row>

1656
      <row>
1657 1658 1659
       <entry><literal>mic_to_euc_kr</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>EUC_KR</literal></entry>
1660 1661
      </row>

Tatsuo Ishii's avatar
Tatsuo Ishii committed
1662
      <row>
1663 1664 1665
       <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
1666 1667
      </row>

1668
      <row>
1669 1670 1671
       <entry><literal>mic_to_iso_8859_1</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>LATIN1</literal></entry>
1672 1673 1674
      </row>

      <row>
1675 1676 1677
       <entry><literal>mic_to_iso_8859_2</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>LATIN2</literal></entry>
1678 1679 1680
      </row>

      <row>
1681 1682 1683
       <entry><literal>mic_to_iso_8859_3</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>LATIN3</literal></entry>
1684 1685 1686
      </row>

      <row>
1687 1688 1689
       <entry><literal>mic_to_iso_8859_4</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>LATIN4</literal></entry>
1690 1691 1692
      </row>

      <row>
1693 1694 1695
       <entry><literal>mic_to_iso_8859_5</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
1696 1697 1698
      </row>

      <row>
1699
       <entry><literal>mic_to_koi8_r</literal></entry>
1700 1701
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>KOI8</literal></entry>
1702 1703
      </row>

Tatsuo Ishii's avatar
Tatsuo Ishii committed
1704
      <row>
1705 1706 1707
       <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
1708 1709
      </row>

1710
      <row>
1711
       <entry><literal>mic_to_windows_1250</literal></entry>
1712 1713
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>WIN1250</literal></entry>
1714 1715 1716
      </row>

      <row>
1717
       <entry><literal>mic_to_windows_1251</literal></entry>
1718 1719
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>WIN</literal></entry>
1720 1721 1722
      </row>

      <row>
1723
       <entry><literal>mic_to_windows_866</literal></entry>
1724 1725
       <entry><literal>MULE_INTERNAL</literal></entry>
       <entry><literal>ALT</literal></entry>
1726 1727
      </row>

Tatsuo Ishii's avatar
Tatsuo Ishii committed
1728
      <row>
1729 1730 1731
       <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
1732 1733 1734
      </row>

      <row>
1735 1736 1737
       <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
1738 1739 1740
      </row>

      <row>
1741 1742 1743
       <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
1744 1745 1746
      </row>

      <row>
1747 1748 1749
       <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
1750 1751 1752
      </row>

      <row>
1753 1754 1755
       <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
1756 1757 1758
      </row>

      <row>
1759 1760 1761
       <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
1762 1763 1764
      </row>

      <row>
1765 1766 1767
       <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
1768 1769 1770
      </row>

      <row>
1771 1772 1773
       <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
1774 1775 1776
      </row>

      <row>
1777 1778 1779
       <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
1780 1781 1782
      </row>

      <row>
1783 1784 1785
       <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
1786 1787 1788
      </row>

      <row>
1789 1790 1791
       <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
1792 1793 1794
      </row>

      <row>
1795 1796 1797
       <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
1798 1799 1800
      </row>

      <row>
1801 1802 1803
       <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
1804 1805 1806
      </row>

      <row>
1807 1808 1809
       <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
1810 1811 1812
      </row>

      <row>
1813 1814 1815
       <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
1816 1817 1818
      </row>

      <row>
1819 1820 1821
       <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
1822 1823 1824
      </row>

      <row>
1825 1826 1827
       <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
1828 1829 1830
      </row>

      <row>
1831 1832 1833
       <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
1834 1835 1836
      </row>

      <row>
1837 1838 1839
       <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
1840 1841 1842
      </row>

      <row>
1843 1844 1845
       <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
1846 1847 1848
      </row>

      <row>
1849 1850 1851
       <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
1852 1853 1854
      </row>

      <row>
1855 1856 1857
       <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
1858 1859 1860
      </row>

      <row>
1861 1862 1863
       <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
1864 1865 1866
      </row>

      <row>
1867 1868 1869
       <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
1870 1871 1872
      </row>

      <row>
1873 1874 1875
       <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
1876 1877 1878
      </row>

      <row>
1879 1880 1881
       <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
1882 1883 1884
      </row>

      <row>
1885 1886 1887
       <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
1888 1889 1890
      </row>

      <row>
1891 1892 1893
       <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
1894 1895 1896
      </row>

      <row>
1897
       <entry><literal>utf_8_to_koi8_r</literal></entry>
1898 1899
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>KOI8</literal></entry>
1900 1901 1902
      </row>

      <row>
1903 1904 1905
       <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
1906 1907 1908
      </row>

      <row>
1909 1910 1911
       <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
1912 1913 1914
      </row>

      <row>
1915 1916 1917
       <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
1918 1919
      </row>

1920
      <row>
1921
       <entry><literal>utf_8_to_windows_1250</literal></entry>
1922 1923
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>WIN1250</literal></entry>
1924 1925 1926
      </row>

      <row>
1927
       <entry><literal>utf_8_to_windows_1251</literal></entry>
1928 1929
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>WIN</literal></entry>
1930 1931 1932
      </row>

      <row>
1933
       <entry><literal>utf_8_to_windows_1256</literal></entry>
1934 1935
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>WIN1256</literal></entry>
1936 1937 1938
      </row>

      <row>
1939
       <entry><literal>utf_8_to_windows_866</literal></entry>
1940 1941
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>ALT</literal></entry>
1942 1943 1944
      </row>

      <row>
1945
       <entry><literal>utf_8_to_windows_874</literal></entry>
1946 1947
       <entry><literal>UNICODE</literal></entry>
       <entry><literal>WIN874</literal></entry>
1948
      </row>
1949

1950
      <row>
1951
       <entry><literal>windows_1250_to_iso_8859_2</literal></entry>
1952 1953
       <entry><literal>WIN1250</literal></entry>
       <entry><literal>LATIN2</literal></entry>
1954
      </row>
1955

1956
      <row>
1957
       <entry><literal>windows_1250_to_mic</literal></entry>
1958 1959
       <entry><literal>WIN1250</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1960 1961 1962
      </row>

      <row>
1963
       <entry><literal>windows_1250_to_utf_8</literal></entry>
1964 1965
       <entry><literal>WIN1250</literal></entry>
       <entry><literal>UNICODE</literal></entry>
1966 1967
      </row>

1968
      <row>
1969
       <entry><literal>windows_1251_to_iso_8859_5</literal></entry>
1970 1971
       <entry><literal>WIN</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
1972
      </row>
1973

1974
      <row>
1975
       <entry><literal>windows_1251_to_koi8_r</literal></entry>
1976 1977
       <entry><literal>WIN</literal></entry>
       <entry><literal>KOI8</literal></entry>
1978 1979
      </row>

1980
      <row>
1981
       <entry><literal>windows_1251_to_mic</literal></entry>
1982 1983
       <entry><literal>WIN</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
1984
      </row>
1985

1986
      <row>
1987
       <entry><literal>windows_1251_to_utf_8</literal></entry>
1988 1989
       <entry><literal>WIN</literal></entry>
       <entry><literal>UNICODE</literal></entry>
1990
      </row>
1991

1992
      <row>
1993
       <entry><literal>windows_1251_to_windows_866</literal></entry>
1994 1995
       <entry><literal>WIN</literal></entry>
       <entry><literal>ALT</literal></entry>
1996 1997
      </row>

1998
      <row>
1999
       <entry><literal>windows_1256_to_utf_8</literal></entry>
2000 2001
       <entry><literal>WIN1256</literal></entry>
       <entry><literal>UNICODE</literal></entry>
2002
      </row>
2003

2004
      <row>
2005
       <entry><literal>windows_866_to_iso_8859_5</literal></entry>
2006 2007
       <entry><literal>ALT</literal></entry>
       <entry><literal>ISO_8859_5</literal></entry>
2008
      </row>
2009

2010
      <row>
2011
       <entry><literal>windows_866_to_koi8_r</literal></entry>
2012 2013
       <entry><literal>ALT</literal></entry>
       <entry><literal>KOI8</literal></entry>
2014
      </row>
2015

2016
      <row>
2017
       <entry><literal>windows_866_to_mic</literal></entry>
2018 2019
       <entry><literal>ALT</literal></entry>
       <entry><literal>MULE_INTERNAL</literal></entry>
2020 2021
      </row>

2022
      <row>
2023
       <entry><literal>windows_866_to_utf_8</literal></entry>
2024 2025 2026 2027 2028
       <entry><literal>ALT</literal></entry>
       <entry><literal>UNICODE</literal></entry>
      </row>

      <row>
2029
       <entry><literal>windows_866_to_windows_1251</literal></entry>
2030 2031 2032 2033 2034
       <entry><literal>ALT</literal></entry>
       <entry><literal>WIN</literal></entry>
      </row>

      <row>
2035
       <entry><literal>windows_874_to_utf_8</literal></entry>
2036 2037 2038 2039
       <entry><literal>WIN874</literal></entry>
       <entry><literal>UNICODE</literal></entry>
      </row>

2040 2041 2042
     </tbody>
    </tgroup>
   </table>
2043

2044
  </sect1>
2045

2046

2047 2048
  <sect1 id="functions-binarystring">
   <title>Binary String Functions and Operators</title>
2049

2050 2051
   <para>
    This section describes functions and operators for examining and
2052
    manipulating values of type <type>bytea</type>.
2053
   </para>
2054

2055 2056 2057
   <para>
    <acronym>SQL</acronym> defines some string functions with a
    special syntax where 
2058
    certain key words rather than commas are used to separate the
2059 2060 2061 2062 2063 2064
    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>
2065

2066 2067 2068 2069 2070 2071 2072 2073 2074 2075 2076 2077
   <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>
2078

2079 2080
     <tbody>
      <row>
2081 2082
       <entry><literal><parameter>string</parameter> <literal>||</literal>
        <parameter>string</parameter></literal></entry>
2083 2084
       <entry> <type>bytea</type> </entry>
       <entry>
2085
        String concatenation
2086 2087 2088 2089 2090
        <indexterm>
         <primary>binary strings</primary>
         <secondary>concatenation</secondary>
        </indexterm>
       </entry>
2091 2092
       <entry><literal>'\\\\Post'::bytea || '\\047greSQL\\000'::bytea</literal></entry>
       <entry><literal>\\Post'greSQL\000</literal></entry>
2093
      </row>
2094

2095
      <row>
2096
       <entry><literal><function>octet_length</function>(<parameter>string</parameter>)</literal></entry>
2097
       <entry><type>integer</type></entry>
2098
       <entry>Number of bytes in binary string</entry>
2099 2100 2101
       <entry><literal>octet_length('jo\\000se'::bytea)</literal></entry>
       <entry><literal>5</literal></entry>
      </row>
2102

2103
      <row>
2104
       <entry><literal><function>position</function>(<parameter>substring</parameter> in <parameter>string</parameter>)</literal></entry>
2105
       <entry><type>integer</type></entry>
2106
       <entry>Location of specified substring</entry>
2107 2108 2109
      <entry><literal>position('\\000om'::bytea in 'Th\\000omas'::bytea)</literal></entry>
       <entry><literal>3</literal></entry>
      </row>
2110

2111
      <row>
2112
       <entry><literal><function>substring</function>(<parameter>string</parameter> <optional>from <type>integer</type></optional> <optional>for <type>integer</type></optional>)</literal></entry>
2113 2114
       <entry><type>bytea</type></entry>
       <entry>
2115
        Extract substring
2116 2117 2118 2119 2120 2121 2122
        <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>
2123

2124 2125
      <row>
       <entry>
2126 2127 2128
        <literal><function>trim</function>(<optional>both</optional>
        <parameter>bytes</parameter> from
        <parameter>string</parameter>)</literal>
2129 2130 2131
       </entry>
       <entry><type>bytea</type></entry>
       <entry>
2132 2133 2134
        Remove the longest string containing only the bytes in
        <parameter>bytes</parameter> from the start
        and end of <parameter>string</parameter>
2135 2136 2137 2138
       </entry>
       <entry><literal>trim('\\000'::bytea from '\\000Tom\\000'::bytea)</literal></entry>
       <entry><literal>Tom</literal></entry>
      </row>
2139 2140 2141 2142 2143 2144 2145 2146 2147 2148 2149 2150 2151 2152 2153

      <row>
       <entry><function>get_byte</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
       <entry><type>integer</type></entry>
       <entry>
        Extract byte from string.
        <indexterm>
         <primary>get_byte</primary>
        </indexterm>
       </entry>
       <entry><literal>get_byte('Th\\000omas'::bytea, 4)</literal></entry>
       <entry><literal>109</literal></entry>
      </row>

      <row>
2154 2155
       <entry><function>set_byte</function>(<parameter>string</parameter>,
       <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
2156 2157 2158 2159 2160 2161 2162 2163 2164 2165 2166 2167 2168 2169 2170 2171 2172 2173 2174 2175 2176 2177 2178 2179 2180
       <entry><type>bytea</type></entry>
       <entry>
        Set byte in string.
        <indexterm>
         <primary>set_byte</primary>
        </indexterm>
       </entry>
       <entry><literal>set_byte('Th\\000omas'::bytea, 4, 64)</literal></entry>
       <entry><literal>Th\000o@as</literal></entry>
      </row>

      <row>
       <entry><function>get_bit</function>(<parameter>string</parameter>, <parameter>offset</parameter>)</entry>
       <entry><type>integer</type></entry>
       <entry>
        Extract bit from string.
        <indexterm>
         <primary>get_bit</primary>
        </indexterm>
       </entry>
       <entry><literal>get_bit('Th\\000omas'::bytea, 45)</literal></entry>
       <entry><literal>1</literal></entry>
      </row>

      <row>
2181 2182
       <entry><function>set_bit</function>(<parameter>string</parameter>,
       <parameter>offset</parameter>, <parameter>newvalue</>)</entry>
2183 2184 2185 2186 2187 2188 2189 2190 2191 2192
       <entry><type>bytea</type></entry>
       <entry>
        Set bit in string.
        <indexterm>
         <primary>set_bit</primary>
        </indexterm>
       </entry>
       <entry><literal>set_bit('Th\\000omas'::bytea, 45, 0)</literal></entry>
       <entry><literal>Th\000omAs</literal></entry>
      </row>
2193 2194 2195
     </tbody>
    </tgroup>
   </table>
2196

2197
   <para>
2198 2199 2200 2201 2202
    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">.
2203
   </para>
2204

2205 2206 2207 2208 2209 2210 2211 2212 2213 2214 2215 2216
   <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>
2217

2218 2219
     <tbody>
      <row>
2220 2221
       <entry><literal><function>btrim</function>(<parameter>string</parameter>
        <type>bytea</type> <parameter>bytes</parameter> <type>bytea</type>)</literal></entry>
2222 2223
       <entry><type>bytea</type></entry>
       <entry>
2224 2225
        Remove the longest string consisting only of bytes
        in <parameter>bytes</parameter> from the start and end of
2226
        <parameter>string</parameter>.
2227 2228 2229 2230 2231 2232
      </entry>
      <entry><literal>btrim('\\000trim\\000'::bytea,'\\000'::bytea)</literal></entry>
      <entry><literal>trim</literal></entry>
     </row>

     <row>
2233
      <entry><literal><function>length</function>(<parameter>string</parameter>)</literal></entry>
2234 2235
      <entry><type>integer</type></entry>
      <entry>
2236
       Length of binary string
2237 2238 2239 2240 2241 2242 2243 2244 2245 2246
       <indexterm>
        <primary>binary strings</primary>
	<secondary>length</secondary>
       </indexterm>
       <indexterm>
        <primary>length</primary>
	<secondary>binary strings</secondary>
	<see>binary strings, length</see>
       </indexterm>
      </entry>
2247 2248
      <entry><literal>length('jo\\000se'::bytea)</literal></entry>
      <entry><literal>5</literal></entry>
2249 2250 2251 2252
     </row>

     <row>
      <entry>
2253 2254
       <literal><function>decode</function>(<parameter>string</parameter> <type>text</type>,
              <parameter>type</parameter> <type>text</type>)</literal>
2255
      </entry>
2256
      <entry><type>bytea</type></entry>
2257
      <entry>
2258 2259
       Decode binary string from <parameter>string</parameter> previously 
       encoded with <literal>encode</>.  Parameter type is same as in <literal>encode</>.
2260
      </entry>
2261
      <entry><literal>decode('123\\000456', 'escape')</literal></entry>
2262 2263 2264 2265 2266
      <entry><literal>123\000456</literal></entry>
     </row>       

     <row>
      <entry>
2267 2268
       <literal><function>encode</function>(<parameter>string</parameter> <type>bytea</type>,
              <parameter>type</parameter> <type>text</type>)</literal>
2269
      </entry>
2270
      <entry><type>text</type></entry>
2271
      <entry>
2272 2273
       Encode binary string to <acronym>ASCII</acronym>-only representation.  Supported
       types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
2274
      </entry>
2275
      <entry><literal>encode('123\\000456'::bytea, 'escape')</literal></entry>
2276 2277 2278 2279 2280 2281 2282 2283 2284 2285
      <entry><literal>123\000456</literal></entry>
     </row>       

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

 </sect1>


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

2289 2290 2291 2292
  <indexterm zone="functions-matching">
   <primary>pattern matching</primary>
  </indexterm>

2293
   <para>
2294
    There are three separate approaches to pattern matching provided by
2295 2296
    <productname>PostgreSQL</productname>:  the traditional
    <acronym>SQL</acronym> 
2297
    <function>LIKE</function> operator, the more recent
2298
    <acronym>SQL99</acronym> 
2299
    <function>SIMILAR TO</function> operator, and
2300 2301
    <acronym>POSIX</acronym>-style regular expressions.
    Additionally, a pattern matching function,
2302
    <function>substring</function>, is available, using either
2303
    <acronym>SQL99</acronym>-style or POSIX-style regular expressions.
2304 2305 2306 2307 2308 2309 2310 2311
   </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>
2312

2313
  <sect2 id="functions-like">
2314
   <title><function>LIKE</function></title>
2315

2316 2317 2318 2319
   <indexterm>
    <primary>like</primary>
   </indexterm>

2320
<synopsis>
2321 2322
<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>
2323
</synopsis>
2324

2325 2326 2327 2328 2329 2330 2331 2332 2333 2334 2335
    <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>
2336 2337

    <para>
2338 2339 2340 2341 2342 2343 2344 2345 2346
     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>

2347 2348 2349
   <para>
    Some examples:
<programlisting>
2350 2351 2352 2353
'abc' LIKE 'abc'    <lineannotation>true</lineannotation>
'abc' LIKE 'a%'     <lineannotation>true</lineannotation>
'abc' LIKE '_b_'    <lineannotation>true</lineannotation>
'abc' LIKE 'c'      <lineannotation>false</lineannotation>
2354 2355 2356
</programlisting>
   </para>
   
2357
   <para>
2358
    <function>LIKE</function> pattern matches always cover the entire
2359
    string.  To match a pattern anywhere within a string, the
2360
    pattern must therefore start and end with a percent sign.
2361
   </para>
2362 2363

   <para>
2364 2365 2366 2367
    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
2368
    character is the backslash but a different one may be selected by
2369 2370 2371 2372 2373 2374 2375
    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
2376
    you must write two backslashes in an SQL statement.  Thus, writing a pattern
2377
    that actually matches a literal backslash means writing four backslashes
2378 2379
    in the statement.  You can avoid this by selecting a different escape
    character with <literal>ESCAPE</literal>; then a backslash is not special
2380
    to <function>LIKE</function> anymore. (But it is still special to the string
2381 2382 2383 2384 2385
    literal parser, so you still need two of them.)
   </para>

   <para>
    It's also possible to select no escape character by writing
2386
    <literal>ESCAPE ''</literal>.  This effectively disables the
Bruce Momjian's avatar
Bruce Momjian committed
2387 2388
    escape mechanism, which makes it impossible to turn off the
    special meaning of underscore and percent signs in the pattern.
2389
   </para>
2390 2391

   <para>
2392
    The key word <token>ILIKE</token> can be used instead of
2393
    <token>LIKE</token> to make the match case insensitive according
2394
    to the active locale.  This is not in the <acronym>SQL</acronym> standard but is a
2395
    <productname>PostgreSQL</productname> extension.
2396
   </para>
2397

2398 2399
   <para>
    The operator <literal>~~</literal> is equivalent to
2400 2401 2402
    <function>LIKE</function>, and <literal>~~*</literal> corresponds to
    <function>ILIKE</function>.  There are also
    <literal>!~~</literal> and <literal>!~~*</literal> operators that
2403
    represent <function>NOT LIKE</function> and <function>NOT
2404
    ILIKE</function>, respectively.  All of these operators are
2405
    <productname>PostgreSQL</productname>-specific.
2406 2407
   </para>
  </sect2>
2408

2409

2410 2411
  <sect2 id="functions-sql99-regexp">
   <title><function>SIMILAR TO</function> and <acronym>SQL99</acronym>
2412
     Regular Expressions</title>
2413

2414 2415
   <indexterm zone="functions-sql99-regexp">
    <primary>regular expressions</primary>
2416
    <!-- <seealso>pattern matching</seealso> breaks index build -->
2417 2418 2419 2420 2421 2422 2423 2424 2425 2426
   </indexterm>

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

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

2427
<synopsis>
2428 2429
<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>
2430
</synopsis>
2431 2432 2433 2434 2435 2436 2437 2438 2439 2440 2441 2442 2443 2444 2445 2446 2447 2448 2449

    <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
2450 2451 2452
     <literal>_</> and <literal>%</> as wildcard characters denoting
     any single character and any string, respectively (these are
     comparable to <literal>.</> and <literal>.*</> in POSIX regular
2453 2454 2455 2456 2457 2458 2459 2460 2461 2462 2463 2464 2465 2466 2467 2468 2469 2470 2471 2472 2473 2474 2475 2476 2477 2478 2479 2480 2481 2482 2483 2484 2485 2486 2487 2488 2489 2490 2491 2492 2493
     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>{...}</>)
2494
     are not provided, though they exist in POSIX.  Also, the dot (<literal>.</>)
2495 2496 2497 2498 2499 2500 2501 2502 2503
     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>

2504 2505 2506
   <para>
    Some examples:
<programlisting>
2507 2508 2509 2510
'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>
2511 2512
</programlisting>
   </para>
2513 2514

    <para>
2515 2516 2517 2518
     The <function>substring</> function with three parameters,
     <function>substring(<parameter>string</parameter> from
     <replaceable>pattern</replaceable> for
     <replaceable>escape-character</replaceable>)</function>, provides
2519 2520 2521 2522
     extraction of a substring that matches a <acronym>SQL99</acronym>
     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
2523 2524
     pattern that should be returned on success, the pattern must contain
     two occurrences of the escape character followed by a double quote
2525 2526
     (<literal>"</>).  The text matching the portion of the pattern
     between these markers is returned.
2527 2528
    </para>

2529 2530 2531
   <para>
    Some examples:
<programlisting>
2532 2533
substring('foobar' from '%#"o_b#"%' for '#')   <lineannotation>oob</lineannotation>
substring('foobar' from '#"o_b#"%' for '#')    <lineannotation>NULL</lineannotation>
2534 2535
</programlisting>
   </para>
2536 2537 2538 2539 2540 2541
  </sect2>

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

   <indexterm zone="functions-posix-regexp">
2542 2543 2544 2545
    <primary>regular expressions</primary>
    <seealso>pattern matching</seealso>
   </indexterm>

2546 2547 2548 2549 2550 2551
   <para>
    <xref linkend="functions-posix-table"> lists the available
    operators for pattern matching using POSIX regular expressions.
   </para>

   <table id="functions-posix-table">
2552 2553 2554 2555 2556 2557 2558 2559 2560 2561 2562
    <title>Regular Expression Match Operators</title>

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

2563 2564 2565 2566 2567 2568
      <tbody>
       <row>
        <entry> <literal>~</literal> </entry>
        <entry>Matches regular expression, case sensitive</entry>
        <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
       </row>
2569

2570 2571 2572 2573 2574
       <row>
        <entry> <literal>~*</literal> </entry>
        <entry>Matches regular expression, case insensitive</entry>
        <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
       </row>
2575

2576 2577 2578 2579 2580 2581 2582 2583 2584 2585 2586 2587 2588 2589 2590 2591 2592 2593
       <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 
2594 2595
     pattern matching than the <function>LIKE</function> and
     <function>SIMILAR TO</> operators.
2596 2597 2598 2599 2600 2601 2602 2603 2604 2605 2606 2607 2608 2609 2610 2611 2612 2613 2614
     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>
2615

2616 2617 2618
   <para>
    Some examples:
<programlisting>
2619 2620 2621 2622
'abc' ~ 'abc'    <lineannotation>true</lineannotation>
'abc' ~ '^a'     <lineannotation>true</lineannotation>
'abc' ~ '(b|d)'  <lineannotation>true</lineannotation>
'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
2623 2624
</programlisting>
   </para>
2625 2626

    <para>
2627 2628
     The <function>substring</> function with two parameters,
     <function>substring(<parameter>string</parameter> from
2629 2630
     <replaceable>pattern</replaceable>)</function>, provides extraction of a substring
     that matches a POSIX regular expression pattern.  It returns null if
2631 2632 2633 2634 2635 2636
     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
2637
     exception.  Also see the non-capturing parentheses described below.
2638 2639
    </para>

2640 2641 2642
   <para>
    Some examples:
<programlisting>
2643 2644
substring('foobar' from 'o.b')     <lineannotation>oob</lineannotation>
substring('foobar' from 'o(.)b')   <lineannotation>o</lineannotation>
2645 2646
</programlisting>
   </para>
2647

2648 2649 2650 2651 2652 2653 2654 2655 2656 2657 2658 2659
   <para>
    <productname>PostgreSQL</productname>'s regular expressions are implemented
    using a package written by Henry Spencer.  Much of
    the description of regular expressions below is copied verbatim from his
    manual entry.
   </para>

<!-- derived from the re_syntax.n man page -->

   <sect3 id="posix-syntax-details">
    <title>Regular Expression Details</title>

2660
   <para>
2661
    Regular expressions (<acronym>RE</acronym>s), as defined in
2662 2663 2664 2665 2666 2667 2668 2669 2670 2671 2672
    <acronym>POSIX</acronym> 1003.2, come in two forms:
    <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
    (roughly those of <command>egrep</command>), and
    <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
    (roughly those of <command>ed</command>).
    <productname>PostgreSQL</productname> supports both forms, and
    also implements some extensions
    that are not in the POSIX standard, but have become widely used anyway
    due to their availability in programming languages such as Perl and Tcl.
    <acronym>RE</acronym>s using these non-POSIX extensions are called
    <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
2673 2674 2675 2676 2677
    in this documentation.  AREs are almost an exact superset of EREs,
    but BREs have several notational incompatibilities (as well as being
    much more limited).
    We first describe the ARE and ERE forms, noting features that apply
    only to AREs, and then describe how BREs differ.
2678
   </para>
2679

2680 2681 2682
   <note>
    <para>
     The form of regular expressions accepted by <productname>PostgreSQL</>
2683 2684
     can be chosen by setting the <varname>regex_flavor</> run-time parameter
     (described in <xref linkend="runtime-config">).  The usual setting is
2685 2686 2687 2688 2689 2690
     <literal>advanced</>, but one might choose <literal>extended</> for
     maximum backwards compatibility with pre-7.4 releases of
     <productname>PostgreSQL</>.
    </para>
   </note>

2691
   <para>
2692
    A regular expression is defined as one or more
2693 2694 2695
    <firstterm>branches</firstterm>, separated by
    <literal>|</literal>.  It matches anything that matches one of the
    branches.
2696
   </para>
2697

2698
   <para>
2699 2700 2701 2702
    A branch is zero or more <firstterm>quantified atoms</> or
    <firstterm>constraints</>, concatenated.
    It matches a match for the first, followed by a match for the second, etc;
    an empty branch matches the empty string.
2703
   </para>
2704

Bruce Momjian's avatar
Bruce Momjian committed
2705
   <para>
2706 2707 2708 2709 2710 2711 2712 2713
    A quantified atom is an <firstterm>atom</> possibly followed
    by a single <firstterm>quantifier</>.
    Without a quantifier, it matches a match for the atom.
    With a quantifier, it can match some number of matches of the atom.
    An <firstterm>atom</firstterm> can be any of the possibilities
    shown in <xref linkend="posix-atoms-table">.
    The possible quantifiers and their meanings are shown in
    <xref linkend="posix-quantifiers-table">.
Bruce Momjian's avatar
Bruce Momjian committed
2714
   </para>
2715

2716
   <para>
2717 2718 2719 2720 2721 2722 2723 2724 2725 2726 2727 2728 2729 2730 2731 2732 2733 2734 2735 2736 2737 2738 2739 2740 2741 2742 2743 2744 2745 2746 2747 2748 2749 2750 2751 2752 2753 2754 2755 2756 2757 2758 2759 2760 2761 2762 2763 2764 2765 2766 2767 2768 2769 2770 2771 2772 2773 2774 2775 2776 2777 2778 2779 2780 2781 2782 2783 2784 2785 2786 2787 2788 2789 2790 2791 2792 2793 2794 2795 2796 2797
    A <firstterm>constraint</> matches an empty string, but matches only when
    specific conditions are met.  A constraint can be used where an atom
    could be used, except it may not be followed by a quantifier.
    The simple constraints are shown in
    <xref linkend="posix-constraints-table">;
    some more constraints are described later.
   </para>


   <table id="posix-atoms-table">
    <title>Regular Expression Atoms</title>

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

      <tbody>
       <row>
       <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
       <entry> (where <replaceable>re</> is any regular expression)
       matches a match for
       <replaceable>re</>, with the match noted for possible reporting </entry>
       </row>

       <row>
       <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
       <entry> as above, but the match is not noted for reporting
       (a <quote>non-capturing</> set of parentheses)
       (AREs only) </entry>
       </row>

       <row>
       <entry> <literal>.</> </entry>
       <entry> matches any single character </entry>
       </row>

       <row>
       <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
       <entry> a <firstterm>bracket expression</>,
       matching any one of the <replaceable>chars</> (see
       <xref linkend="posix-bracket-expressions"> for more detail) </entry>
       </row>

       <row>
       <entry> <literal>\</><replaceable>k</> </entry>
       <entry> (where <replaceable>k</> is a non-alphanumeric character)
       matches that character taken as an ordinary character,
       e.g. <literal>\\</> matches a backslash character </entry>
       </row>

       <row>
       <entry> <literal>\</><replaceable>c</> </entry>
       <entry> where <replaceable>c</> is alphanumeric
       (possibly followed by other characters)
       is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
       (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
       </row>

       <row>
       <entry> <literal>{</> </entry>
       <entry> when followed by a character other than a digit,
       matches the left-brace character <literal>{</>;
       when followed by a digit, it is the beginning of a
       <replaceable>bound</> (see below) </entry>
       </row>

       <row>
       <entry> <replaceable>x</> </entry>
       <entry> where <replaceable>x</> is a single character with no other
       significance, matches that character </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    An RE may not end with <literal>\</>.
2798 2799 2800 2801
   </para>

   <note>
    <para>
2802 2803 2804
     Remember that the backslash (<literal>\</literal>) already has a special
     meaning in <productname>PostgreSQL</> string literals.
     To write a pattern constant that contains a backslash,
2805
     you must write two backslashes in the statement.
2806
    </para>
2807 2808 2809 2810 2811 2812 2813 2814 2815 2816 2817 2818 2819 2820 2821 2822 2823 2824 2825 2826 2827 2828 2829 2830 2831 2832 2833 2834 2835 2836 2837 2838 2839 2840 2841 2842 2843 2844 2845 2846 2847 2848 2849 2850 2851 2852 2853 2854 2855 2856 2857 2858 2859 2860 2861 2862 2863 2864 2865 2866 2867 2868 2869 2870 2871 2872 2873 2874 2875 2876 2877 2878 2879 2880 2881 2882 2883 2884 2885 2886 2887 2888 2889 2890 2891 2892 2893 2894 2895 2896 2897 2898 2899 2900 2901 2902 2903 2904 2905 2906
   </note>

   <table id="posix-quantifiers-table">
    <title>Regular Expression Quantifiers</title>

    <tgroup cols="2">
     <thead>
      <row>
       <entry>Quantifier</entry>
       <entry>Matches</entry>
      </row>
     </thead>

      <tbody>
       <row>
       <entry> <literal>*</> </entry>
       <entry> a sequence of 0 or more matches of the atom </entry>
       </row>

       <row>
       <entry> <literal>+</> </entry>
       <entry> a sequence of 1 or more matches of the atom </entry>
       </row>

       <row>
       <entry> <literal>?</> </entry>
       <entry> a sequence of 0 or 1 matches of the atom </entry>
       </row>

       <row>
       <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
       <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
       </row>

       <row>
       <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
       <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
       </row>

       <row>
       <entry>
       <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
       <entry> a sequence of <replaceable>m</> through <replaceable>n</>
       (inclusive) matches of the atom; <replaceable>m</> may not exceed
       <replaceable>n</> </entry>
       </row>

       <row>
       <entry> <literal>*?</> </entry>
       <entry> non-greedy version of <literal>*</> </entry>
       </row>

       <row>
       <entry> <literal>+?</> </entry>
       <entry> non-greedy version of <literal>+</> </entry>
       </row>

       <row>
       <entry> <literal>??</> </entry>
       <entry> non-greedy version of <literal>?</> </entry>
       </row>

       <row>
       <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
       <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
       </row>

       <row>
       <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
       <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
       </row>

       <row>
       <entry>
       <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
       <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    The forms using <literal>{</><replaceable>...</><literal>}</>
    are known as <firstterm>bound</>s.
    The numbers <replaceable>m</> and <replaceable>n</> within a bound are
    unsigned decimal integers with permissible values from 0 to 255 inclusive.
   </para>

    <para>
     <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
     same possibilities as their corresponding normal (<firstterm>greedy</>)
     counterparts, but prefer the smallest number rather than the largest
     number of matches.
     See <xref linkend="posix-matching-rules"> for more detail.
   </para>

   <note>
    <para>
     A quantifier cannot immediately follow another quantifier.
     A quantifier cannot
2907 2908 2909 2910
     begin an expression or subexpression or follow
     <literal>^</literal> or <literal>|</literal>.
    </para>
   </note>
2911

2912 2913 2914 2915 2916 2917 2918 2919 2920 2921 2922 2923 2924 2925 2926 2927 2928 2929 2930 2931 2932 2933 2934 2935 2936 2937 2938 2939 2940 2941 2942 2943 2944 2945 2946 2947 2948 2949 2950
   <table id="posix-constraints-table">
    <title>Regular Expression Constraints</title>

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

      <tbody>
       <row>
       <entry> <literal>^</> </entry>
       <entry> matches at the beginning of the string </entry>
       </row>

       <row>
       <entry> <literal>$</> </entry>
       <entry> matches at the end of the string </entry>
       </row>

       <row>
       <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
       <entry> <firstterm>positive lookahead</> matches at any point
       where a substring matching <replaceable>re</> begins
       (AREs only) </entry>
       </row>

       <row>
       <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
       <entry> <firstterm>negative lookahead</> matches at any point
       where no substring matching <replaceable>re</> begins
       (AREs only) </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

2951
   <para>
2952 2953 2954
    Lookahead constraints may not contain <firstterm>back references</>
    (see <xref linkend="posix-escape-sequences">),
    and all parentheses within them are considered non-capturing.
2955
   </para>
2956 2957 2958 2959
   </sect3>

   <sect3 id="posix-bracket-expressions">
    <title>Bracket Expressions</title>
2960

2961
   <para>
2962 2963 2964 2965
    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
2966 2967
    <emphasis>not</> from the rest of the list.
    If two characters
2968 2969 2970 2971 2972 2973
    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
2974
    collating-sequence-dependent, so portable programs should avoid
2975
    relying on them.
2976
   </para>
2977

2978
   <para>
2979 2980 2981 2982 2983 2984
    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
2985 2986 2987 2988 2989 2990 2991
    collating element (see below).  With the exception of these characters,
    some combinations using <literal>[</literal>
    (see next paragraphs), and escapes (AREs only), all other special
    characters lose their special significance within a bracket expression.
    In particular, <literal>\</literal> is not special when following
    ERE or BRE rules, though it is special (as introducing an escape)
    in AREs.
2992 2993 2994 2995
   </para>

   <para>
    Within a bracket expression, a collating element (a character, a
2996
    multiple-character sequence that collates as if it were a single
2997 2998 2999 3000
    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
3001
    expression containing a multiple-character collating element can thus
3002 3003 3004 3005 3006 3007
    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>

3008 3009 3010 3011 3012 3013 3014
   <note>
    <para>
     <productname>PostgreSQL</> currently has no multi-character collating
     elements. This information describes possible future behavior.
    </para>
   </note>

3015 3016 3017 3018 3019 3020 3021 3022 3023 3024 3025 3026 3027 3028 3029 3030 3031 3032 3033 3034 3035 3036 3037 3038 3039 3040 3041 3042 3043 3044 3045 3046 3047
   <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
3048
    expressions <literal>[[:&lt;:]]</literal> and
3049 3050
    <literal>[[:&gt;:]]</literal> are constraints,
    matching empty strings at the beginning
3051
    and end of a word respectively.  A word is defined as a sequence
3052 3053 3054
    of word characters that is neither preceded nor followed by word
    characters.  A word character is an <literal>alnum</> character (as
    defined by
3055 3056
    <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
    or an underscore.  This is an extension, compatible with but not
3057 3058 3059 3060 3061 3062 3063 3064 3065 3066 3067 3068 3069 3070 3071 3072 3073 3074 3075 3076 3077 3078 3079 3080 3081 3082 3083 3084 3085 3086 3087 3088 3089 3090 3091 3092 3093 3094 3095 3096 3097 3098 3099 3100 3101 3102 3103 3104 3105 3106 3107 3108 3109 3110 3111 3112 3113 3114 3115 3116 3117 3118 3119 3120 3121 3122 3123 3124 3125 3126 3127 3128 3129 3130 3131 3132 3133 3134 3135 3136 3137 3138 3139 3140 3141 3142 3143 3144 3145 3146 3147 3148 3149 3150 3151 3152 3153 3154 3155 3156 3157 3158 3159 3160 3161 3162 3163 3164 3165 3166 3167 3168 3169 3170 3171 3172 3173 3174 3175 3176 3177 3178 3179 3180 3181 3182 3183 3184 3185 3186 3187 3188 3189 3190 3191 3192 3193 3194 3195 3196 3197 3198 3199 3200 3201 3202 3203 3204 3205 3206 3207 3208 3209 3210 3211 3212 3213 3214 3215 3216 3217 3218 3219 3220 3221 3222 3223 3224 3225 3226 3227 3228 3229 3230 3231 3232 3233 3234 3235 3236 3237 3238 3239 3240 3241 3242 3243 3244 3245 3246 3247 3248 3249 3250 3251 3252 3253 3254 3255 3256 3257 3258 3259 3260 3261 3262 3263 3264 3265 3266 3267 3268 3269 3270 3271 3272 3273 3274 3275 3276 3277 3278 3279 3280 3281 3282 3283 3284 3285 3286 3287 3288 3289 3290 3291 3292 3293 3294 3295 3296 3297 3298 3299 3300
    specified by <acronym>POSIX</acronym> 1003.2, and should be used with
    caution in software intended to be portable to other systems.
    The constraint escapes described below are usually preferable (they
    are no more standard, but are certainly easier to type).
   </para>
   </sect3>

   <sect3 id="posix-escape-sequences">
    <title>Regular Expression Escapes</title>

   <para>
    <firstterm>Escapes</> are special sequences beginning with <literal>\</>
    followed by an alphanumeric character. Escapes come in several varieties:
    character entry, class shorthands, constraint escapes, and back references.
    A <literal>\</> followed by an alphanumeric character but not constituting
    a valid escape is illegal in AREs.
    In EREs, there are no escapes: outside a bracket expression,
    a <literal>\</> followed by an alphanumeric character merely stands for
    that character as an ordinary character, and inside a bracket expression,
    <literal>\</> is an ordinary character.
    (The latter is the one actual incompatibility between EREs and AREs.)
   </para>

   <para>
    <firstterm>Character-entry escapes</> exist to make it easier to specify
    non-printing and otherwise inconvenient characters in REs.  They are
    shown in <xref linkend="posix-character-entry-escapes-table">.
   </para>

   <para>
    <firstterm>Class-shorthand escapes</> provide shorthands for certain
    commonly-used character classes.  They are
    shown in <xref linkend="posix-class-shorthand-escapes-table">.
   </para>

   <para>
    A <firstterm>constraint escape</> is a constraint,
    matching the empty string if specific conditions are met,
    written as an escape.  They are
    shown in <xref linkend="posix-constraint-escapes-table">.
   </para>

   <para>
    A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
    same string matched by the previous parenthesized subexpression specified
    by the number <replaceable>n</>
    (see <xref linkend="posix-constraint-backref-table">).  For example,
    <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
    but not <literal>bc</> or <literal>cb</>.
    The subexpression must entirely precede the back reference in the RE.
    Subexpressions are numbered in the order of their leading parentheses.
    Non-capturing parentheses do not define subexpressions.
   </para>

   <note>
    <para>
     Keep in mind that an escape's leading <literal>\</> will need to be
     doubled when entering the pattern as an SQL string constant.
    </para>
   </note>

   <table id="posix-character-entry-escapes-table">
    <title>Regular Expression Character-Entry Escapes</title>

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

      <tbody>
       <row>
       <entry> <literal>\a</> </entry>
       <entry> alert (bell) character, as in C </entry>
       </row>

       <row>
       <entry> <literal>\b</> </entry>
       <entry> backspace, as in C </entry>
       </row>

       <row>
       <entry> <literal>\B</> </entry>
       <entry> synonym for <literal>\</> to help reduce the need for backslash
       doubling </entry>
       </row>

       <row>
       <entry> <literal>\c</><replaceable>X</> </entry>
       <entry> (where <replaceable>X</> is any character) the character whose
       low-order 5 bits are the same as those of
       <replaceable>X</>, and whose other bits are all zero </entry>
       </row>

       <row>
       <entry> <literal>\e</> </entry>
       <entry> the character whose collating-sequence name
       is <literal>ESC</>,
       or failing that, the character with octal value 033 </entry>
       </row>

       <row>
       <entry> <literal>\f</> </entry>
       <entry> formfeed, as in C </entry>
       </row>

       <row>
       <entry> <literal>\n</> </entry>
       <entry> newline, as in C </entry>
       </row>

       <row>
       <entry> <literal>\r</> </entry>
       <entry> carriage return, as in C </entry>
       </row>

       <row>
       <entry> <literal>\t</> </entry>
       <entry> horizontal tab, as in C </entry>
       </row>

       <row>
       <entry> <literal>\u</><replaceable>wxyz</> </entry>
       <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
       the Unicode character <literal>U+</><replaceable>wxyz</>
       in the local byte ordering </entry>
       </row>

       <row>
       <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
       <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
       digits)
       reserved for a somewhat-hypothetical Unicode extension to 32 bits
       </entry> 
       </row>

       <row>
       <entry> <literal>\v</> </entry>
       <entry> vertical tab, as in C </entry>
       </row>

       <row>
       <entry> <literal>\x</><replaceable>hhh</> </entry>
       <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
       digits)
       the character whose hexadecimal value is
       <literal>0x</><replaceable>hhh</>
       (a single character no matter how many hexadecimal digits are used)
       </entry>
       </row>

       <row>
       <entry> <literal>\0</> </entry>
       <entry> the character whose value is <literal>0</> </entry>
       </row>

       <row>
       <entry> <literal>\</><replaceable>xy</> </entry>
       <entry> (where <replaceable>xy</> is exactly two octal digits,
       and is not a <firstterm>back reference</>)
       the character whose octal value is
       <literal>0</><replaceable>xy</> </entry>
       </row>

       <row>
       <entry> <literal>\</><replaceable>xyz</> </entry>
       <entry> (where <replaceable>xyz</> is exactly three octal digits,
       and is not a <firstterm>back reference</>)
       the character whose octal value is
       <literal>0</><replaceable>xyz</> </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    Hexadecimal digits are <literal>0</>-<literal>9</>,
    <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
    Octal digits are <literal>0</>-<literal>7</>.
   </para>

   <para>
    The character-entry escapes are always taken as ordinary characters.
    For example, <literal>\135</> is <literal>]</> in ASCII, but
    <literal>\135</> does not terminate a bracket expression.
   </para>

   <table id="posix-class-shorthand-escapes-table">
    <title>Regular Expression Class-Shorthand Escapes</title>

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

      <tbody>
       <row>
       <entry> <literal>\d</> </entry>
       <entry> <literal>[[:digit:]]</> </entry>
       </row>

       <row>
       <entry> <literal>\s</> </entry>
       <entry> <literal>[[:space:]]</> </entry>
       </row>

       <row>
       <entry> <literal>\w</> </entry>
       <entry> <literal>[[:alnum:]_]</>
       (note underscore is included) </entry>
       </row>

       <row>
       <entry> <literal>\D</> </entry>
       <entry> <literal>[^[:digit:]]</> </entry>
       </row>

       <row>
       <entry> <literal>\S</> </entry>
       <entry> <literal>[^[:space:]]</> </entry>
       </row>

       <row>
       <entry> <literal>\W</> </entry>
       <entry> <literal>[^[:alnum:]_]</>
       (note underscore is included) </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    Within bracket expressions, <literal>\d</>, <literal>\s</>,
    and <literal>\w</> lose their outer brackets,
    and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
    (So, for example, <literal>[a-c\d]</> is equivalent to
    <literal>[a-c[:digit:]]</>.
    Also, <literal>[a-c\D]</>, which is equivalent to
    <literal>[a-c^[:digit:]]</>, is illegal.)
3301 3302
   </para>

3303 3304 3305 3306 3307 3308 3309 3310 3311 3312 3313 3314 3315 3316 3317 3318 3319 3320 3321 3322 3323 3324 3325 3326 3327 3328 3329 3330 3331 3332 3333 3334 3335 3336 3337 3338 3339 3340 3341 3342 3343 3344 3345 3346 3347 3348 3349 3350 3351 3352 3353 3354 3355 3356 3357 3358 3359 3360 3361 3362 3363 3364 3365 3366 3367 3368 3369 3370 3371 3372 3373 3374 3375 3376 3377 3378 3379 3380 3381 3382 3383 3384 3385 3386 3387 3388 3389 3390 3391 3392 3393 3394 3395 3396 3397 3398 3399 3400 3401 3402 3403 3404 3405 3406 3407
   <table id="posix-constraint-escapes-table">
    <title>Regular Expression Constraint Escapes</title>

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

      <tbody>
       <row>
       <entry> <literal>\A</> </entry>
       <entry> matches only at the beginning of the string
       (see <xref linkend="posix-matching-rules"> for how this differs from
       <literal>^</>) </entry>
       </row>

       <row>
       <entry> <literal>\m</> </entry>
       <entry> matches only at the beginning of a word </entry>
       </row>

       <row>
       <entry> <literal>\M</> </entry>
       <entry> matches only at the end of a word </entry>
       </row>

       <row>
       <entry> <literal>\y</> </entry>
       <entry> matches only at the beginning or end of a word </entry>
       </row>

       <row>
       <entry> <literal>\Y</> </entry>
       <entry> matches only at a point that is not the beginning or end of a
       word </entry>
       </row>

       <row>
       <entry> <literal>\Z</> </entry>
       <entry> matches only at the end of the string
       (see <xref linkend="posix-matching-rules"> for how this differs from
       <literal>$</>) </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    A word is defined as in the specification of
    <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</> above.
    Constraint escapes are illegal within bracket expressions.
   </para>

   <table id="posix-constraint-backref-table">
    <title>Regular Expression Back References</title>

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

      <tbody>
       <row>
       <entry> <literal>\</><replaceable>m</> </entry>
       <entry> (where <replaceable>m</> is a nonzero digit)
       a back reference to the <replaceable>m</>'th subexpression </entry>
       </row>

       <row>
       <entry> <literal>\</><replaceable>mnn</> </entry>
       <entry> (where <replaceable>m</> is a nonzero digit, and
       <replaceable>nn</> is some more digits, and the decimal value
       <replaceable>mnn</> is not greater than the number of closing capturing
       parentheses seen so far) 
       a back reference to the <replaceable>mnn</>'th subexpression </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <note>
    <para>
     There is an inherent historical ambiguity between octal character-entry 
     escapes and back references, which is resolved by heuristics,
     as hinted at above.
     A leading zero always indicates an octal escape.
     A single non-zero digit, not followed by another digit,
     is always taken as a back reference.
     A multi-digit sequence not starting with a zero is taken as a back 
     reference if it comes after a suitable subexpression
     (i.e. the number is in the legal range for a back reference),
     and otherwise is taken as octal.
    </para>
   </note>
   </sect3>

   <sect3 id="posix-metasyntax">
    <title>Regular Expression Metasyntax</title>

3408
   <para>
3409 3410
    In addition to the main syntax described above, there are some special
    forms and miscellaneous syntactic facilities available.
3411 3412 3413
   </para>

   <para>
3414 3415 3416
    Normally the flavor of RE being used is determined by
    <varname>REGEX_FLAVOR</>.
    However, this can be overridden by a <firstterm>director</> prefix.
3417
    If an RE of any flavor begins with <literal>***:</>,
3418
    the rest of the RE is taken as an ARE.
3419 3420 3421
    If an RE of any flavor begins with <literal>***=</>,
    the rest of the RE is taken to be a literal string,
    with all characters considered ordinary characters.
3422 3423 3424
   </para>

   <para>
3425 3426 3427 3428
    An ARE may begin with <firstterm>embedded options</>:
    a sequence <literal>(?</><replaceable>xyz</><literal>)</>
    (where <replaceable>xyz</> is one or more alphabetic characters)
    specifies options affecting the rest of the RE.
3429 3430
    These options override any previously determined options (including
    both the RE flavor and case sensitivity).
3431 3432 3433 3434 3435 3436 3437 3438 3439 3440 3441 3442 3443 3444 3445 3446 3447 3448 3449 3450 3451 3452 3453
    The available option letters are
    shown in <xref linkend="posix-embedded-options-table">.
   </para>

   <table id="posix-embedded-options-table">
    <title>ARE Embedded-Option Letters</title>

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

      <tbody>
       <row>
       <entry> <literal>b</> </entry>
       <entry> rest of RE is a BRE </entry>
       </row>

       <row>
       <entry> <literal>c</> </entry>
3454
       <entry> case-sensitive matching (overrides operator type) </entry>
3455 3456 3457 3458 3459 3460 3461 3462 3463 3464
       </row>

       <row>
       <entry> <literal>e</> </entry>
       <entry> rest of RE is an ERE </entry>
       </row>

       <row>
       <entry> <literal>i</> </entry>
       <entry> case-insensitive matching (see
3465
       <xref linkend="posix-matching-rules">) (overrides operator type) </entry>
3466 3467 3468 3469 3470 3471 3472 3473 3474 3475 3476 3477 3478 3479 3480 3481 3482 3483 3484 3485 3486 3487 3488 3489 3490 3491 3492
       </row>

       <row>
       <entry> <literal>m</> </entry>
       <entry> historical synonym for <literal>n</> </entry>
       </row>

       <row>
       <entry> <literal>n</> </entry>
       <entry> newline-sensitive matching (see
       <xref linkend="posix-matching-rules">) </entry>
       </row>

       <row>
       <entry> <literal>p</> </entry>
       <entry> partial newline-sensitive matching (see
       <xref linkend="posix-matching-rules">) </entry>
       </row>

       <row>
       <entry> <literal>q</> </entry>
       <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
       characters </entry>
       </row>

       <row>
       <entry> <literal>s</> </entry>
3493
       <entry> non-newline-sensitive matching (default) </entry>
3494 3495 3496 3497
       </row>

       <row>
       <entry> <literal>t</> </entry>
3498
       <entry> tight syntax (default; see below) </entry>
3499 3500 3501 3502 3503 3504 3505 3506 3507 3508 3509 3510 3511 3512 3513 3514 3515 3516 3517 3518 3519 3520 3521 3522 3523 3524 3525 3526 3527 3528 3529 3530 3531 3532 3533 3534 3535 3536 3537 3538 3539 3540 3541 3542 3543 3544 3545 3546 3547 3548 3549 3550 3551 3552 3553 3554 3555 3556 3557 3558 3559 3560 3561 3562 3563 3564 3565 3566 3567 3568 3569 3570 3571 3572 3573 3574 3575 3576 3577 3578 3579 3580 3581 3582 3583 3584 3585 3586 3587 3588 3589 3590 3591 3592 3593 3594 3595 3596 3597 3598 3599 3600 3601 3602 3603 3604 3605 3606 3607 3608 3609 3610 3611 3612 3613 3614 3615 3616 3617 3618 3619 3620 3621 3622 3623 3624 3625 3626 3627 3628 3629 3630 3631 3632 3633 3634 3635 3636 3637 3638 3639 3640 3641 3642 3643 3644 3645
       </row>

       <row>
       <entry> <literal>w</> </entry>
       <entry> inverse partial newline-sensitive (<quote>weird</>) matching
       (see <xref linkend="posix-matching-rules">) </entry>
       </row>

       <row>
       <entry> <literal>x</> </entry>
       <entry> expanded syntax (see below) </entry>
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
    Embedded options take effect at the <literal>)</> terminating the sequence.
    They are available only at the start of an ARE,
    and may not be used later within it.
   </para>

   <para>
    In addition to the usual (<firstterm>tight</>) RE syntax, in which all
    characters are significant, there is an <firstterm>expanded</> syntax,
    available by specifying the embedded <literal>x</> option.
    In the expanded syntax,
    white-space characters in the RE are ignored, as are
    all characters between a <literal>#</>
    and the following newline (or the end of the RE).  This
    permits paragraphing and commenting a complex RE.
    There are three exceptions to that basic rule:

    <itemizedlist>
     <listitem>
      <para>
       a white-space character or <literal>#</> preceded by <literal>\</> is
       retained
      </para>
     </listitem>
     <listitem>
      <para>
       white space or <literal>#</> within a bracket expression is retained
      </para>
     </listitem>
     <listitem>
      <para>
       white space and comments are illegal within multi-character symbols,
       like the ARE <literal>(?:</> or the BRE <literal>\(</>
      </para>
     </listitem>
    </itemizedlist>

    Expanded-syntax white-space characters are blank, tab, newline, and
    any character that belongs to the <replaceable>space</> character class.
   </para>

   <para>
    Finally, in an ARE, outside bracket expressions, the sequence
    <literal>(?#</><replaceable>ttt</><literal>)</>
    (where <replaceable>ttt</> is any text not containing a <literal>)</>)
    is a comment, completely ignored.
    Again, this is not allowed between the characters of
    multi-character symbols, like <literal>(?:</>.
    Such comments are more a historical artifact than a useful facility,
    and their use is deprecated; use the expanded syntax instead.
   </para>

   <para>
    <emphasis>None</> of these metasyntax extensions is available if
    an initial <literal>***=</> director
    has specified that the user's input be treated as a literal string
    rather than as an RE.
   </para>
   </sect3>

   <sect3 id="posix-matching-rules">
    <title>Regular Expression Matching Rules</title>

   <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,
    its choice is determined by its <firstterm>preference</>:
    either the longest substring, or the shortest.
   </para>

   <para>
    Most atoms, and all constraints, have no preference.
    A parenthesized RE has the same preference (possibly none) as the RE.
    A quantified atom with quantifier
    <literal>{</><replaceable>m</><literal>}</>
    or
    <literal>{</><replaceable>m</><literal>}?</>
    has the same preference (possibly none) as the atom itself.
    A quantified atom with other normal quantifiers (including
    <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
    with <replaceable>m</> equal to <replaceable>n</>)
    prefers longest match.
    A quantified atom with other non-greedy quantifiers (including
    <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
    with <replaceable>m</> equal to <replaceable>n</>)
    prefers shortest match.
    A branch has the same preference as the first quantified atom in it
    which has a preference.
    An RE consisting of two or more branches connected by the
    <literal>|</> operator prefers longest match.
   </para>

   <para>
    Subject to the constraints imposed by the rules for matching the whole RE,
    subexpressions also match the longest or shortest possible substrings,
    based on their preferences,
    with subexpressions starting earlier in the RE taking priority over
    ones starting later.
    Note that outer subexpressions thus take priority over
    their component subexpressions.
   </para>

   <para>
    The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
    can be used to force longest and shortest preference, respectively,
    on a subexpression or a whole RE.
   </para>

   <para>
    Match lengths are measured in characters, not collating elements.
    An empty string is considered longer than no match at all.
    For example:
    <literal>bb*</>
    matches the three middle characters of <literal>abbbc</>;
    <literal>(week|wee)(night|knights)</>
    matches all ten characters of <literal>weeknights</>;
    when <literal>(.*).*</>
    is matched against <literal>abc</> the parenthesized subexpression
    matches all three characters; and when
    <literal>(a*)*</> is matched against <literal>bc</>
    both the whole RE and the parenthesized
    subexpression match an empty 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
3646
    transformed into a bracket expression containing both cases,
3647 3648 3649 3650 3651 3652 3653 3654 3655 3656 3657 3658 3659 3660 3661 3662 3663 3664 3665 3666 3667 3668 3669 3670 3671 3672 3673 3674 3675 3676 3677 3678 3679 3680 3681 3682 3683 3684 3685 3686 3687 3688 3689 3690 3691 3692 3693 3694 3695 3696 3697 3698 3699 3700 3701 3702 3703 3704 3705 3706 3707 3708 3709 3710 3711 3712 3713 3714 3715 3716 3717
    e.g. <literal>x</> becomes <literal>[xX]</>.
    When it appears inside a bracket expression, all case counterparts
    of it are added to the bracket expression, e.g.
    <literal>[x]</> becomes <literal>[xX]</>
    and <literal>[^x]</> becomes <literal>[^xX]</>.
   </para>

   <para>
    If newline-sensitive matching is specified, <literal>.</>
    and bracket expressions using <literal>^</>
    will never match the newline character
    (so that matches will never cross newlines unless the RE
    explicitly arranges it)
    and <literal>^</>and <literal>$</>
    will match the empty string after and before a newline
    respectively, in addition to matching at beginning and end of string
    respectively.
    But the ARE escapes <literal>\A</> and <literal>\Z</>
    continue to match beginning or end of string <emphasis>only</>.
   </para>

   <para>
    If partial newline-sensitive matching is specified,
    this affects <literal>.</> and bracket expressions
    as with newline-sensitive matching, but not <literal>^</>
    and <literal>$</>.
   </para>

   <para>
    If inverse partial newline-sensitive matching is specified,
    this affects <literal>^</> and <literal>$</>
    as with newline-sensitive matching, but not <literal>.</>
    and bracket expressions.
    This isn't very useful but is provided for symmetry.
   </para>
   </sect3>

   <sect3 id="posix-limits-compatibility">
    <title>Limits and Compatibility</title>

   <para>
    No particular limit is imposed on the length of REs in this
    implementation.  However,
    programs intended to be highly portable should not employ REs longer
    than 256 bytes,
    as a POSIX-compliant implementation can refuse to accept such REs.
   </para>

   <para>
    The only feature of AREs that is actually incompatible with
    POSIX EREs is that <literal>\</> does not lose its special
    significance inside bracket expressions.
    All other ARE features use syntax which is illegal or has
    undefined or unspecified effects in POSIX EREs;
    the <literal>***</> syntax of directors likewise is outside the POSIX
    syntax for both BREs and EREs.
   </para>

   <para>
    Many of the ARE extensions are borrowed from Perl, but some have
    been changed to clean them up, and a few Perl extensions are not present.
    Incompatibilities of note include <literal>\b</>, <literal>\B</>,
    the lack of special treatment for a trailing newline,
    the addition of complemented bracket expressions to the things
    affected by newline-sensitive matching,
    the restrictions on parentheses and back references in lookahead
    constraints, and the longest/shortest-match (rather than first-match)
    matching semantics.
   </para>

   <para>
3718
    Two significant incompatibilities exist between AREs and the ERE syntax
3719 3720 3721 3722 3723 3724 3725 3726 3727 3728 3729 3730 3731 3732 3733 3734 3735 3736 3737 3738
    recognized by pre-7.4 releases of <productname>PostgreSQL</>:

    <itemizedlist>
     <listitem>
      <para>
       In AREs, <literal>\</> followed by an alphanumeric character is either
       an escape or an error, while in previous releases, it was just another
       way of writing the alphanumeric.
       This should not be much of a problem because there was no reason to
       write such a sequence in earlier releases.
      </para>
     </listitem>
     <listitem>
      <para>
       In AREs, <literal>\</> remains a special character within
       <literal>[]</>, so a literal <literal>\</> within a bracket
       expression must be written <literal>\\</>.
      </para>
     </listitem>
    </itemizedlist>
3739 3740 3741 3742

    While these differences are unlikely to create a problem for most
    applications, you can avoid them if necessary by
    setting <varname>REGEX_FLAVOR</> to <literal>extended</>.
3743 3744 3745 3746 3747
   </para>
   </sect3>

   <sect3 id="posix-basic-regexes">
    <title>Basic Regular Expressions</title>
3748

3749 3750 3751 3752 3753 3754 3755 3756 3757 3758 3759 3760 3761 3762 3763 3764 3765 3766 3767 3768 3769 3770 3771 3772 3773 3774 3775 3776 3777 3778
   <para>
    BREs differ from EREs in several respects.
    <literal>|</>, <literal>+</>, and <literal>?</>
    are ordinary characters and there is no equivalent
    for their functionality.
    The delimiters for bounds are
    <literal>\{</> and <literal>\}</>,
    with <literal>{</> and <literal>}</>
    by themselves ordinary characters.
    The parentheses for nested subexpressions are
    <literal>\(</> and <literal>\)</>,
    with <literal>(</> and <literal>)</> by themselves ordinary characters.
    <literal>^</> is an ordinary character except at the beginning of the
    RE or the beginning of a parenthesized subexpression,
    <literal>$</> is an ordinary character except at the end of the
    RE or the end of a parenthesized subexpression,
    and <literal>*</> is an ordinary character if it appears at the beginning
    of the RE or the beginning of a parenthesized subexpression
    (after a possible leading <literal>^</>).
    Finally, single-digit back references are available, and
    <literal>\&lt;</> and <literal>\&gt;</>
    are synonyms for
    <literal>[[:&lt;:]]</> and <literal>[[:&gt;:]]</>
    respectively; no other escapes are available.
   </para>
   </sect3>

<!-- end re_syntax.n man page -->

  </sect2>
3779 3780 3781 3782
 </sect1>


  <sect1 id="functions-formatting">
3783
   <title>Data Type Formatting Functions</title>
3784

3785 3786 3787 3788
   <indexterm zone="functions-formatting">
    <primary>formatting</primary>
   </indexterm>

3789
   <para>
3790
    The <productname>PostgreSQL</productname> formatting functions
3791 3792
    provide a powerful set of tools for converting various data types
    (date/time, integer, floating point, numeric) to formatted strings
3793
    and for converting from formatted strings to specific data types.
3794
    <xref linkend="functions-formatting-table"> lists them.
3795
    These functions all follow a common calling convention: the first
3796
    argument is the value to be formatted and the second argument is a
3797
    template that defines the output or input format.
3798 3799
   </para>

3800
    <table id="functions-formatting-table">
3801 3802 3803 3804 3805
     <title>Formatting Functions</title>
     <tgroup cols="4">
      <thead>
       <row>
	<entry>Function</entry>
3806
	<entry>Return Type</entry>
3807 3808 3809 3810 3811 3812
	<entry>Description</entry>
	<entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
3813
	<entry><literal><function>to_char</function>(<type>timestamp</type>, <type>text</type>)</literal></entry>
3814 3815
	<entry><type>text</type></entry>
	<entry>convert time stamp to string</entry>
3816
	<entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
3817
       </row>
3818
       <row>
3819
	<entry><literal><function>to_char</function>(<type>interval</type>, <type>text</type>)</literal></entry>
3820
	<entry><type>text</type></entry>
3821
	<entry>convert interval to string</entry>
3822
	<entry><literal>to_char(interval '15h&nbsp;2m&nbsp;12s', 'HH24:MI:SS')</literal></entry>
3823
       </row>
3824
       <row>
3825
	<entry><literal><function>to_char</function>(<type>int</type>, <type>text</type>)</literal></entry>
3826
	<entry><type>text</type></entry>
3827
	<entry>convert integer to string</entry>
3828
	<entry><literal>to_char(125, '999')</literal></entry>
3829 3830
       </row>
       <row>
3831 3832
	<entry><literal><function>to_char</function>(<type>double precision</type>,
        <type>text</type>)</literal></entry>
3833
	<entry><type>text</type></entry>
3834
	<entry>convert real/double precision to string</entry>
3835
	<entry><literal>to_char(125.8::real, '999D9')</literal></entry>
3836 3837
       </row>
       <row>
3838
	<entry><literal><function>to_char</function>(<type>numeric</type>, <type>text</type>)</literal></entry>
3839
	<entry><type>text</type></entry>
3840
	<entry>convert numeric to string</entry>
3841
	<entry><literal>to_char(-125.8, '999D99S')</literal></entry>
3842 3843
       </row>
       <row>
3844
	<entry><literal><function>to_date</function>(<type>text</type>, <type>text</type>)</literal></entry>
3845
	<entry><type>date</type></entry>
3846
	<entry>convert string to date</entry>
3847
	<entry><literal>to_date('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
3848 3849
       </row>
       <row>
3850
	<entry><literal><function>to_timestamp</function>(<type>text</type>, <type>text</type>)</literal></entry>
3851 3852
	<entry><type>timestamp</type></entry>
	<entry>convert string to time stamp</entry>
3853
	<entry><literal>to_timestamp('05&nbsp;Dec&nbsp;2000', 'DD&nbsp;Mon&nbsp;YYYY')</literal></entry>
3854 3855
       </row>
       <row>
3856
	<entry><literal><function>to_number</function>(<type>text</type>, <type>text</type>)</literal></entry>
3857
	<entry><type>numeric</type></entry>
3858
	<entry>convert string to numeric</entry>
3859
	<entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
3860 3861 3862 3863 3864
       </row>
      </tbody>
     </tgroup>
    </table>

3865
   <para>
3866
    In an output template string (for <function>to_char</>), there are certain patterns that are
3867 3868
    recognized and replaced with appropriately-formatted data from the value
    to be formatted.  Any text that is not a template pattern is simply
3869
    copied verbatim.  Similarly, in an input template string (for anything but <function>to_char</>), template patterns
3870 3871 3872 3873
    identify the parts of the input data string to be looked at and the
    values to be found there.
   </para>

3874 3875 3876 3877 3878 3879
  <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">
3880
     <title>Template Patterns for Date/Time Formatting</title>
3881 3882 3883
     <tgroup cols="2">
      <thead>
       <row>
3884
	<entry>Pattern</entry>
3885 3886 3887 3888 3889
	<entry>Description</entry>
       </row>
      </thead>
      <tbody>
       <row>
3890
	<entry><literal>HH</literal></entry>
3891
	<entry>hour of day (01-12)</entry>
3892 3893
       </row>
       <row>
3894
	<entry><literal>HH12</literal></entry>
3895
	<entry>hour of day (01-12)</entry>
3896
       </row>       
3897
       <row>
3898
	<entry><literal>HH24</literal></entry>
3899 3900
	<entry>hour of day (00-23)</entry>
       </row>       
3901
       <row>
3902
	<entry><literal>MI</literal></entry>
3903
	<entry>minute (00-59)</entry>
3904 3905
       </row>   
       <row>
3906
	<entry><literal>SS</literal></entry>
3907
	<entry>second (00-59)</entry>
3908
       </row>
3909
       <row>
3910
	<entry><literal>MS</literal></entry>
3911 3912 3913
	<entry>millisecond (000-999)</entry>
       </row>
       <row>
3914
	<entry><literal>US</literal></entry>
3915 3916
	<entry>microsecond (000000-999999)</entry>
       </row>
3917
       <row>
3918
	<entry><literal>SSSS</literal></entry>
3919
	<entry>seconds past midnight (0-86399)</entry>
3920
       </row>
3921
       <row>
3922
	<entry><literal>AM</literal> or <literal>A.M.</literal> or
3923
	<literal>PM</literal> or <literal>P.M.</literal></entry>
3924 3925 3926
	<entry>meridian indicator (upper case)</entry>
       </row>
       <row>
3927
	<entry><literal>am</literal> or <literal>a.m.</literal> or
3928
	<literal>pm</literal> or <literal>p.m.</literal></entry>
3929 3930
	<entry>meridian indicator (lower case)</entry>
       </row>
3931
       <row>
3932
	<entry><literal>Y,YYY</literal></entry>
3933
	<entry>year (4 and more digits) with comma</entry>
3934 3935
       </row>
       <row>
3936
	<entry><literal>YYYY</literal></entry>
3937
	<entry>year (4 and more digits)</entry>
3938 3939
       </row>
       <row>
3940
	<entry><literal>YYY</literal></entry>
3941
	<entry>last 3 digits of year</entry>
3942 3943
       </row>
       <row>
3944
	<entry><literal>YY</literal></entry>
3945
	<entry>last 2 digits of year</entry>
3946 3947
       </row>
       <row>
3948
	<entry><literal>Y</literal></entry>
3949
	<entry>last digit of year</entry>
3950
       </row>
3951
       <row>
3952
	<entry><literal>BC</literal> or <literal>B.C.</literal> or
3953
	<literal>AD</literal> or <literal>A.D.</literal></entry>
3954
	<entry>era indicator (upper case)</entry>
3955 3956
       </row>
       <row>
3957
	<entry><literal>bc</literal> or <literal>b.c.</literal> or
3958
	<literal>ad</literal> or <literal>a.d.</literal></entry>
3959
	<entry>era indicator (lower case)</entry>
3960
       </row>
3961
       <row>
3962
	<entry><literal>MONTH</literal></entry>
3963
	<entry>full upper-case month name (blank-padded to 9 chars)</entry>
3964 3965
       </row>
       <row>
3966
	<entry><literal>Month</literal></entry>
3967
	<entry>full mixed-case month name (blank-padded to 9 chars)</entry>
3968 3969
       </row>
       <row>
3970
	<entry><literal>month</literal></entry>
3971
	<entry>full lower-case month name (blank-padded to 9 chars)</entry>
3972 3973
       </row>
       <row>
3974
	<entry><literal>MON</literal></entry>
3975
	<entry>abbreviated upper-case month name (3 chars)</entry>
3976 3977
       </row>
       <row>
3978
	<entry><literal>Mon</literal></entry>
3979
	<entry>abbreviated mixed-case month name (3 chars)</entry>
3980 3981
       </row>
       <row>
3982
	<entry><literal>mon</literal></entry>
3983
	<entry>abbreviated lower-case month name (3 chars)</entry>
3984 3985
       </row>
       <row>
3986
	<entry><literal>MM</literal></entry>
3987
	<entry>month number (01-12)</entry>
3988 3989
       </row>
       <row>
3990
	<entry><literal>DAY</literal></entry>
3991
	<entry>full upper-case day name (blank-padded to 9 chars)</entry>
3992 3993
       </row>
       <row>
3994
	<entry><literal>Day</literal></entry>
3995
	<entry>full mixed-case day name (blank-padded to 9 chars)</entry>
3996 3997
       </row>
       <row>
3998
	<entry><literal>day</literal></entry>
3999
	<entry>full lower-case day name (blank-padded to 9 chars)</entry>
4000 4001
       </row>
       <row>
4002
	<entry><literal>DY</literal></entry>
4003
	<entry>abbreviated upper-case day name (3 chars)</entry>
4004 4005
       </row>
       <row>
4006
	<entry><literal>Dy</literal></entry>
4007
	<entry>abbreviated mixed-case day name (3 chars)</entry>
4008 4009
       </row>
       <row>
4010
	<entry><literal>dy</literal></entry>
4011
	<entry>abbreviated lower-case day name (3 chars)</entry>
4012 4013
       </row>
       <row>
4014
	<entry><literal>DDD</literal></entry>
4015
	<entry>day of year (001-366)</entry>
4016 4017
       </row>
       <row>
4018
	<entry><literal>DD</literal></entry>
4019
	<entry>day of month (01-31)</entry>
4020 4021
       </row>
       <row>
4022
	<entry><literal>D</literal></entry>
4023
	<entry>day of week (1-7; Sunday is 1)</entry>
4024 4025
       </row>
       <row>
4026
	<entry><literal>W</literal></entry>
4027
	<entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
4028 4029
       </row> 
       <row>
4030
	<entry><literal>WW</literal></entry>
4031
	<entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
4032
       </row>
Bruce Momjian's avatar
Bruce Momjian committed
4033
       <row>
4034
	<entry><literal>IW</literal></entry>
4035
	<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
4036
       </row>
4037
       <row>
4038
	<entry><literal>CC</literal></entry>
4039
	<entry>century (2 digits)</entry>
4040 4041
       </row>
       <row>
4042
	<entry><literal>J</literal></entry>
4043
	<entry>Julian Day (days since January 1, 4712 BC)</entry>
4044 4045
       </row>
       <row>
4046
	<entry><literal>Q</literal></entry>
4047
	<entry>quarter</entry>
4048 4049
       </row>
       <row>
4050
	<entry><literal>RM</literal></entry>
4051
	<entry>month in Roman numerals (I-XII; I=January) (upper case)</entry>
4052 4053
       </row>
       <row>
4054
	<entry><literal>rm</literal></entry>
4055
	<entry>month in Roman numerals (i-xii; i=January) (lower case)</entry>
4056
       </row>
4057
       <row>
4058
	<entry><literal>TZ</literal></entry>
4059
	<entry>time-zone name (upper case)</entry>
4060 4061
       </row>
       <row>
4062
	<entry><literal>tz</literal></entry>
4063
	<entry>time-zone name (lower case)</entry>
4064
       </row>
4065 4066 4067 4068 4069
      </tbody>
     </tgroup>
    </table>

   <para>
4070
    Certain modifiers may be applied to any template pattern to alter its
4071 4072 4073
    behavior.  For example, <literal>FMMonth</literal>
    is the <literal>Month</literal> pattern with the
    <literal>FM</literal> modifier.
4074 4075
    <xref linkend="functions-formatting-datetimemod-table"> shows the
    modifier patterns for date/time formatting.
4076 4077
   </para>

4078
    <table id="functions-formatting-datetimemod-table">
4079
     <title>Template Pattern Modifiers for Date/Time Formatting</title>
4080 4081 4082
     <tgroup cols="3">
      <thead>
       <row>
4083
	<entry>Modifier</entry>
4084 4085 4086 4087 4088 4089
	<entry>Description</entry>
	<entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
4090 4091
	<entry><literal>FM</literal> prefix</entry>
	<entry>fill mode (suppress padding blanks and zeroes)</entry>
4092
	<entry><literal>FMMonth</literal></entry>
4093 4094
       </row>
       <row>
4095
	<entry><literal>TH</literal> suffix</entry>
4096
	<entry>upper-case ordinal number suffix</entry>
4097
	<entry><literal>DDTH</literal></entry>
4098 4099
       </row>	
       <row>
4100
	<entry><literal>th</literal> suffix</entry>
4101
	<entry>lower-case ordinal number suffix</entry>
4102
	<entry><literal>DDth</literal></entry>
4103 4104
       </row>
       <row>
4105
	<entry><literal>FX</literal> prefix</entry>
4106
	<entry>fixed format global option (see usage notes)</entry>
4107
	<entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
4108 4109
       </row>	
       <row>
4110
	<entry><literal>SP</literal> suffix</entry>
4111
	<entry>spell mode (not yet implemented)</entry>
4112
	<entry><literal>DDSP</literal></entry>
4113 4114 4115 4116 4117 4118
       </row>       
      </tbody>
     </tgroup>
    </table>

   <para>
4119
    Usage notes for the date/time formatting:
4120 4121

    <itemizedlist>
4122 4123
     <listitem>
      <para>
4124
       <literal>FM</literal> suppresses leading zeroes and trailing blanks
4125 4126 4127 4128 4129
       that would otherwise be added to make the output of a pattern be
       fixed-width.
      </para>
     </listitem>

4130 4131 4132
     <listitem>
      <para>
       <function>to_timestamp</function> and <function>to_date</function>
4133
       skip multiple blank spaces in the input string if the <literal>FX</literal> option 
4134
       is not used. <literal>FX</literal> must be specified as the first item
4135 4136 4137 4138
       in the template.  For example 
       <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> is correct, but
       <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error,
       because <function>to_timestamp</function> expects one space only.
4139 4140 4141 4142 4143
      </para>
     </listitem>

     <listitem>
      <para>
4144
       Ordinary text is allowed in <function>to_char</function>
4145 4146
       templates and will be output literally.  You can put a substring
       in double quotes to force it to be interpreted as literal text
4147
       even if it contains pattern key words.  For example, in
4148
       <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
4149
       will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
4150
       will not be.
4151 4152 4153 4154 4155
      </para>
     </listitem>

     <listitem>
      <para>
4156 4157 4158
       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 :-) -->
4159 4160
       (Two backslashes are necessary because the backslash already
       has a special meaning in a string constant.)
4161 4162
      </para>
     </listitem>
4163 4164 4165

     <listitem>
      <para>
4166 4167
       The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
       <type>date</type> has a restriction if you use a year with more than 4 digits. You must
Peter Eisentraut's avatar
Peter Eisentraut committed
4168
       use some non-digit character or template after <literal>YYYY</literal>,
4169
       otherwise the year is always interpreted as 4 digits. For example
4170
       (with the year 20000):
Peter Eisentraut's avatar
Peter Eisentraut committed
4171
       <literal>to_date('200001131', 'YYYYMMDD')</literal> will be 
4172
       interpreted as a 4-digit year; instead use a non-digit 
Peter Eisentraut's avatar
Peter Eisentraut committed
4173 4174 4175
       separator after the year, like
       <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
       <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
4176 4177
      </para>
     </listitem>
4178 4179 4180

     <listitem>
      <para>
4181 4182
       Millisecond (<literal>MS</literal>) and microsecond (<literal>US</literal>)
       values in a conversion from string to <type>timestamp</type> are used as part of the
Peter Eisentraut's avatar
Peter Eisentraut committed
4183
       seconds after the decimal point. For example 
4184
       <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
4185
       but 300, because the conversion counts it as 12 + 0.3 seconds.
4186 4187
       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
4188
       same number of milliseconds. To get three milliseconds, one must use
4189
       <literal>12:003</literal>, which the conversion counts as
Peter Eisentraut's avatar
Peter Eisentraut committed
4190 4191 4192 4193 4194
       12 + 0.003 = 12.003 seconds.
      </para>

      <para>
       Here is a more 
4195
       complex example: 
4196
       <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
Peter Eisentraut's avatar
Peter Eisentraut committed
4197 4198
       is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
       1230 microseconds = 2.021230 seconds. 
4199 4200
      </para>
     </listitem>
4201
    </itemizedlist>
4202
   </para>
4203

4204 4205 4206 4207 4208 4209
  <para>
   <xref linkend="functions-formatting-numeric-table"> shows the
   template patterns available for formatting numeric values.
  </para>

    <table id="functions-formatting-numeric-table">
4210
     <title>Template Patterns for Numeric Formatting</title>
4211 4212 4213
     <tgroup cols="2">
      <thead>
       <row>
4214
	<entry>Pattern</entry>
4215 4216 4217 4218 4219
	<entry>Description</entry>
       </row>
      </thead>
      <tbody>
       <row>
4220
	<entry><literal>9</literal></entry>
4221
	<entry>value with the specified number of digits</entry>
4222 4223
       </row>
       <row>
4224
	<entry><literal>0</literal></entry>
4225
	<entry>value with leading zeros</entry>
4226 4227
       </row>
       <row>
4228
	<entry><literal>.</literal> (period)</entry>
4229
	<entry>decimal point</entry>
4230 4231
       </row>       
       <row>
4232
	<entry><literal>,</literal> (comma)</entry>
4233
	<entry>group (thousand) separator</entry>
4234 4235
       </row>
       <row>
4236
	<entry><literal>PR</literal></entry>
4237
	<entry>negative value in angle brackets</entry>
4238 4239
       </row>
       <row>
4240
	<entry><literal>S</literal></entry>
4241
	<entry>sign anchored to number (uses locale)</entry>
4242 4243
       </row>
       <row>
4244
	<entry><literal>L</literal></entry>
4245
	<entry>currency symbol (uses locale)</entry>
4246 4247
       </row>
       <row>
4248
	<entry><literal>D</literal></entry>
4249
	<entry>decimal point (uses locale)</entry>
4250 4251
       </row>
       <row>
4252
	<entry><literal>G</literal></entry>
4253
	<entry>group separator (uses locale)</entry>
4254 4255
       </row>
       <row>
4256
	<entry><literal>MI</literal></entry>
4257
	<entry>minus sign in specified position (if number &lt; 0)</entry>
4258 4259
       </row>
       <row>
4260
	<entry><literal>PL</literal></entry>
4261
	<entry>plus sign in specified position (if number &gt; 0)</entry>
4262 4263
       </row>
       <row>
4264
	<entry><literal>SG</literal></entry>
4265
	<entry>plus/minus sign in specified position</entry>
4266 4267
       </row>
       <row>
4268
	<entry><literal>RN</literal></entry>
4269
	<entry>roman numeral (input between 1 and 3999)</entry>
4270 4271
       </row>
       <row>
4272
	<entry><literal>TH</literal> or <literal>th</literal></entry>
4273
	<entry>ordinal number suffix</entry>
4274 4275
       </row>
       <row>
4276
	<entry><literal>V</literal></entry>
4277
	<entry>shift specified number of digits (see notes)</entry>
4278 4279
       </row>
       <row>
4280
	<entry><literal>EEEE</literal></entry>
Peter Eisentraut's avatar
Peter Eisentraut committed
4281
	<entry>scientific notation (not implemented yet)</entry>
4282 4283 4284 4285 4286 4287
       </row>
      </tbody>
     </tgroup>
    </table>

   <para>
4288
    Usage notes for the numeric formatting:
4289 4290 4291 4292

    <itemizedlist>
     <listitem>
      <para>
4293
       A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
4294
       <literal>MI</literal> is not anchored to
4295
       the number; for example,
4296 4297
       <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>,
       but <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>.
4298 4299
       The Oracle implementation does not allow the use of
       <literal>MI</literal> ahead of <literal>9</literal>, but rather
4300
       requires that <literal>9</literal> precede
4301 4302 4303 4304 4305 4306
       <literal>MI</literal>.
      </para>
     </listitem>

     <listitem>
      <para>
4307
       <literal>9</literal> results in a value with the same number of 
4308
       digits as there are <literal>9</literal>s. If a digit is
4309
       not available it outputs a space.
4310 4311 4312 4313 4314
      </para>
     </listitem>

     <listitem>
      <para>
4315
       <literal>TH</literal> does not convert values less than zero
4316
       and does not convert fractional numbers.
4317 4318 4319 4320 4321
      </para>
     </listitem>

     <listitem>
      <para>
4322
       <literal>PL</literal>, <literal>SG</literal>, and
4323
       <literal>TH</literal> are <productname>PostgreSQL</productname>
4324
       extensions. 
4325 4326 4327 4328 4329 4330 4331 4332 4333 4334 4335
      </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
4336 4337
       <literal>V</literal> combined with a decimal point.
       (E.g., <literal>99.9V99</literal> is not allowed.)
4338 4339 4340
      </para>
     </listitem>
    </itemizedlist>
4341
   </para>   
4342

4343 4344 4345 4346 4347 4348
  <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">
4349
     <title><function>to_char</function> Examples</title>
4350 4351 4352
     <tgroup cols="2">
      <thead>
       <row>
4353 4354
	<entry>Expression</entry>
	<entry>Result</entry>
4355 4356 4357 4358
       </row>
      </thead>
      <tbody>
       <row>
4359 4360
        <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
        <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
4361
       </row>
4362
       <row>
4363 4364
        <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
        <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
4365 4366
       </row>          
       <row>
4367
        <entry><literal>to_char(-0.1, '99.99')</literal></entry>
Bruce Momjian's avatar
Bruce Momjian committed
4368
        <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
4369 4370
       </row>
       <row>
4371
        <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
4372
        <entry><literal>'-.1'</literal></entry>
4373 4374
       </row>
       <row>
4375 4376
        <entry><literal>to_char(0.1, '0.9')</literal></entry>
        <entry><literal>'&nbsp;0.1'</literal></entry>
4377 4378
       </row>
       <row>
4379 4380
        <entry><literal>to_char(12, '9990999.9')</literal></entry>
        <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
4381 4382
       </row>
       <row>
4383
        <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
Bruce Momjian's avatar
Bruce Momjian committed
4384
        <entry><literal>'0012.'</literal></entry>
4385 4386
       </row>
       <row>
4387 4388
        <entry><literal>to_char(485, '999')</literal></entry>
        <entry><literal>'&nbsp;485'</literal></entry>
4389 4390
       </row>
       <row>
4391
        <entry><literal>to_char(-485, '999')</literal></entry>
4392
        <entry><literal>'-485'</literal></entry>
4393 4394
       </row>
       <row>
4395 4396
        <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
        <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
4397 4398
       </row>
       <row>
4399 4400
        <entry><literal>to_char(1485, '9,999')</literal></entry>
        <entry><literal>'&nbsp;1,485'</literal></entry>
4401 4402
       </row>
       <row>
4403 4404
        <entry><literal>to_char(1485, '9G999')</literal></entry>
        <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
4405 4406
       </row>
       <row>
4407
        <entry><literal>to_char(148.5, '999.999')</literal></entry>
Bruce Momjian's avatar
Bruce Momjian committed
4408
        <entry><literal>'&nbsp;148.500'</literal></entry>
4409
       </row>
Bruce Momjian's avatar
Bruce Momjian committed
4410 4411 4412 4413 4414 4415 4416 4417
       <row>
        <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
        <entry><literal>'148.5'</literal></entry>
       </row>
       <row>
        <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
        <entry><literal>'148.500'</literal></entry>
       </row>
4418
       <row>
4419 4420
        <entry><literal>to_char(148.5, '999D999')</literal></entry>
        <entry><literal>'&nbsp;148,500'</literal></entry>	 
4421 4422
       </row>
       <row>
4423 4424
        <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
        <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
4425 4426
       </row>
       <row>
4427
        <entry><literal>to_char(-485, '999S')</literal></entry>
4428
        <entry><literal>'485-'</literal></entry>
4429 4430
       </row>
       <row>		
4431
        <entry><literal>to_char(-485, '999MI')</literal></entry>
4432
        <entry><literal>'485-'</literal></entry>	
4433 4434
       </row>
       <row>
4435
        <entry><literal>to_char(485, '999MI')</literal></entry>
Bruce Momjian's avatar
Bruce Momjian committed
4436 4437 4438 4439
        <entry><literal>'485&nbsp;'</literal></entry>		
       </row>
       <row>
        <entry><literal>to_char(485, 'FM999MI')</literal></entry>
4440
        <entry><literal>'485'</literal></entry>		
4441 4442
       </row>
       <row>
4443
        <entry><literal>to_char(485, 'PL999')</literal></entry>
4444
        <entry><literal>'+485'</literal></entry>	
4445 4446
       </row>
       <row>		
4447
        <entry><literal>to_char(485, 'SG999')</literal></entry>
4448
        <entry><literal>'+485'</literal></entry>	
4449 4450
       </row>
       <row>
4451
        <entry><literal>to_char(-485, 'SG999')</literal></entry>
4452
        <entry><literal>'-485'</literal></entry>	
4453 4454
       </row>
       <row>
4455
        <entry><literal>to_char(-485, '9SG99')</literal></entry>
4456
        <entry><literal>'4-85'</literal></entry>	
4457 4458
       </row>
       <row>
4459
        <entry><literal>to_char(-485, '999PR')</literal></entry>
4460
        <entry><literal>'&lt;485&gt;'</literal></entry>		
4461 4462
       </row>
       <row>
4463 4464
        <entry><literal>to_char(485, 'L999')</literal></entry>
        <entry><literal>'DM&nbsp;485</literal></entry>	 
4465 4466
       </row>
       <row>
4467 4468
        <entry><literal>to_char(485, 'RN')</literal></entry>		
        <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
4469 4470
       </row>
       <row>
4471
        <entry><literal>to_char(485, 'FMRN')</literal></entry>	
4472
        <entry><literal>'CDLXXXV'</literal></entry>
4473 4474
       </row>
       <row>
4475 4476
        <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
        <entry><literal>'V'</literal></entry>		
4477 4478
       </row>
       <row>
4479 4480
        <entry><literal>to_char(482, '999th')</literal></entry>
        <entry><literal>'&nbsp;482nd'</literal></entry>				
4481 4482
       </row>
       <row>
4483 4484
        <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
        <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
4485 4486
       </row>
       <row>
4487 4488
        <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
        <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
4489 4490
       </row>
       <row>
4491 4492
        <entry><literal>to_char(12, '99V999')</literal></entry>		
        <entry><literal>'&nbsp;12000'</literal></entry>
4493 4494
       </row>
       <row>
4495 4496
        <entry><literal>to_char(12.4, '99V999')</literal></entry>
        <entry><literal>'&nbsp;12400'</literal></entry>
4497 4498
       </row>
       <row>		
4499
        <entry><literal>to_char(12.45, '99V9')</literal></entry>
4500
        <entry><literal>'&nbsp;125'</literal></entry>
4501 4502 4503 4504
       </row>
      </tbody>
     </tgroup>
    </table>
4505

4506 4507 4508
  </sect1>


4509
  <sect1 id="functions-datetime">
4510
   <title>Date/Time Functions and Operators</title>
4511

4512 4513 4514 4515 4516 4517 4518 4519
  <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
4520 4521
   the background information on date/time data types from <xref
   linkend="datatype-datetime">.
4522 4523 4524
  </para>

  <para>
4525 4526 4527
   All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
   inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
   with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
4528
   For brevity, these variants are not shown separately.
4529
  </para>
4530 4531 4532 4533

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

4534
     <tgroup cols="3">
4535 4536
      <thead>
       <row>
4537
        <entry>Operator</entry>
4538 4539 4540 4541 4542 4543 4544
        <entry>Example</entry>
        <entry>Result</entry>
       </row>
      </thead>

      <tbody>
       <row>
4545
        <entry> <literal>+</literal> </entry>
4546 4547
        <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
        <entry><literal>timestamp '2001-09-29 00:00'</literal></entry>
4548 4549 4550
       </row>

       <row>
4551
        <entry> <literal>+</literal> </entry>
4552 4553
        <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
        <entry><literal>timestamp '2001-09-28 01:00'</literal></entry>
4554 4555 4556
       </row>

       <row>
4557
        <entry> <literal>+</literal> </entry>
4558 4559
        <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
        <entry><literal>time '04:00'</literal></entry>
4560 4561 4562
       </row>

       <row>
4563
        <entry> <literal>-</literal> </entry>
4564 4565
        <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
        <entry><literal>timestamp '2001-09-28'</literal></entry>
4566 4567 4568
       </row>

       <row>
4569
        <entry> <literal>-</literal> </entry>
4570 4571
        <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
        <entry><literal>timestamp '2001-09-27 23:00'</literal></entry>
4572 4573 4574
       </row>

       <row>
4575
        <entry> <literal>-</literal> </entry>
4576 4577
        <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
        <entry><literal>time '03:00'</literal></entry>
4578 4579 4580
       </row>

       <row>
4581
        <entry> <literal>-</literal> </entry>
4582 4583
        <entry><literal>interval '2 hours' - time '05:00'</literal></entry>
        <entry><literal>time '03:00:00'</literal></entry>
4584 4585 4586 4587
       </row>

       <row>
        <entry> <literal>*</literal> </entry>
4588 4589
        <entry><literal>interval '1 hour' * int '3'</literal></entry>
        <entry><literal>interval '03:00'</literal></entry>
4590 4591 4592 4593
       </row>

       <row>
        <entry> <literal>/</literal> </entry>
4594 4595
        <entry><literal>interval '1 hour' / int '3'</literal></entry>
        <entry><literal>interval '00:20'</literal></entry>
4596 4597 4598 4599 4600
       </row>
      </tbody>
     </tgroup>
    </table>

4601
    <table id="functions-datetime-table">
4602
     <title>Date/Time Functions</title>
4603
     <tgroup cols="5">
4604 4605
      <thead>
       <row>
4606
	<entry>Function</entry>
4607
	<entry>Return Type</entry>
4608 4609
	<entry>Description</entry>
	<entry>Example</entry>
4610
	<entry>Result</entry>
4611 4612
       </row>
      </thead>
4613

4614 4615
      <tbody>
       <row>
4616
	<entry><literal><function>age</function>(<type>timestamp</type>)</literal></entry>
4617
	<entry><type>interval</type></entry>
4618
	<entry>Subtract from today</entry>
4619 4620
	<entry><literal>age(timestamp '1957-06-13')</literal></entry>
	<entry><literal>43 years 8 mons 3 days</literal></entry>
4621
       </row>
4622

4623
       <row>
4624
	<entry><literal><function>age</function>(<type>timestamp</type>, <type>timestamp</type>)</literal></entry>
4625
	<entry><type>interval</type></entry>
4626
	<entry>Subtract arguments</entry>
4627 4628
	<entry><literal>age('2001-04-10', timestamp '1957-06-13')</literal></entry>
	<entry><literal>43 years 9 mons 27 days</literal></entry>
4629 4630 4631
       </row>

       <row>
4632
	<entry><literal><function>current_date</function></literal></entry>
4633
	<entry><type>date</type></entry>
4634
	<entry>Today's date; see <xref linkend="functions-datetime-current">
4635 4636 4637
	</entry>
	<entry></entry>
	<entry></entry>
4638
       </row>
4639 4640

       <row>
4641
        <entry><literal><function>current_time</function></literal></entry>
4642
        <entry><type>time with time zone</type></entry>
4643
        <entry>Time of day; see <xref linkend="functions-datetime-current">
4644 4645 4646
        </entry>
        <entry></entry>
        <entry></entry>
4647 4648
       </row>

4649
       <row>
4650
	<entry><literal><function>current_timestamp</function></literal></entry>
4651
	<entry><type>timestamp with time zone</type></entry>
4652
	<entry>Date and time; see <xref linkend="functions-datetime-current">
4653 4654 4655 4656 4657 4658
	</entry>
	<entry></entry>
	<entry></entry>
       </row>

       <row>
4659
	<entry><literal><function>date_part</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
4660
	<entry><type>double precision</type></entry>
4661
	<entry>Get subfield (equivalent to
4662
	 <function>extract</function>); see <xref linkend="functions-datetime-extract">
4663
        </entry>
4664 4665
	<entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
	<entry><literal>20</literal></entry>
4666
       </row>
4667

4668
       <row>
4669
	<entry><literal><function>date_part</function>(<type>text</type>, <type>interval</type>)</literal></entry>
4670
	<entry><type>double precision</type></entry>
4671
	<entry>Get subfield (equivalent to
4672
	 <function>extract</function>); see <xref linkend="functions-datetime-extract">
4673
        </entry>
4674 4675
	<entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
	<entry><literal>3</literal></entry>
4676
       </row>
4677

4678
       <row>
4679
	<entry><literal><function>date_trunc</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
4680
	<entry><type>timestamp</type></entry>
4681 4682
	<entry>Truncate to specified precision; see also <xref
                                                        linkend="functions-datetime-trunc">
4683
        </entry>
4684 4685
	<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>
4686
       </row>
4687

4688
       <row>
4689 4690
	<entry><literal><function>extract</function>(<parameter>field</parameter> from
         <type>timestamp</type>)</literal></entry>
4691
	<entry><type>double precision</type></entry>
4692
	<entry>Get subfield; see <xref linkend="functions-datetime-extract">
4693
        </entry>
4694 4695
	<entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
	<entry><literal>20</literal></entry>
4696
       </row>
4697 4698

       <row>
4699 4700
	<entry><literal><function>extract</function>(<parameter>field</parameter> from
         <type>interval</type>)</literal></entry>
4701
	<entry><type>double precision</type></entry>
4702
	<entry>Get subfield; see <xref linkend="functions-datetime-extract">
4703
        </entry>
4704 4705
	<entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
	<entry><literal>3</literal></entry>
4706 4707
       </row>

4708
       <row>
4709
	<entry><literal><function>isfinite</function>(<type>timestamp</type>)</literal></entry>
4710
	<entry><type>boolean</type></entry>
4711
	<entry>Test for finite time stamp (not equal to infinity)</entry>
4712 4713
	<entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
	<entry><literal>true</literal></entry>
4714
       </row>
4715

4716
       <row>
4717
	<entry><literal><function>isfinite</function>(<type>interval</type>)</literal></entry>
4718
	<entry><type>boolean</type></entry>
4719
	<entry>Test for finite interval</entry>
4720 4721
	<entry><literal>isfinite(interval '4 hours')</literal></entry>
	<entry><literal>true</literal></entry>
4722
       </row>
4723

4724
       <row>
4725
        <entry><literal><function>localtime</function></literal></entry>
4726
        <entry><type>time</type></entry>
4727
        <entry>Time of day; see <xref linkend="functions-datetime-current">
4728 4729 4730 4731 4732 4733
        </entry>
        <entry></entry>
        <entry></entry>
       </row>

       <row>
4734
        <entry><literal><function>localtimestamp</function></literal></entry>
4735
        <entry><type>timestamp</type></entry>
4736
        <entry>Date and time; see <xref linkend="functions-datetime-current">
4737 4738 4739 4740 4741
        </entry>
        <entry></entry>
        <entry></entry>
       </row>

4742
       <row>
4743
	<entry><literal><function>now</function>()</literal></entry>
4744
	<entry><type>timestamp with time zone</type></entry>
4745
	<entry>Current date and time (equivalent to
4746 4747
	 <function>current_timestamp</function>); see <xref
                                                     linkend="functions-datetime-current">
4748 4749 4750
	</entry>
	<entry></entry>
	<entry></entry>
4751
       </row>
4752

4753
       <row>
4754
	<entry><literal><function>timeofday()</function></literal></entry>
4755
	<entry><type>text</type></entry>
4756 4757
	<entry>Current date and time; see <xref
                                         linkend="functions-datetime-current">
4758
	</entry>
4759 4760
	<entry><literal>timeofday()</literal></entry>
	<entry><literal>Wed Feb 21 17:01:13.000126 2001 EST</literal></entry>
4761 4762
       </row>

4763 4764 4765
      </tbody>
     </tgroup>
    </table>
4766 4767 4768 4769 4770 4771 4772 4773 4774

  <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>
4775
    The <function>extract</function> function retrieves subfields
4776 4777 4778 4779 4780
    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
4781 4782
    well.)  <replaceable>field</replaceable> is an identifier or
    string that selects what field to extract from the source value.
4783 4784
    The <function>extract</function> function returns values of type
    <type>double precision</type>.
4785
    The following are valid field names:
4786 4787 4788 4789

    <!-- alphabetical -->
    <variablelist>
     <varlistentry>
4790
      <term><literal>century</literal></term>
4791 4792 4793 4794 4795 4796 4797 4798 4799 4800 4801
      <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>
4802 4803 4804
        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.
4805 4806 4807 4808 4809
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
4810
      <term><literal>day</literal></term>
4811 4812 4813 4814 4815 4816 4817 4818 4819 4820 4821 4822 4823
      <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>
4824
      <term><literal>decade</literal></term>
4825 4826 4827 4828 4829 4830 4831 4832 4833 4834 4835 4836 4837
      <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>
4838
      <term><literal>dow</literal></term>
4839 4840 4841 4842 4843 4844 4845 4846 4847 4848 4849 4850 4851 4852
      <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>
4853
      <term><literal>doy</literal></term>
4854 4855 4856 4857
      <listitem>
       <para>
        The day of the year (1 - 365/366) (for <type>timestamp</type> values only)
       </para>
4858

4859 4860 4861 4862 4863 4864 4865 4866
<screen>
SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
<lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
</screen>
      </listitem>
     </varlistentry>

     <varlistentry>
4867
      <term><literal>epoch</literal></term>
4868 4869 4870
      <listitem>
       <para>
        For <type>date</type> and <type>timestamp</type> values, the
4871 4872
        number of seconds since 1970-01-01 00:00:00-00 (can be negative);
	for <type>interval</type> values, the total number
4873 4874 4875 4876 4877 4878 4879 4880 4881 4882 4883 4884 4885 4886
        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>
4887
      <term><literal>hour</literal></term>
4888 4889 4890 4891 4892 4893 4894 4895 4896 4897 4898 4899 4900
      <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>
4901
      <term><literal>microseconds</literal></term>
4902 4903 4904 4905 4906 4907 4908 4909 4910 4911 4912 4913 4914 4915
      <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>
4916
      <term><literal>millennium</literal></term>
4917 4918 4919 4920 4921 4922 4923 4924 4925 4926 4927
      <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>
4928 4929 4930
        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.
4931 4932 4933 4934 4935
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
4936
      <term><literal>milliseconds</literal></term>
4937 4938 4939 4940 4941 4942 4943 4944 4945 4946 4947 4948 4949 4950
      <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>
4951
      <term><literal>minute</literal></term>
4952 4953 4954 4955 4956 4957 4958 4959 4960 4961 4962 4963 4964
      <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>
4965
      <term><literal>month</literal></term>
4966 4967 4968 4969 4970 4971 4972 4973 4974 4975 4976 4977 4978 4979 4980 4981 4982 4983 4984 4985 4986
      <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>
4987
      <term><literal>quarter</literal></term>
4988 4989 4990 4991 4992 4993 4994 4995 4996 4997 4998 4999 5000 5001
      <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>
5002
      <term><literal>second</literal></term>
5003 5004 5005 5006 5007 5008 5009 5010 5011 5012 5013 5014 5015 5016 5017 5018
      <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>
5019 5020 5021 5022
     <varlistentry>
      <term><literal>timezone</literal></term>
      <listitem>
       <para>
5023 5024 5025
        The time zone offset from UTC, measured in seconds.  Positive values
	correspond to time zones east of UTC, negative values to
	zones west of UTC.
5026 5027 5028 5029 5030 5031 5032 5033
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>timezone_hour</literal></term>
      <listitem>
       <para>
5034
        The hour component of the time zone offset
5035 5036 5037 5038 5039 5040 5041 5042
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term><literal>timezone_minute</literal></term>
      <listitem>
       <para>
5043
        The minute component of the time zone offset
5044 5045 5046
       </para>
      </listitem>
     </varlistentry>
5047 5048

     <varlistentry>
5049
      <term><literal>week</literal></term>
5050 5051
      <listitem>
       <para>
5052
        The number of
5053 5054
        the week of the year that the day is in.  By definition
        (<acronym>ISO</acronym> 8601), the first week of a year
5055
        contains January 4 of that year.  (The <acronym>ISO</acronym>-8601
5056
        week starts on Monday.)  In other words, the first Thursday of
5057
        a year is in week 1 of that year. (for <type>timestamp</type> values only)
5058 5059 5060 5061 5062 5063 5064 5065 5066 5067
       </para>

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

     <varlistentry>
5068
      <term><literal>year</literal></term>
5069 5070 5071 5072 5073 5074 5075 5076 5077 5078 5079 5080 5081 5082
      <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>

5083 5084 5085
   </para>

   <para>
5086 5087 5088
    The <function>extract</function> function is primarily intended
    for computational processing.  For formatting date/time values for
    display, see <xref linkend="functions-formatting">.
5089
   </para>
5090 5091

   <para>
5092 5093
    The <function>date_part</function> function is modeled on the traditional
    <productname>Ingres</productname> equivalent to the
5094
    <acronym>SQL</acronym>-standard function <function>extract</function>:
5095 5096 5097
<synopsis>
date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
</synopsis>
5098
    Note that here the <replaceable>field</replaceable> parameter needs to
5099
    be a string value, not a name.  The valid field names for
5100 5101 5102 5103 5104 5105 5106 5107
    <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
5108
SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
5109 5110 5111 5112 5113 5114 5115 5116 5117 5118 5119 5120 5121 5122 5123 5124 5125 5126
<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
5127 5128
    <type>timestamp</type>.  (Values of type <type>date</type> and
    <type>time</type> are cast automatically.)
5129 5130 5131 5132 5133 5134 5135 5136 5137
    <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>
5138 5139 5140 5141 5142 5143 5144 5145 5146 5147 5148
     <member><literal>microseconds</literal></member>
     <member><literal>milliseconds</literal></member>
     <member><literal>second</literal></member>
     <member><literal>minute</literal></member>
     <member><literal>hour</literal></member>
     <member><literal>day</literal></member>
     <member><literal>month</literal></member>
     <member><literal>year</literal></member>
     <member><literal>decade</literal></member>
     <member><literal>century</literal></member>
     <member><literal>millennium</literal></member>
5149 5150 5151
    </simplelist>
   </para>

5152 5153
   <para>
    Examples:
5154 5155 5156 5157 5158 5159 5160
<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>
5161
   </para>
5162 5163
  </sect2>

5164
  <sect2 id="functions-datetime-zoneconvert">
5165
   <title><literal>AT TIME ZONE</literal></title>
5166 5167

   <indexterm>
5168
    <primary>time zone</primary>
5169 5170 5171 5172
    <secondary>conversion</secondary>
   </indexterm>

   <para>
5173 5174 5175 5176
    The <literal>AT TIME ZONE</literal> construct allows conversions
    of time stamps to different time zones.  <xref
    linkend="functions-datetime-zoneconvert-table"> shows its
    variants.
5177 5178 5179
   </para>

    <table id="functions-datetime-zoneconvert-table">
5180
     <title><literal>AT TIME ZONE</literal> Variants</title>
5181 5182 5183 5184
     <tgroup cols="3">
      <thead>
       <row>
	<entry>Expression</entry>
5185
	<entry>Return Type</entry>
5186 5187 5188 5189 5190 5191 5192
	<entry>Description</entry>
       </row>
      </thead>

      <tbody>
       <row>
	<entry>
5193
	 <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
5194 5195
	</entry>
	<entry><type>timestamp with time zone</type></entry>
5196
	<entry>Convert local time in given time zone to UTC</entry>
5197 5198 5199 5200
       </row>

       <row>
	<entry>
5201
	 <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
5202 5203
	</entry>
	<entry><type>timestamp without time zone</type></entry>
5204
	<entry>Convert UTC to local time in given time zone</entry>
5205 5206 5207 5208
       </row>

       <row>
	<entry>
5209
	 <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
5210 5211
	</entry>
	<entry><type>time with time zone</type></entry>
5212
	<entry>Convert local time across time zones</entry>
5213 5214 5215 5216 5217 5218
       </row>
      </tbody>
     </tgroup>
    </table>

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

   <para>
5225
    Examples (supposing that the local time zone is <literal>PST8PDT</>):
5226 5227 5228 5229 5230 5231 5232
<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>
5233 5234 5235 5236
    The first example takes a zone-less time stamp and interprets it as MST time
    (UTC-7) to produce a UTC time stamp, which is then rotated to PST (UTC-8)
    for display.  The second example takes a time stamp specified in EST
    (UTC-5) and converts it to local time in MST (UTC-7).
5237 5238 5239
   </para>

   <para>
5240 5241 5242 5243
    The function <literal><function>timezone</function>(<replaceable>zone</>,
    <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
    <literal><replaceable>timestamp</> AT TIME ZONE
    <replaceable>zone</></literal>. 
5244 5245 5246
   </para>
  </sect2>

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

5250 5251 5252 5253 5254 5255 5256 5257 5258 5259
   <indexterm>
    <primary>date</primary>
    <secondary>current</secondary>
   </indexterm>

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

5260
   <para>
5261 5262
    The following functions are available to obtain the current date and/or
    time:
5263
<synopsis>
5264
CURRENT_DATE
5265
CURRENT_TIME
5266
CURRENT_TIMESTAMP
5267 5268
CURRENT_TIME ( <replaceable>precision</replaceable> )
CURRENT_TIMESTAMP ( <replaceable>precision</replaceable> )
5269 5270 5271 5272
LOCALTIME
LOCALTIMESTAMP
LOCALTIME ( <replaceable>precision</replaceable> )
LOCALTIMESTAMP ( <replaceable>precision</replaceable> )
5273
</synopsis>
5274 5275 5276 5277 5278 5279 5280 5281 5282 5283
    </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>
5284 5285 5286 5287 5288 5289
     <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
5290
     to that many fractional digits in the seconds field.  Without a precision parameter,
5291
     the result is given to the full available precision.
5292 5293
    </para>

5294 5295 5296 5297 5298 5299 5300
    <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>
5301

5302 5303 5304
   <para>
    Some examples:
<screen>
5305
SELECT CURRENT_TIME;
5306
<lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
5307 5308

SELECT CURRENT_DATE;
5309
<lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
5310 5311

SELECT CURRENT_TIMESTAMP;
5312
<lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
5313 5314

SELECT CURRENT_TIMESTAMP(2);
5315
<lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
5316 5317

SELECT LOCALTIMESTAMP;
5318
<lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
5319
</screen>
5320
   </para>
5321 5322 5323

   <para>
    The function <function>now()</function> is the traditional
5324
    <productname>PostgreSQL</productname> equivalent to
5325
    <function>CURRENT_TIMESTAMP</function>.
5326 5327 5328
   </para>

   <para>
5329
    There is also the function <function>timeofday()</function>, which for historical
5330
    reasons returns a <type>text</type> string rather than a <type>timestamp</type> value:
5331 5332
<screen>
SELECT timeofday();
5333
<lineannotation>Result: </lineannotation><computeroutput>Sat Feb 17 19:07:32.000126 2001 EST</computeroutput>
5334
</screen>
5335
   </para>
5336 5337

   <para>
5338
    It is important to know that
5339 5340
    <function>CURRENT_TIMESTAMP</function> and related functions return
    the start time of the current transaction; their values do not
5341 5342 5343 5344 5345
    change during the transaction. This is considered a feature:
    the intent is to allow a single transaction to have a consistent
    notion of the <quote>current</quote> time, so that multiple
    modifications within the same transaction bear the same
    timestamp. <function>timeofday()</function>
5346
    returns the wall-clock time and does advance during transactions.
5347 5348
   </para>

Bruce Momjian's avatar
Bruce Momjian committed
5349
   <note>
5350 5351
    <para>
     Other database systems may advance these values more
Bruce Momjian's avatar
Bruce Momjian committed
5352 5353
     frequently.
    </para>
5354 5355
   </note>

5356
   <para>
5357
    All the date/time data types also accept the special literal value
5358
    <literal>now</literal> to specify the current date and time.  Thus,
5359
    the following three all return the same result:
5360 5361 5362 5363 5364
<programlisting>
SELECT CURRENT_TIMESTAMP;
SELECT now();
SELECT TIMESTAMP 'now';
</programlisting>
5365 5366
   </para>

5367 5368
    <note>
     <para>
5369 5370
      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>
5371
      to a <type>timestamp</type> as soon as the constant is parsed, so that when
5372
      the default value is needed,
5373 5374
      the time of the table creation would be used!  The first two
      forms will not be evaluated until the default value is used,
5375 5376
      because they are function calls.  Thus they will give the desired
      behavior of defaulting to the time of row insertion.
5377 5378 5379 5380
     </para>
    </note>
  </sect2>
 </sect1>
5381 5382 5383

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

   <para>
5387 5388 5389
    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
5390 5391 5392 5393
    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">.
5394 5395
   </para>

5396
   <table id="functions-geometry-op-table">
5397 5398 5399 5400 5401 5402
     <title>Geometric Operators</title>
     <tgroup cols="3">
      <thead>
       <row>
	<entry>Operator</entry>
	<entry>Description</entry>
5403
	<entry>Example</entry>
5404 5405 5406 5407
       </row>
      </thead>
      <tbody>
       <row>
5408
	<entry> <literal>+</literal> </entry>
5409 5410 5411 5412
	<entry>Translation</entry>
	<entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
       </row>
       <row>
5413
	<entry> <literal>-</literal> </entry>
5414 5415 5416 5417
	<entry>Translation</entry>
	<entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
       </row>
       <row>
5418
	<entry> <literal>*</literal> </entry>
5419 5420 5421 5422
	<entry>Scaling/rotation</entry>
	<entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
       </row>
       <row>
5423
	<entry> <literal>/</literal> </entry>
5424 5425 5426 5427
	<entry>Scaling/rotation</entry>
	<entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
       </row>
       <row>
5428 5429
	<entry> <literal>#</literal> </entry>
	<entry>Point or box of intersection</entry>
5430 5431 5432
	<entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
       </row>
       <row>
5433
	<entry> <literal>#</literal> </entry>
5434
	<entry>Number of points in path or polygon</entry>
5435 5436
	<entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
       </row>
5437
       <row>
5438
	<entry> <literal>@-@</literal> </entry>
5439 5440 5441 5442
	<entry>Length or circumference</entry>
	<entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
       </row>
       <row>
5443 5444
	<entry> <literal>@@</literal> </entry>
	<entry>Center</entry>
5445 5446
	<entry><literal>@@ circle '((0,0),10)'</literal></entry>
       </row>
5447
       <row>
5448 5449
	<entry> <literal>##</literal> </entry>
	<entry>Closest point to first operand on second operand</entry>
5450 5451
	<entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
       </row>
5452
       <row>
5453
	<entry> <literal>&lt;-&gt;</literal> </entry>
5454 5455 5456
	<entry>Distance between</entry>
	<entry><literal>circle '((0,0),1)' &lt;-&gt; circle '((5,0),1)'</literal></entry>
       </row>
5457
       <row>
5458
	<entry> <literal>&amp;&amp;</literal> </entry>
5459 5460 5461 5462
	<entry>Overlaps?</entry>
	<entry><literal>box '((0,0),(1,1))' &amp;&amp; box '((0,0),(2,2))'</literal></entry>
       </row>
       <row>
5463
	<entry> <literal>&amp;&lt;</literal> </entry>
5464
	<entry>Overlaps or is left of?</entry>
5465 5466 5467
	<entry><literal>box '((0,0),(1,1))' &amp;&lt; box '((0,0),(2,2))'</literal></entry>
       </row>
       <row>
5468
	<entry> <literal>&amp;&gt;</literal> </entry>
5469
	<entry>Overlaps or is right of?</entry>
5470 5471 5472
	<entry><literal>box '((0,0),(3,3))' &amp;&gt; box '((0,0),(2,2))'</literal></entry>
       </row>
       <row>
5473 5474
	<entry> <literal>&lt;&lt;</literal> </entry>
	<entry>Is left of?</entry>
5475 5476 5477
	<entry><literal>circle '((0,0),1)' &lt;&lt; circle '((5,0),1)'</literal></entry>
       </row>
       <row>
5478 5479
	<entry> <literal>&gt;&gt;</literal> </entry>
	<entry>Is right of?</entry>
5480 5481
	<entry><literal>circle '((5,0),1)' &gt;&gt; circle '((0,0),1)'</literal></entry>
       </row>
5482
       <row>
5483 5484
	<entry> <literal>&lt;^</literal> </entry>
	<entry>Is below?</entry>
5485 5486
	<entry><literal>circle '((0,0),1)' &lt;^ circle '((0,5),1)'</literal></entry>
       </row>
5487
       <row>
5488 5489
	<entry> <literal>&gt;^</literal> </entry>
	<entry>Is above?</entry>
5490 5491 5492
	<entry><literal>circle '((0,5),1)' >^ circle '((0,0),1)'</literal></entry>
       </row>
       <row>
5493 5494
	<entry> <literal>?#</literal> </entry>
	<entry>Intersects?</entry>
5495 5496 5497
	<entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
       </row>
       <row>
5498 5499
	<entry> <literal>?-</literal> </entry>
	<entry>Is horizontal?</entry>
5500
	<entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
5501 5502
       </row>
       <row>
5503 5504
	<entry> <literal>?-</literal> </entry>
	<entry>Are horizontally aligned?</entry>
5505
	<entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
5506 5507
       </row>
       <row>
5508 5509
	<entry> <literal>?|</literal> </entry>
	<entry>Is vertical?</entry>
5510
	<entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
5511 5512
       </row>
       <row>
5513 5514
	<entry> <literal>?|</literal> </entry>
	<entry>Are vertically aligned?</entry>
5515 5516
	<entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
       </row>
5517
       <row>
5518 5519
	<entry> <literal>?-|</literal> </entry>
	<entry>Is perpendicular?</entry>
5520 5521
	<entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
       </row>
5522
       <row>
5523 5524
	<entry> <literal>?||</literal> </entry>
	<entry>Are parallel?</entry>
5525 5526 5527
	<entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
       </row>
       <row>
5528
	<entry> <literal>~</literal> </entry>
5529 5530
	<entry>Contains?</entry>
	<entry><literal>circle '((0,0),2)' ~ point '(1,1)'</literal></entry>
5531 5532
       </row>
       <row>
5533
	<entry> <literal>@</literal> </entry>
5534 5535
	<entry>Contained in or on?</entry>
	<entry><literal>point '(1,1)' @ circle '((0,0),2)'</literal></entry>
5536 5537
       </row>
       <row>
5538
	<entry> <literal>~=</literal> </entry>
5539
	<entry>Same as?</entry>
5540 5541 5542 5543 5544
	<entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
       </row>
      </tbody>
     </tgroup>
   </table>
5545

5546 5547

   <table id="functions-geometry-func-table">
5548 5549 5550 5551 5552
     <title>Geometric Functions</title>
     <tgroup cols="4">
      <thead>
       <row>
	<entry>Function</entry>
5553
	<entry>Return Type</entry>
5554 5555 5556 5557 5558 5559
	<entry>Description</entry>
	<entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
5560
	<entry><literal><function>area</function>(<replaceable>object</>)</literal></entry>
5561
	<entry><type>double precision</type></entry>
5562
	<entry>area</entry>
5563
	<entry><literal>area(box '((0,0),(1,1))')</literal></entry>
5564 5565
       </row>
       <row>
5566
	<entry><literal><function>box_intersect</function>(<type>box</>, <type>box</>)</literal></entry>
5567
	<entry><type>box</type></entry>
5568
	<entry>intersection box</entry>
5569
	<entry><literal>box_intersect(box '((0,0),(1,1))',box '((0.5,0.5),(2,2))')</literal></entry>
5570 5571
       </row>
       <row>
5572
	<entry><literal><function>center</function>(<replaceable>object</>)</literal></entry>
5573
	<entry><type>point</type></entry>
5574
	<entry>center</entry>
5575
	<entry><literal>center(box '((0,0),(1,2))')</literal></entry>
5576 5577
       </row>
       <row>
5578
	<entry><literal><function>diameter</function>(<type>circle</>)</literal></entry>
5579
	<entry><type>double precision</type></entry>
5580
	<entry>diameter of circle</entry>
5581
	<entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
5582 5583
       </row>
       <row>
5584
	<entry><literal><function>height</function>(<type>box</>)</literal></entry>
5585
	<entry><type>double precision</type></entry>
5586
	<entry>vertical size of box</entry>
5587
	<entry><literal>height(box '((0,0),(1,1))')</literal></entry>
5588 5589
       </row>
       <row>
5590
	<entry><literal><function>isclosed</function>(<type>path</>)</literal></entry>
5591
	<entry><type>boolean</type></entry>
5592
	<entry>a closed path?</entry>
5593
	<entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
5594 5595
       </row>
       <row>
5596
	<entry><literal><function>isopen</function>(<type>path</>)</literal></entry>
5597
	<entry><type>boolean</type></entry>
5598
	<entry>an open path?</entry>
5599
	<entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
5600 5601
       </row>
       <row>
5602
	<entry><literal><function>length</function>(<replaceable>object</>)</literal></entry>
5603
	<entry><type>double precision</type></entry>
5604
	<entry>length</entry>
5605
	<entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
5606
       </row>
5607
       <row>
5608
	<entry><literal><function>npoints</function>(<type>path</>)</literal></entry>
5609 5610 5611 5612 5613
	<entry><type>integer</type></entry>
	<entry>number of points</entry>
	<entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
       </row>
       <row>
5614
	<entry><literal><function>npoints</function>(<type>polygon</>)</literal></entry>
5615 5616 5617 5618
	<entry><type>integer</type></entry>
	<entry>number of points</entry>
	<entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
       </row>
5619
       <row>
5620
	<entry><literal><function>pclose</function>(<type>path</>)</literal></entry>
5621
	<entry><type>path</type></entry>
5622
	<entry>convert path to closed</entry>
5623
	<entry><literal>popen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
5624
       </row>
5625 5626
<![IGNORE[
<!-- Not defined by this name. Implements the intersection operator '#' -->
5627
       <row>
5628
	<entry><literal><function>point</function>(<type>lseg</>, <type>lseg</>)</literal></entry>
5629
	<entry><type>point</type></entry>
5630
	<entry>intersection</entry>
5631
	<entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
5632
       </row>
5633
]]>
5634
       <row>
5635
	<entry><literal><function>popen</function>(<type>path</>)</literal></entry>
5636
	<entry><type>path</type></entry>
5637
	<entry>convert path to open</entry>
5638
	<entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
5639 5640
       </row>
       <row>
5641
	<entry><literal><function>radius</function>(<type>circle</type>)</literal></entry>
5642
	<entry><type>double precision</type></entry>
5643
	<entry>radius of circle</entry>
5644
	<entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
5645 5646
       </row>
       <row>
5647
	<entry><literal><function>width</function>(<type>box</>)</literal></entry>
5648
	<entry><type>double precision</type></entry>
5649
	<entry>horizontal size of box</entry>
5650
	<entry><literal>width(box '((0,0),(1,1))')</literal></entry>
5651 5652 5653
       </row>
      </tbody>
     </tgroup>
5654
   </table>
5655

5656

5657
   <table id="functions-geometry-conv-table">
5658 5659 5660 5661 5662
     <title>Geometric Type Conversion Functions</title>
     <tgroup cols="4">
      <thead>
       <row>
	<entry>Function</entry>
5663
	<entry>Return Type</entry>
5664 5665 5666 5667 5668 5669
	<entry>Description</entry>
	<entry>Example</entry>
       </row>
      </thead>
      <tbody>
       <row>
5670
	<entry><literal><function>box</function>(<type>circle</type>)</literal></entry>
5671
	<entry><type>box</type></entry>
5672
	<entry>circle to box</entry>
5673
	<entry><literal>box(circle '((0,0),2.0)')</literal></entry>
5674 5675
       </row>
       <row>
5676
	<entry><literal><function>box</function>(<type>point</type>, <type>point</type>)</literal></entry>
5677
	<entry><type>box</type></entry>
5678
	<entry>points to box</entry>
5679
	<entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
5680 5681
       </row>
       <row>
5682
	<entry><literal><function>box</function>(<type>polygon</type>)</literal></entry>
5683
	<entry><type>box</type></entry>
5684
	<entry>polygon to box</entry>
5685
	<entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
5686 5687
       </row>
       <row>
5688
	<entry><literal><function>circle</function>(<type>box</type>)</literal></entry>
5689
	<entry><type>circle</type></entry>
5690
	<entry>box to circle</entry>
5691
	<entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
5692 5693
       </row>
       <row>
5694
	<entry><literal><function>circle</function>(<type>point</type>, <type>double precision</type>)</literal></entry>
5695
	<entry><type>circle</type></entry>
5696
	<entry>point and radius to circle</entry>
5697
	<entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
5698 5699
       </row>
       <row>
5700
	<entry><literal><function>lseg</function>(<type>box</type>)</literal></entry>
5701
	<entry><type>lseg</type></entry>
5702
	<entry>box diagonal to line segment</entry>
5703
	<entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
5704 5705
       </row>
       <row>
5706
	<entry><literal><function>lseg</function>(<type>point</type>, <type>point</type>)</literal></entry>
5707
	<entry><type>lseg</type></entry>
5708
	<entry>points to line segment</entry>
5709
	<entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
5710 5711
       </row>
       <row>
5712
	<entry><literal><function>path</function>(<type>polygon</type>)</literal></entry>
5713
	<entry><type>point</type></entry>
5714
	<entry>polygon to path</entry>
5715
	<entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
5716 5717
       </row>
       <row>
5718
	<entry><literal><function>point</function>(<type>circle</type>)</literal></entry>
5719
	<entry><type>point</type></entry>
5720
	<entry>center of circle</entry>
5721
	<entry><literal>point(circle '((0,0),2.0)')</literal></entry>
5722 5723
       </row>
       <row>
5724
	<entry><literal><function>point</function>(<type>lseg</type>, <type>lseg</type>)</literal></entry>
5725
	<entry><type>point</type></entry>
5726
	<entry>intersection</entry>
5727
	<entry><literal>point(lseg '((-1,0),(1,0))', lseg '((-2,-2),(2,2))')</literal></entry>
5728 5729
       </row>
       <row>
5730
	<entry><literal><function>point</function>(<type>polygon</type>)</literal></entry>
5731
	<entry><type>point</type></entry>
5732
	<entry>center of polygon</entry>
5733
	<entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
5734 5735
       </row>
       <row>
5736
	<entry><literal><function>polygon</function>(<type>box</type>)</literal></entry>
5737
	<entry><type>polygon</type></entry>
5738
	<entry>box to 4-point polygon</entry>
5739
	<entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
5740 5741
       </row>
       <row>
5742
	<entry><literal><function>polygon</function>(<type>circle</type>)</literal></entry>
5743
	<entry><type>polygon</type></entry>
5744
	<entry>circle to 12-point polygon</entry>
5745
	<entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
5746 5747
       </row>
       <row>
5748
	<entry><literal><function>polygon</function>(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</literal></entry>
5749
	<entry><type>polygon</type></entry>
5750
	<entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
5751
	<entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
5752 5753
       </row>
       <row>
5754
	<entry><literal><function>polygon</function>(<type>path</type>)</literal></entry>
5755
	<entry><type>polygon</type></entry>
5756
	<entry>path to polygon</entry>
5757
	<entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
5758 5759 5760
       </row>
      </tbody>
     </tgroup>
5761 5762
   </table>

5763 5764
    <para>
     It is possible to access the two component numbers of a <type>point</>
5765
     as though it were an array with indices 0 and 1.  For example, if
5766
     <literal>t.p</> is a <type>point</> column then
5767
     <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
5768
     <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
5769 5770
     In the same way, a value of type <type>box</> or <type>lseg</> may be treated
     as an array of two <type>point</> values.
5771 5772
    </para>

5773
  </sect1>
5774

5775

5776 5777
 <sect1 id="functions-net">
  <title>Network Address Type Functions</title>
5778

5779 5780
  <para>
   <xref linkend="cidr-inet-operators-table"> shows the operators
5781
   available for the <type>cidr</type> and <type>inet</type> types.
5782
   The operators <literal>&lt;&lt;</literal>,
5783 5784
   <literal>&lt;&lt;=</literal>, <literal>&gt;&gt;</literal>, and
   <literal>&gt;&gt;=</literal> test for subnet inclusion.  They
5785 5786 5787 5788
   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>
5789

5790
    <table id="cidr-inet-operators-table">
5791 5792 5793 5794 5795 5796
     <title><type>cidr</type> and <type>inet</type> Operators</title>
     <tgroup cols="3">
      <thead>
       <row>
	<entry>Operator</entry>
	<entry>Description</entry>
5797
	<entry>Example</entry>
5798 5799 5800 5801
       </row>
      </thead>
      <tbody>
       <row>
5802 5803
	<entry> <literal>&lt;</literal> </entry>
	<entry>is less than</entry>
5804 5805 5806
	<entry><literal>inet '192.168.1.5' &lt; inet '192.168.1.6'</literal></entry>
       </row>
       <row>
5807 5808
	<entry> <literal>&lt;=</literal> </entry>
	<entry>is less than or equal</entry>
5809 5810 5811
	<entry><literal>inet '192.168.1.5' &lt;= inet '192.168.1.5'</literal></entry>
       </row>
       <row>
5812 5813
	<entry> <literal>=</literal> </entry>
	<entry>equals</entry>
5814 5815 5816
	<entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
       </row>
       <row>
5817 5818
	<entry> <literal>&gt;=</literal> </entry>
	<entry>is greater or equal</entry>
5819 5820 5821
	<entry><literal>inet '192.168.1.5' &gt;= inet '192.168.1.5'</literal></entry>
       </row>
       <row>
5822 5823
	<entry> <literal>&gt;</literal> </entry>
	<entry>is greater than</entry>
5824 5825 5826
	<entry><literal>inet '192.168.1.5' &gt; inet '192.168.1.4'</literal></entry>
       </row>
       <row>
5827 5828
	<entry> <literal>&lt;&gt;</literal> </entry>
	<entry>is not equal</entry>
5829 5830 5831
	<entry><literal>inet '192.168.1.5' &lt;&gt; inet '192.168.1.4'</literal></entry>
       </row>
       <row>
5832
	<entry> <literal>&lt;&lt;</literal> </entry>
5833 5834 5835 5836
	<entry>is contained within</entry>
	<entry><literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal></entry>
       </row>
       <row>
5837
	<entry> <literal>&lt;&lt;=</literal> </entry>
5838 5839 5840 5841
	<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>
5842
	<entry> <literal>&gt;&gt;</literal> </entry>
5843 5844 5845 5846
	<entry>contains</entry>
	<entry><literal>inet'192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal></entry>
       </row>
       <row>
5847
	<entry> <literal>&gt;&gt;=</literal> </entry>
5848 5849 5850 5851 5852 5853
	<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>
5854

5855 5856
  <para>
   <xref linkend="cidr-inet-functions-table"> shows the functions
5857 5858 5859
   available for use with the <type>cidr</type> and <type>inet</type>
   types.  The <function>host</function>,
   <function>text</function>, and <function>abbrev</function>
5860
   functions are primarily intended to offer alternative display
5861 5862 5863
   formats. You can cast a text value to <type>inet</> using normal casting
   syntax: <literal>inet(<replaceable>expression</>)</literal> or
   <literal><replaceable>colname</>::inet</literal>.
5864
  </para>
5865

5866
    <table id="cidr-inet-functions-table">
5867
     <title><type>cidr</type> and <type>inet</type> Functions</title>
5868
     <tgroup cols="5">
5869 5870 5871
      <thead>
       <row>
	<entry>Function</entry>
5872
	<entry>Return Type</entry>
5873 5874
	<entry>Description</entry>
	<entry>Example</entry>
5875
	<entry>Result</entry>
5876 5877 5878 5879
       </row>
      </thead>
      <tbody>
       <row>
5880
	<entry><literal><function>broadcast</function>(<type>inet</type>)</literal></entry>
5881
	<entry><type>inet</type></entry>
5882
	<entry>broadcast address for network</entry>
5883 5884
	<entry><literal>broadcast('192.168.1.5/24')</literal></entry>
	<entry><literal>192.168.1.255/24</literal></entry>
5885 5886
       </row>
       <row>
5887
	<entry><literal><function>host</function>(<type>inet</type>)</literal></entry>
5888
	<entry><type>text</type></entry>
5889
	<entry>extract IP address as text</entry>
5890 5891
	<entry><literal>host('192.168.1.5/24')</literal></entry>
	<entry><literal>192.168.1.5</literal></entry>
5892 5893
       </row>
       <row>
5894
	<entry><literal><function>masklen</function>(<type>inet</type>)</literal></entry>
5895
	<entry><type>integer</type></entry>
5896
	<entry>extract netmask length</entry>
5897 5898
	<entry><literal>masklen('192.168.1.5/24')</literal></entry>
	<entry><literal>24</literal></entry>
5899
       </row>
Bruce Momjian's avatar
Bruce Momjian committed
5900
       <row>
5901
	<entry><literal><function>set_masklen</function>(<type>inet</type>,<type>integer</type>)</literal></entry>
5902
	<entry><type>inet</type></entry>
5903
	<entry>set netmask length for <type>inet</type> value</entry>
5904 5905
	<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
5906
       </row>
5907
       <row>
5908
	<entry><literal><function>netmask</function>(<type>inet</type>)</literal></entry>
5909
	<entry><type>inet</type></entry>
5910
	<entry>construct netmask for network</entry>
5911 5912
	<entry><literal>netmask('192.168.1.5/24')</literal></entry>
	<entry><literal>255.255.255.0</literal></entry>
5913
       </row>
Bruce Momjian's avatar
Bruce Momjian committed
5914
       <row>
5915
	<entry><literal><function>hostmask</function>(<type>inet</type>)</literal></entry>
Bruce Momjian's avatar
Bruce Momjian committed
5916 5917 5918 5919 5920
	<entry><type>inet</type></entry>
	<entry>construct hostmask for network</entry>
	<entry><literal>hostmask('192.168.23.20/30')</literal></entry>
	<entry><literal>0.0.0.3</literal></entry>
       </row>
5921
       <row>
5922
	<entry><literal><function>network</function>(<type>inet</type>)</literal></entry>
5923
	<entry><type>cidr</type></entry>
5924
	<entry>extract network part of address</entry>
5925 5926
	<entry><literal>network('192.168.1.5/24')</literal></entry>
	<entry><literal>192.168.1.0/24</literal></entry>
5927 5928
       </row>
       <row>
5929
	<entry><literal><function>text</function>(<type>inet</type>)</literal></entry>
5930
	<entry><type>text</type></entry>
5931
	<entry>extract IP address and netmask length as text</entry>
5932 5933
	<entry><literal>text(inet '192.168.1.5')</literal></entry>
	<entry><literal>192.168.1.5/32</literal></entry>
5934
       </row>
5935
       <row>
5936
	<entry><literal><function>abbrev</function>(<type>inet</type>)</literal></entry>
5937
	<entry><type>text</type></entry>
5938
	<entry>abbreviated display format as text</entry>
5939 5940
	<entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
	<entry><literal>10.1/16</literal></entry>
5941
       </row>
5942 5943 5944 5945
      </tbody>
     </tgroup>
    </table>

5946 5947
  <para>
   <xref linkend="macaddr-functions-table"> shows the functions
5948 5949 5950
   available for use with the <type>macaddr</type> type.  The function
   <literal><function>trunc</function>(<type>macaddr</type>)</literal> returns a MAC
   address with the last 3 bytes set to zero.  This can be used to
5951 5952 5953 5954 5955
   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>
5956

5957
    <table id="macaddr-functions-table">
5958
     <title><type>macaddr</type> Functions</title>
5959 5960 5961 5962
     <tgroup cols="5">
      <thead>
       <row>
	<entry>Function</entry>
5963
	<entry>Return Type</entry>
5964 5965 5966
	<entry>Description</entry>
	<entry>Example</entry>
	<entry>Result</entry>
5967
       </row>
5968 5969
      </thead>
      <tbody>
5970
       <row>
5971
	<entry><literal><function>trunc</function>(<type>macaddr</type>)</literal></entry>
5972
	<entry><type>macaddr</type></entry>
5973
	<entry>set last 3 bytes to zero</entry>
5974 5975
	<entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
	<entry><literal>12:34:56:00:00:00</literal></entry>
5976
       </row>
5977 5978 5979
      </tbody>
     </tgroup>
    </table>
5980

5981
   <para>
5982 5983
    The <type>macaddr</type> type also supports the standard relational
    operators (<literal>&gt;</literal>, <literal>&lt;=</literal>, etc.) for
5984 5985 5986
    lexicographical ordering.
   </para>

5987
  </sect1>
5988

5989

5990 5991 5992 5993 5994 5995 5996 5997 5998 5999 6000 6001 6002 6003 6004 6005
 <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>

6006 6007 6008 6009 6010 6011 6012 6013 6014 6015 6016 6017 6018
  <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">
6019
    <title>Sequence Functions</title>
6020 6021
    <tgroup cols="3">
     <thead>
6022
      <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
6023 6024 6025 6026
     </thead>

     <tbody>
      <row>
6027
	<entry><literal><function>nextval</function>(<type>text</type>)</literal></entry>
6028
	<entry><type>bigint</type></entry>
6029
	<entry>Advance sequence and return new value</entry>
6030 6031
      </row>
      <row>
6032
	<entry><literal><function>currval</function>(<type>text</type>)</literal></entry>
6033
	<entry><type>bigint</type></entry>
6034
	<entry>Return value most recently obtained with <function>nextval</function></entry>
6035 6036
      </row>
      <row>
6037
	<entry><literal><function>setval</function>(<type>text</type>, <type>bigint</type>)</literal></entry>
6038
	<entry><type>bigint</type></entry>
6039
	<entry>Set sequence's current value</entry>
6040 6041
      </row>
      <row>
6042
	<entry><literal><function>setval</function>(<type>text</type>, <type>bigint</type>, <type>boolean</type>)</literal></entry>
6043
	<entry><type>bigint</type></entry>
6044
	<entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
6045 6046 6047 6048 6049 6050
      </row>
     </tbody>
    </tgroup>
   </table>

  <para>
6051 6052 6053 6054 6055
   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
   <acronym>SQL</acronym> names, the sequence functions convert their
   argument to lower case unless the string is double-quoted.  Thus
6056
<programlisting>
6057 6058 6059
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></>
6060 6061 6062
</programlisting>
   The sequence name can be schema-qualified if necessary:
<programlisting>
6063 6064 6065
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></>
6066 6067 6068 6069 6070 6071 6072 6073 6074 6075
</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>
6076
      <term><function>nextval</function></term>
6077 6078 6079
      <listitem>
       <para>
        Advance the sequence object to its next value and return that
6080
	value.  This is done atomically: even if multiple sessions
6081
	execute <function>nextval</function> concurrently, each will safely receive
6082 6083 6084 6085 6086 6087
	a distinct sequence value.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
6088
      <term><function>currval</function></term>
6089 6090
      <listitem>
       <para>
6091
        Return the value most recently obtained by <function>nextval</function>
6092
	for this sequence in the current session.  (An error is
6093
	reported if <function>nextval</function> has never been called for this
6094 6095 6096
	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.
6097 6098 6099 6100 6101
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
6102
      <term><function>setval</function></term>
6103 6104 6105
      <listitem>
       <para>
        Reset the sequence object's counter value.  The two-parameter
6106 6107 6108
	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
6109
	before returning a value.  In the three-parameter form,
6110 6111 6112
	<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
6113
	value, and sequence advancement commences with the following
6114
	<function>nextval</function>.  For example,
6115 6116

<screen>
6117
SELECT setval('foo', 42);           <lineannotation>Next <function>nextval</> will return 43</lineannotation>
6118
SELECT setval('foo', 42, true);     <lineannotation>Same as above</lineannotation>
6119
SELECT setval('foo', 42, false);    <lineannotation>Next <function>nextval</> will return 42</lineannotation>
6120 6121
</screen>

6122
        The result returned by <function>setval</function> is just the value of its
6123 6124 6125 6126 6127 6128 6129 6130 6131 6132
	second argument.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
  </para>

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

  <para>
   If a sequence object has been created with default parameters,
6144 6145
   <function>nextval</function> calls on it will return successive values
   beginning with 1.  Other behaviors can be obtained by using
6146
   special parameters in the <xref linkend="SQL-CREATESEQUENCE"> command;
6147 6148 6149 6150 6151 6152
   see its command reference page for more information.
  </para>

 </sect1>


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

6156 6157 6158 6159 6160 6161 6162 6163
  <indexterm>
   <primary>case</primary>
  </indexterm>

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

6164
  <para>
6165
   This section describes the <acronym>SQL</acronym>-compliant conditional expressions
6166
   available in <productname>PostgreSQL</productname>.
6167 6168 6169 6170 6171 6172 6173 6174 6175 6176
  </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>

6177
  <sect2>
6178 6179 6180 6181 6182 6183
   <title><literal>CASE</></title>

  <para>
   The <acronym>SQL</acronym> <token>CASE</token> expression is a
   generic conditional expression, similar to if/else statements in
   other languages:
6184 6185 6186 6187 6188 6189 6190 6191

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

6192
   <token>CASE</token> clauses can be used wherever
6193
   an expression is valid.  <replaceable>condition</replaceable> is an
6194
   expression that returns a <type>boolean</type> result.  If the result is true
6195 6196
   then the value of the <token>CASE</token> expression is the
   <replaceable>result</replaceable> that follows the condition.  If the result is false any
6197 6198 6199 6200 6201
   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
6202
   omitted and no condition matches, the result is null.
6203 6204 6205 6206 6207
  </para>

   <para>
    An example:
<screen>
6208 6209
SELECT * FROM test;

6210 6211 6212 6213 6214
 a
---
 1
 2
 3
6215 6216 6217 6218 6219 6220 6221 6222 6223


SELECT a,
       CASE WHEN a=1 THEN 'one'
            WHEN a=2 THEN 'two'
            ELSE 'other'
       END
    FROM test;

6224 6225 6226 6227 6228 6229 6230 6231 6232
 a | case
---+-------
 1 | one
 2 | two
 3 | other
</screen>
   </para>

  <para>
6233
   The data types of all the <replaceable>result</replaceable>
6234
   expressions must be convertible to a single output type.
6235
   See <xref linkend="typeconv-union-case"> for more detail.
6236 6237
  </para>

6238 6239 6240 6241
  <para>
   The following <quote>simple</quote> <token>CASE</token> expression is a
   specialized variant of the general form above:

6242 6243 6244 6245 6246 6247 6248 6249
<synopsis>
CASE <replaceable>expression</replaceable>
    WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
    <optional>WHEN ...</optional>
    <optional>ELSE <replaceable>result</replaceable></optional>
END
</synopsis>

6250
   The
6251
   <replaceable>expression</replaceable> is computed and compared to
6252
   all the <replaceable>value</replaceable> specifications in the
6253 6254
   <token>WHEN</token> clauses until one is found that is equal.  If
   no match is found, the <replaceable>result</replaceable> in the
6255
   <token>ELSE</token> clause (or a null value) is returned.  This is similar
6256 6257 6258 6259 6260 6261 6262
   to the <function>switch</function> statement in C.
  </para>

   <para>
    The example above can be written using the simple
    <token>CASE</token> syntax:
<screen>
6263 6264 6265 6266 6267 6268 6269
SELECT a,
       CASE a WHEN 1 THEN 'one'
              WHEN 2 THEN 'two'
              ELSE 'other'
       END
    FROM test;

6270 6271 6272 6273 6274 6275 6276
 a | case
---+-------
 1 | one
 2 | two
 3 | other
</screen>
    </para>
6277
  </sect2>
6278

6279
  <sect2>
6280
   <title><literal>COALESCE</></title>
6281 6282

<synopsis>
6283
<function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
6284 6285 6286 6287
</synopsis>

  <para>
   The <function>COALESCE</function> function returns the first of its
6288 6289
   arguments that is not null.  This is often useful to substitute a
   default value for null values when data is retrieved for display,
6290 6291 6292 6293 6294
   for example:
<programlisting>
SELECT COALESCE(description, short_description, '(none)') ...
</programlisting>
  </para>
6295
  </sect2>
6296

6297
  <sect2>
6298
   <title><literal>NULLIF</></title>
6299

6300 6301 6302 6303
  <indexterm>
   <primary>nullif</primary>
  </indexterm>

6304
<synopsis>
6305
<function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
6306 6307 6308
</synopsis>

  <para>
6309
   The <function>NULLIF</function> function returns a null value if and only
6310 6311 6312 6313 6314 6315 6316 6317 6318
   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>
6319

6320
  </sect2>
6321

6322 6323 6324
 </sect1>


6325 6326
 <sect1 id="functions-misc">
  <title>Miscellaneous Functions</title>
6327

6328 6329 6330 6331 6332 6333
  <para>
   <xref linkend="functions-misc-session-table"> shows several
   functions that extract session and system information.
  </para>

   <table id="functions-misc-session-table">
6334
    <title>Session Information Functions</title>
6335 6336
    <tgroup cols="3">
     <thead>
6337
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
6338 6339 6340
     </thead>

     <tbody>
6341 6342 6343 6344 6345 6346 6347 6348 6349 6350 6351 6352 6353 6354 6355 6356 6357 6358
      <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>

6359
      <row>
6360 6361
       <entry><function>current_user</function></entry>
       <entry><type>name</type></entry>
6362
       <entry>user name of current execution context</entry>
6363
      </row>
6364

6365
      <row>
6366 6367
       <entry><function>session_user</function></entry>
       <entry><type>name</type></entry>
6368
       <entry>session user name</entry>
6369
      </row>
6370

6371
      <row>
6372 6373 6374
       <entry><function>user</function></entry>
       <entry><type>name</type></entry>
       <entry>equivalent to <function>current_user</function></entry>
6375
      </row>
6376

6377
      <row>
6378
       <entry><function>version()</function></entry>
6379 6380
       <entry><type>text</type></entry>
       <entry>PostgreSQL version information</entry>
Bruce Momjian's avatar
Bruce Momjian committed
6381
      </row>
6382 6383 6384 6385
     </tbody>
    </tgroup>
   </table>

6386 6387 6388 6389 6390
   <indexterm zone="functions-misc">
    <primary>user</primary>
    <secondary>current</secondary>
   </indexterm>

6391 6392 6393 6394 6395 6396 6397 6398 6399 6400
   <indexterm zone="functions-misc">
    <primary>schema</primary>
    <secondary>current</secondary>
   </indexterm>

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

6401
   <para>
6402
    The <function>session_user</function> is the user that initiated a
6403
    database connection; it is fixed for the duration of that
6404
    connection. The <function>current_user</function> is the user identifier
6405 6406 6407
    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>.
6408 6409
    In Unix parlance, the session user is the <quote>real user</quote> and
    the current user is the <quote>effective user</quote>.
6410 6411
   </para>

6412 6413
   <note>
    <para>
6414 6415
     <function>current_user</function>, <function>session_user</function>, and
     <function>user</function> have special syntactic status in <acronym>SQL</acronym>:
6416 6417 6418
     they must be called without trailing parentheses.
    </para>
   </note>
6419

6420
   <para>
6421
    <function>current_schema</function> returns the name of the schema that is
6422
    at the front of the search path (or a null value if the search path is
6423 6424
    empty).  This is the schema that will be used for any tables or
    other named objects that are created without specifying a target schema.
6425
    <function>current_schemas(boolean)</function> returns an array of the names of all
6426 6427
    schemas presently in the search path.  The Boolean option determines whether or not
    implicitly included system schemas such as <literal>pg_catalog</> are included in the search 
6428
    path returned.
6429 6430
   </para>

6431 6432 6433 6434 6435 6436 6437 6438
   <note>
    <para>
     The search path may be altered at run time.  The command is:
<programlisting>
SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
</programlisting>
    </para>
   </note>
6439

6440 6441 6442 6443 6444
   <indexterm zone="functions-misc">
    <primary>version</primary>
   </indexterm>

   <para>
6445 6446
    <function>version()</function> returns a string describing the
    <productname>PostgreSQL</productname> server's version.
6447 6448
   </para>

6449 6450 6451 6452 6453 6454
  <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">
6455
    <title>Configuration Settings Functions</title>
6456 6457 6458 6459 6460 6461 6462 6463
    <tgroup cols="3">
     <thead>
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
     </thead>

     <tbody>
      <row>
       <entry>
6464
        <literal><function>current_setting</function>(<parameter>setting_name</parameter>)</literal>
6465 6466
       </entry>
       <entry><type>text</type></entry>
6467
       <entry>current value of setting</entry>
6468 6469 6470
      </row>
      <row>
       <entry>
6471
        <literal><function>set_config(<parameter>setting_name</parameter>,
6472
                             <parameter>new_value</parameter>,
6473
                             <parameter>is_local</parameter>)</function></literal>
6474 6475
       </entry>
       <entry><type>text</type></entry>
6476
       <entry>set parameter and return new value</entry>
6477 6478 6479 6480 6481 6482
      </row>
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-misc">
6483 6484 6485 6486 6487
    <primary>SET</primary>
   </indexterm>

   <indexterm zone="functions-misc">
    <primary>SHOW</primary>
6488 6489 6490
   </indexterm>

   <indexterm zone="functions-misc">
6491
    <primary>configuration</primary>
6492
    <secondary>server</secondary>
6493 6494 6495
   </indexterm>

   <para>
6496 6497 6498 6499 6500
    The function <function>current_setting</function> yields the
    current value of the setting <parameter>setting_name</parameter>,
    as part of a query result. It corresponds to the
    <acronym>SQL</acronym> command <command>SHOW</command>.  An
    example:
6501
<programlisting>
6502 6503
SELECT current_setting('datestyle');

6504 6505 6506
 current_setting
-----------------
 ISO, US
6507 6508 6509 6510 6511
(1 row)
</programlisting>
   </para>

   <para>
6512 6513 6514 6515 6516
    <function>set_config</function> sets the parameter
    <parameter>setting_name</parameter> to
    <parameter>new_value</parameter>.  If
    <parameter>is_local</parameter> is <literal>true</literal>, the
    new value will only apply to the current transaction. If you want
6517
    the new value to apply for the current session, use
6518 6519
    <literal>false</literal> instead. The function corresponds to the
    SQL command <command>SET</command>. An example:
6520
<programlisting>
6521 6522
SELECT set_config('show_statement_stats', 'off', false);

6523 6524 6525 6526 6527 6528 6529
 set_config
------------
 off
(1 row)
</programlisting>
   </para>

6530 6531 6532 6533 6534 6535 6536 6537
  <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">
6538
    <title>Access Privilege Inquiry Functions</title>
6539 6540
    <tgroup cols="3">
     <thead>
6541
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
6542 6543 6544 6545
     </thead>

     <tbody>
      <row>
6546
       <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
6547
                                  <parameter>table</parameter>,
6548
                                  <parameter>privilege</parameter>)</literal>
6549
       </entry>
6550
       <entry><type>boolean</type></entry>
6551
       <entry>does user have privilege for table</entry>
6552 6553
      </row>
      <row>
6554 6555
       <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
                                  <parameter>privilege</parameter>)</literal>
6556
       </entry>
6557
       <entry><type>boolean</type></entry>
6558
       <entry>does current user have privilege for table</entry>
6559
      </row>
6560
      <row>
6561
       <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
6562
                                  <parameter>database</parameter>,
6563
                                  <parameter>privilege</parameter>)</literal>
6564 6565
       </entry>
       <entry><type>boolean</type></entry>
6566
       <entry>does user have privilege for database</entry>
6567 6568
      </row>
      <row>
6569 6570
       <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
                                  <parameter>privilege</parameter>)</literal>
6571 6572
       </entry>
       <entry><type>boolean</type></entry>
6573
       <entry>does current user have privilege for database</entry>
6574 6575
      </row>
      <row>
6576
       <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
6577
                                  <parameter>function</parameter>,
6578
                                  <parameter>privilege</parameter>)</literal>
6579 6580
       </entry>
       <entry><type>boolean</type></entry>
6581
       <entry>does user have privilege for function</entry>
6582 6583
      </row>
      <row>
6584 6585
       <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
                                  <parameter>privilege</parameter>)</literal>
6586 6587
       </entry>
       <entry><type>boolean</type></entry>
6588
       <entry>does current user have privilege for function</entry>
6589 6590
      </row>
      <row>
6591
       <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
6592
                                  <parameter>language</parameter>,
6593
                                  <parameter>privilege</parameter>)</literal>
6594 6595
       </entry>
       <entry><type>boolean</type></entry>
6596
       <entry>does user have privilege for language</entry>
6597 6598
      </row>
      <row>
6599 6600
       <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
                                  <parameter>privilege</parameter>)</literal>
6601 6602
       </entry>
       <entry><type>boolean</type></entry>
6603
       <entry>does current user have privilege for language</entry>
6604 6605
      </row>
      <row>
6606
       <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
6607
                                  <parameter>schema</parameter>,
6608
                                  <parameter>privilege</parameter>)</literal>
6609 6610
       </entry>
       <entry><type>boolean</type></entry>
6611
       <entry>does user have privilege for schema</entry>
6612 6613
      </row>
      <row>
6614 6615
       <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
                                  <parameter>privilege</parameter>)</literal>
6616 6617
       </entry>
       <entry><type>boolean</type></entry>
6618
       <entry>does current user have privilege for schema</entry>
6619
      </row>
6620 6621 6622 6623 6624 6625 6626
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-misc">
    <primary>has_table_privilege</primary>
   </indexterm>
6627 6628 6629 6630 6631 6632 6633 6634 6635 6636 6637 6638
   <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>
6639 6640

   <para>
6641
    <function>has_table_privilege</function> checks whether a user
6642
    can access a table in a particular way.  The user can be
6643
    specified by name or by ID
6644
    (<literal>pg_user.usesysid</literal>), or if the argument is
6645
    omitted
6646
    <function>current_user</function> is assumed.  The table can be specified
6647
    by name or by OID.  (Thus, there are actually six variants of
6648
    <function>has_table_privilege</function>, which can be distinguished by
6649 6650
    the number and types of their arguments.)  When specifying by name,
    the name can be schema-qualified if necessary.
6651
    The desired access privilege type
6652
    is specified by a text string, which must evaluate to one of the
6653 6654 6655
    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.)
6656 6657 6658 6659
    An example is:
<programlisting>
SELECT has_table_privilege('myschema.mytable', 'select');
</programlisting>
6660 6661
   </para>

6662 6663 6664 6665
   <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>.
6666
    The desired access privilege type must evaluate to
6667 6668 6669 6670 6671 6672 6673 6674 6675 6676 6677
    <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,
6678
    the allowed input is the same as for the <type>regprocedure</> data type.
6679
    The desired access privilege type must currently evaluate to
6680 6681 6682 6683 6684 6685 6686
    <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>.
6687
    The desired access privilege type must currently evaluate to
6688 6689 6690 6691 6692 6693 6694
    <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>.
6695
    The desired access privilege type must evaluate to
6696 6697 6698 6699
    <literal>CREATE</literal> or
    <literal>USAGE</literal>.
   </para>

6700 6701 6702 6703 6704 6705
  <para>
   To evaluate whether a user holds a grant option on the privilege,
   append <literal> WITH GRANT OPTION</literal> to the privilege key
   word; for example <literal>'UPDATE WITH GRANT OPTION'</literal>.
  </para>

6706 6707 6708 6709 6710 6711 6712 6713 6714 6715 6716 6717 6718 6719 6720
  <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">
6721 6722 6723 6724 6725 6726 6727 6728
    <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>
6729
       <entry><literal><function>pg_table_is_visible</function>(<parameter>table_oid</parameter>)</literal>
6730 6731 6732 6733 6734
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is table visible in search path</entry>
      </row>
      <row>
6735
       <entry><literal><function>pg_type_is_visible</function>(<parameter>type_oid</parameter>)</literal>
6736 6737 6738 6739 6740
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is type visible in search path</entry>
      </row>
      <row>
6741
       <entry><literal><function>pg_function_is_visible</function>(<parameter>function_oid</parameter>)</literal>
6742 6743 6744 6745 6746
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is function visible in search path</entry>
      </row>
      <row>
6747
       <entry><literal><function>pg_operator_is_visible</function>(<parameter>operator_oid</parameter>)</literal>
6748 6749 6750 6751 6752
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is operator visible in search path</entry>
      </row>
      <row>
6753
       <entry><literal><function>pg_opclass_is_visible</function>(<parameter>opclass_oid</parameter>)</literal>
6754 6755 6756 6757
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is operator class visible in search path</entry>
      </row>
6758 6759 6760 6761 6762 6763
      <row>
       <entry><literal><function>pg_conversion_is_visible</function>(<parameter>conversion_oid</parameter>)</literal>
       </entry>
       <entry><type>boolean</type></entry>
       <entry>is conversion visible in search path</entry>
      </row>
6764 6765 6766 6767 6768 6769 6770 6771 6772 6773 6774 6775 6776 6777 6778 6779 6780 6781 6782
     </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>
6783 6784 6785
   <indexterm zone="functions-misc">
    <primary>pg_conversion_is_visible</primary>
   </indexterm>
6786 6787

   <para>
6788 6789 6790 6791
   <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>,
6792 6793 6794 6795 6796
   <function>pg_operator_is_visible</function>,
   <function>pg_opclass_is_visible</function>, and
   <function>pg_conversion_is_visible</function> perform the same sort of
   visibility check for types, functions, operators, operator classes
   and conversions, respectively.  For functions and operators, an object in
6797 6798 6799 6800
   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.
6801 6802 6803 6804 6805 6806 6807 6808 6809 6810 6811 6812 6813 6814
   </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>

6815 6816 6817 6818 6819 6820 6821 6822 6823 6824 6825 6826
   <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>

6827 6828 6829 6830
   <indexterm zone="functions-misc">
    <primary>pg_get_triggerdef</primary>
   </indexterm>

6831 6832 6833 6834 6835 6836 6837 6838 6839 6840 6841
   <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.
6842 6843
   <function>pg_get_viewdef</function>,
   <function>pg_get_ruledef</function>,
6844 6845
   <function>pg_get_indexdef</function>,
   <function>pg_get_triggerdef</function>, and
6846
   <function>pg_get_constraintdef</function> respectively
6847 6848
   reconstruct the creating command for a view, rule, index, or
   constraint.  (Note that this is a decompiled reconstruction, not
6849 6850
   the verbatim text of the command.)
   <function>pg_get_userbyid</function>
6851
   extracts a user's name given a user ID number.
6852 6853 6854
  </para>

   <table id="functions-misc-catalog-table">
6855
    <title>System Catalog Information Functions</title>
6856 6857
    <tgroup cols="3">
     <thead>
6858
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
6859 6860 6861 6862
     </thead>

     <tbody>
      <row>
6863
       <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>)</literal></entry>
6864
       <entry><type>text</type></entry>
6865
       <entry>get <command>CREATE VIEW</> command for view (<emphasis>deprecated</emphasis>)</entry>
6866 6867
      </row>
      <row>
6868
       <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>)</literal></entry>
6869
       <entry><type>text</type></entry>
6870
       <entry>get <command>CREATE VIEW</> command for view</entry>
6871 6872
      </row>
      <row>
6873
       <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>)</literal></entry>
6874
       <entry><type>text</type></entry>
6875
       <entry>get <command>CREATE RULE</> command for rule</entry>
6876 6877
      </row>
      <row>
6878
       <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>)</literal></entry>
6879
       <entry><type>text</type></entry>
6880
       <entry>get <command>CREATE INDEX</> command for index</entry>
6881
      </row>
6882
      <row>
6883
       <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
6884
       <entry><type>text</type></entry>
6885
       <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
6886
      </row>
6887
      <row>
6888
       <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>)</literal></entry>
6889
       <entry><type>text</type></entry>
6890
       <entry>get definition of a constraint</entry>
6891
      </row>
6892
      <row>
6893
       <entry><literal><function>pg_get_userbyid</function>(<parameter>userid</parameter>)</literal></entry>
6894
       <entry><type>name</type></entry>
6895
       <entry>get user name with given ID</entry>
6896 6897 6898 6899 6900 6901
      </row>
     </tbody>
    </tgroup>
   </table>

   <indexterm zone="functions-misc">
6902
    <primary>obj_description</primary>
6903 6904
   </indexterm>

6905
   <indexterm zone="functions-misc">
6906
    <primary>col_description</primary>
6907 6908 6909
   </indexterm>

   <para>
6910 6911 6912
    The function shown in <xref
    linkend="functions-misc-comment-table"> extract comments
    previously stored with the <command>COMMENT</command> command.  A
6913
    null value is returned if no comment could be found matching the
6914
    specified parameters.
6915 6916
   </para>

6917
   <table id="functions-misc-comment-table">
6918
    <title>Comment Information Functions</title>
6919 6920
    <tgroup cols="3">
     <thead>
6921
      <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
6922 6923 6924 6925
     </thead>

     <tbody>
      <row>
6926
       <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
6927
       <entry><type>text</type></entry>
6928
       <entry>get comment for a database object</entry>
6929 6930
      </row>
      <row>
6931
       <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>)</literal></entry>
6932
       <entry><type>text</type></entry>
6933
       <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
6934 6935
      </row>
      <row>
6936
       <entry><literal><function>col_description</function>(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</literal></entry>
6937
       <entry><type>text</type></entry>
6938
       <entry>get comment for a table column</entry>
6939 6940 6941 6942 6943 6944
      </row>
     </tbody>
    </tgroup>
   </table>

   <para>
6945
    The two-parameter form of <function>obj_description</function> returns the
6946 6947
    comment for a database object specified by its OID and the name of the
    containing system catalog.  For example,
6948
    <literal>obj_description(123456,'pg_class')</literal>
6949
    would retrieve the comment for a table with OID 123456.
6950
    The one-parameter form of <function>obj_description</function> requires only
6951 6952 6953 6954 6955 6956
    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>
6957
    <function>col_description</function> returns the comment for a table column,
6958
    which is specified by the OID of its table and its column number.
6959
    <function>obj_description</function> cannot be used for table columns since
6960 6961 6962
    columns do not have OIDs of their own.
   </para>

6963 6964
  </sect1>

6965 6966 6967 6968 6969 6970 6971 6972 6973 6974 6975 6976 6977 6978 6979 6980 6981 6982 6983 6984 6985 6986 6987 6988 6989 6990 6991 6992 6993 6994 6995 6996 6997 6998 6999 7000 7001 7002 7003 7004 7005 7006 7007 7008 7009 7010 7011 7012 7013 7014 7015 7016 7017 7018 7019 7020 7021 7022 7023 7024 7025 7026 7027 7028 7029 7030 7031 7032 7033 7034 7035 7036 7037 7038 7039 7040 7041 7042 7043 7044 7045 7046 7047 7048 7049 7050 7051 7052 7053 7054 7055 7056 7057 7058 7059 7060 7061 7062 7063 7064 7065 7066 7067 7068 7069 7070 7071 7072 7073 7074 7075 7076 7077 7078 7079 7080 7081 7082 7083 7084 7085 7086 7087 7088 7089 7090 7091 7092 7093 7094 7095 7096 7097 7098 7099 7100 7101 7102 7103 7104 7105 7106 7107 7108 7109 7110 7111 7112 7113 7114 7115 7116 7117 7118 7119 7120 7121 7122 7123 7124 7125 7126 7127 7128 7129 7130 7131 7132 7133 7134 7135 7136 7137 7138 7139 7140 7141 7142 7143 7144 7145 7146 7147 7148 7149 7150 7151 7152 7153 7154 7155 7156 7157 7158 7159 7160 7161
 <sect1 id="functions-array">
  <title>Array Functions</title>

  <para>
   <xref linkend="array-operators-table"> shows the operators
   available for the <type>array</type> types.
  </para>

    <table id="array-operators-table">
     <title><type>array</type> Operators</title>
     <tgroup cols="4">
      <thead>
       <row>
	<entry>Operator</entry>
	<entry>Description</entry>
	<entry>Example</entry>
	<entry>Result</entry>
       </row>
      </thead>
      <tbody>
       <row>
	<entry> <literal>=</literal> </entry>
	<entry>equals</entry>
	<entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
	<entry><literal>t</literal></entry>
       </row>
       <row>
	<entry> <literal>||</literal> </entry>
	<entry>array-to-array concatenation</entry>
	<entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
	<entry><literal>{{1,2,3},{4,5,6}}</literal></entry>
       </row>
       <row>
	<entry> <literal>||</literal> </entry>
	<entry>array-to-array concatenation</entry>
	<entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
	<entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
       </row>
       <row>
	<entry> <literal>||</literal> </entry>
	<entry>element-to-array concatenation</entry>
	<entry><literal>3 || ARRAY[4,5,6]</literal></entry>
	<entry><literal>{3,4,5,6}</literal></entry>
       </row>
       <row>
	<entry> <literal>||</literal> </entry>
	<entry>array-to-element concatenation</entry>
	<entry><literal>ARRAY[4,5,6] || 7</literal></entry>
	<entry><literal>{4,5,6,7}</literal></entry>
       </row>
      </tbody>
     </tgroup>
    </table>

  <para>
   <xref linkend="array-functions-table"> shows the functions
   available for use with array types. See <xref linkend="arrays">
   for more discussion and examples for the use of these functions.
  </para>

    <table id="array-functions-table">
     <title><type>array</type> 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>
     <literal>
      <function>array_append</function>
      (<type>anyarray</type>, <type>anyelement</type>)
     </literal>
    </entry>
	<entry><type>anyarray</type></entry>
	<entry>
     append an element to the end of an array, returning
     <literal>NULL</literal> for <literal>NULL</literal> inputs
    </entry>
	<entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
	<entry><literal>{1,2,3}</literal></entry>
       </row>
       <row>
	<entry>
     <literal>
      <function>array_cat</function>
      (<type>anyarray</type>, <type>anyarray</type>)
     </literal>
    </entry>
	<entry><type>anyarray</type></entry>
	<entry>
     concatenate two arrays, returning <literal>NULL</literal>
     for <literal>NULL</literal> inputs
    </entry>
	<entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5,6])</literal></entry>
	<entry><literal>{{1,2,3},{4,5,6}}</literal></entry>
       </row>
       <row>
	<entry>
     <literal>
      <function>array_dims</function>
      (<type>anyarray</type>)
     </literal>
    </entry>
	<entry><type>text</type></entry>
	<entry>
     returns a text representation of array dimension lower and upper bounds,
     generating an ERROR for <literal>NULL</literal> inputs
    </entry>
	<entry><literal>array_dims(array[[1,2,3],[4,5,6]])</literal></entry>
	<entry><literal>[1:2][1:3]</literal></entry>
       </row>
       <row>
	<entry>
     <literal>
      <function>array_lower</function>
      (<type>anyarray</type>, <type>integer</type>)
     </literal>
    </entry>
	<entry><type>integer</type></entry>
	<entry>
     returns lower bound of the requested array dimension, returning
     <literal>NULL</literal> for <literal>NULL</literal> inputs
    </entry>
	<entry><literal>array_lower(array_prepend(0, ARRAY[1,2,3]), 1)</literal></entry>
	<entry><literal>0</literal></entry>
       </row>
       <row>
	<entry>
     <literal>
      <function>array_prepend</function>
      (<type>anyelement</type>, <type>anyarray</type>)
     </literal>
    </entry>
	<entry><type>anyarray</type></entry>
	<entry>
     append an element to the beginning of an array, returning
     <literal>NULL</literal> for <literal>NULL</literal> inputs
    </entry>
	<entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
	<entry><literal>{1,2,3}</literal></entry>
       </row>
       <row>
	<entry>
     <literal>
      <function>array_to_string</function>
      (<type>anyarray</type>, <type>text</type>)
     </literal>
    </entry>
	<entry><type>text</type></entry>
	<entry>
     concatenates array elements using provided delimiter, returning
     <literal>NULL</literal> for <literal>NULL</literal> inputs
    </entry>
	<entry><literal>array_to_string(array[1.1,2.2,3.3]::numeric(4,2)[],'~^~')</literal></entry>
	<entry><literal>1.10~^~2.20~^~3.30</literal></entry>
       </row>
       <row>
	<entry>
     <literal>
      <function>array_upper</function>
      (<type>anyarray</type>, <type>integer</type>)
     </literal>
    </entry>
	<entry><type>integer</type></entry>
	<entry>
     returns upper bound of the requested array dimension, returning
     <literal>NULL</literal> for <literal>NULL</literal> inputs
    </entry>
	<entry><literal>array_upper(array_append(ARRAY[1,2,3], 4), 1)</literal></entry>
	<entry><literal>4</literal></entry>
       </row>
       <row>
	<entry>
     <literal>
      <function>string_to_array</function>
      (<type>text</type>, <type>text</type>)
     </literal>
    </entry>
	<entry><type>text[]</type></entry>
	<entry>
     splits string into array elements using provided delimiter, returning
     <literal>NULL</literal> for <literal>NULL</literal> inputs
    </entry>
	<entry><literal>string_to_array('1.10~^~2.20~^~3.30','~^~')::float8[]</literal></entry>
	<entry><literal>{1.1,2.2,3.3}</literal></entry>
       </row>
      </tbody>
     </tgroup>
    </table>
  </sect1>
7162

7163 7164
 <sect1 id="functions-aggregate">
  <title>Aggregate Functions</title>
7165

7166 7167
  <para>
   <firstterm>Aggregate functions</firstterm> compute a single result
7168
   value from a set of input values.  <xref
7169
   linkend="functions-aggregate-table"> shows the built-in aggregate
7170 7171
   functions.  The special syntax considerations for aggregate
   functions are explained in <xref linkend="syntax-aggregates">.
7172
   Consult <xref linkend="tutorial"> for additional introductory
7173
   information.
7174
  </para>
7175

7176
  <table id="functions-aggregate-table">
7177
   <title>Aggregate Functions</title>
7178

7179
   <tgroup cols="4">
7180 7181 7182
    <thead>
     <row>
      <entry>Function</entry>
7183 7184
      <entry>Argument Type</entry>
      <entry>Return Type</entry>
7185 7186 7187 7188 7189 7190 7191
      <entry>Description</entry>
     </row>
    </thead>

    <tbody>
     <row>
      <entry>
7192 7193 7194 7195
       <indexterm>
        <primary>average</primary>
        <secondary>function</secondary>
       </indexterm>
7196 7197 7198 7199
       <function>avg(<replaceable class="parameter">expression</replaceable>)</function>
      </entry>
      <entry>
       <type>smallint</type>, <type>integer</type>,
7200
       <type>bigint</type>, <type>real</type>, <type>double
7201
       precision</type>, <type>numeric</type>, or <type>interval</type>
7202 7203 7204 7205 7206
      </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
7207
      </entry>
7208
      <entry>the average (arithmetic mean) of all input values</entry>
7209 7210 7211
     </row>

     <row>
7212 7213 7214
      <entry><function>count(*)</function></entry>
      <entry></entry>
      <entry><type>bigint</type></entry>
7215 7216 7217 7218
      <entry>number of input values</entry>
     </row>

     <row>
7219 7220 7221
      <entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
      <entry>any</entry>
      <entry><type>bigint</type></entry>
7222
      <entry>
7223 7224
       number of input values for which the value of <replaceable
       class="parameter">expression</replaceable> is not null
7225 7226 7227 7228
      </entry>
     </row>

     <row>
7229 7230 7231
      <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>
7232
      <entry>
7233 7234 7235
       maximum value of <replaceable
       class="parameter">expression</replaceable> across all input
       values
7236 7237 7238 7239
      </entry>
     </row>

     <row>
7240 7241 7242
      <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>
7243
      <entry>
7244 7245 7246
       minimum value of <replaceable
       class="parameter">expression</replaceable> across all input
       values
7247 7248 7249 7250 7251
      </entry>
     </row>

     <row>
      <entry>
7252 7253 7254
       <indexterm>
        <primary>standard deviation</primary>
       </indexterm>
7255 7256 7257 7258
       <function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
      </entry>
      <entry>
       <type>smallint</type>, <type>integer</type>,
7259
       <type>bigint</type>, <type>real</type>, <type>double
7260
       precision</type>, or <type>numeric</type>
7261 7262 7263
      </entry>
      <entry>
       <type>double precision</type> for floating-point arguments,
7264
       otherwise <type>numeric</type>
7265
      </entry>
7266
      <entry>sample standard deviation of the input values</entry>
7267 7268 7269
     </row>

     <row>
7270
      <entry><function>sum(<replaceable class="parameter">expression</replaceable>)</function></entry>
7271 7272 7273
      <entry>
       <type>smallint</type>, <type>integer</type>,
       <type>bigint</type>, <type>real</type>, <type>double
7274 7275 7276 7277 7278 7279 7280 7281 7282
       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
7283
      </entry>
7284
      <entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
7285 7286 7287 7288
     </row>

     <row>
      <entry>
7289 7290 7291
       <indexterm>
        <primary>variance</primary>
       </indexterm>
7292 7293 7294 7295 7296
       <function>variance</function>(<replaceable class="parameter">expression</replaceable>)
      </entry>
      <entry>
       <type>smallint</type>, <type>integer</type>,
       <type>bigint</type>, <type>real</type>, <type>double
7297
       precision</type>, or <type>numeric</type>
7298 7299 7300
      </entry>
      <entry>
       <type>double precision</type> for floating-point arguments,
7301
       otherwise <type>numeric</type>
7302
      </entry>
7303
      <entry>sample variance of the input values (square of the sample standard deviation)</entry>
7304 7305 7306 7307 7308
     </row>

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

7310
  <para>
7311
   It should be noted that except for <function>count</function>,
7312
   these functions return a null value when no rows are selected.  In
7313 7314
   particular, <function>sum</function> of no rows returns null, not
   zero as one might expect.  The function <function>coalesce</function> may be
7315
   used to substitute zero for null when necessary.
7316
  </para>
7317

7318 7319 7320 7321 7322 7323 7324 7325 7326 7327 7328 7329 7330 7331 7332 7333 7334 7335 7336 7337 7338 7339 7340 7341 7342 7343 7344 7345 7346 7347 7348 7349 7350 7351 7352 7353 7354 7355 7356 7357 7358 7359 7360 7361 7362 7363 7364 7365 7366 7367 7368
  <note>
   <para>
    Users accustomed to working with other RDBMS products may be
    surprised by the performance characteristics of certain aggregate
    functions in <productname>PostgreSQL</productname> when the
    aggregate is applied to the entire table (in other words, no
    <literal>WHERE</literal> clause is specified). In particular,
    a query like
<programlisting>
SELECT min(col) FROM sometable;
</programlisting>
   will be executed by <productname>PostgreSQL</productname> using a
   sequential scan of the entire table. Other database systems may
   optimize queries of this form to use an index on the column, if one
   is available. Similarly, the aggregate functions
   <function>max()</function> and <function>count()</function> always
   require a sequential scan if applied to the entire table in
   <productname>PostgreSQL</productname>.
   </para>

   <para>
    <productname>PostgreSQL</productname> cannot easily implement this
    optimization because it also allows for user-defined aggregate
    queries. Since <function>min()</function>,
    <function>max()</function>, and <function>count()</function> are
    defined using a generic API for aggregate functions, there is no
    provision for <quote>special-casing</quote> the execution of these
    functions under certain circumstances.
   </para>

   <para>
    Fortunately, there is a simple workaround for
    <function>min()</function> and <function>max()</function>. The
    query shown below is equivalent to the query above, except that it
    can take advantage of a B+-Tree index if there is one present on
    the column in question.
<programlisting>
SELECT col FROM sometable ORDER BY col ASC LIMIT 1;
</programlisting>
    A similar query (obtained by substituting <literal>DESC</literal>
    for <literal>ASC</literal> in the query above) can be used in the
    place of <function>max()</function>).
   </para>

   <para>
    Unfortunately, there is no similarly trivial query that can be
    used to improve the performance of <function>count()</function>
    when applied to the entire table.
   </para>
  </note>

7369
 </sect1>
7370

7371 7372 7373 7374 7375 7376 7377 7378 7379 7380 7381 7382 7383 7384 7385 7386 7387 7388 7389 7390 7391 7392 7393 7394 7395 7396 7397 7398 7399 7400 7401 7402 7403 7404 7405 7406 7407 7408 7409

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

7410
  <sect2>
7411
   <title><literal>EXISTS</literal></title>
7412 7413 7414 7415 7416 7417

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

  <para>
7418
   The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
7419
   or <firstterm>subquery</firstterm>.  The
7420
   subquery is evaluated to determine whether it returns any rows.
7421
   If it returns at least one row, the result of <token>EXISTS</token> is
7422 7423
   <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token> 
   is <quote>false</>.
7424 7425 7426 7427 7428 7429 7430 7431 7432 7433
  </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.
7434 7435
   It is unwise to write a subquery that has any side effects (such as
   calling sequence functions); whether the side effects occur or not
7436 7437 7438 7439 7440 7441 7442
   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
7443
   to write all <literal>EXISTS</> tests in the form
7444 7445
   <literal>EXISTS(SELECT 1 WHERE ...)</literal>.  There are exceptions to
   this rule however, such as subqueries that use <token>INTERSECT</token>.
7446 7447 7448
  </para>

  <para>
7449 7450 7451
   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:
7452 7453 7454 7455 7456
<screen>
SELECT col1 FROM tab1
    WHERE EXISTS(SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
</screen>
  </para>
7457
  </sect2>
7458

7459
  <sect2>
7460
   <title><literal>IN</literal></title>
7461 7462 7463 7464 7465 7466

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

  <para>
7467
   The right-hand side is a parenthesized
7468 7469
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result.
7470 7471
   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
7472 7473 7474 7475
   case where the subquery returns no rows).
  </para>

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

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

<synopsis>
7489
(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) IN (<replaceable>subquery</replaceable>)
7490 7491 7492
</synopsis>

  <para>
7493
   The right-hand side of this form of <token>IN</token> is a parenthesized
7494 7495 7496
   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.
7497 7498
   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
7499 7500 7501 7502
   case where the subquery returns no rows).
  </para>

  <para>
7503
   As usual, null values in the rows are combined per
7504
   the normal rules of SQL Boolean expressions.  Two rows are considered
7505 7506
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
7507 7508 7509
   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.
7510
  </para>
7511
  </sect2>
7512

7513
  <sect2>
7514
   <title><literal>NOT IN </literal></title>
7515 7516 7517 7518 7519 7520

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

  <para>
7521
   The right-hand side is a parenthesized
7522 7523
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result.
7524
   The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
7525
   are found (including the special case where the subquery returns no rows).
7526
   The result is <quote>false</> if any equal row is found.
7527 7528 7529
  </para>

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

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

<synopsis>
7543
(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) NOT IN (<replaceable>subquery</replaceable>)
7544 7545 7546
</synopsis>

  <para>
7547
   The right-hand side of this form of <token>NOT IN</token> is a parenthesized
7548 7549 7550
   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.
7551
   The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
7552
   are found (including the special case where the subquery returns no rows).
7553
   The result is <quote>false</> if any equal row is found.
7554 7555 7556
  </para>

  <para>
7557
   As usual, null values in the rows are combined per
7558
   the normal rules of SQL Boolean expressions.  Two rows are considered
7559 7560
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
7561 7562 7563
   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.
7564
  </para>
7565
  </sect2>
7566

7567
  <sect2>
7568
   <title><literal>ANY</literal>/<literal>SOME</literal></title>
7569 7570

<synopsis>
7571 7572
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
<replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
7573 7574 7575
</synopsis>

  <para>
7576
   The right-hand side is a parenthesized
7577 7578
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result using the
7579
   given <replaceable>operator</replaceable>, which must yield a Boolean
7580
   result.
7581 7582
   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
7583 7584 7585 7586
   case where the subquery returns no rows).
  </para>

  <para>
7587 7588
   <token>SOME</token> is a synonym for <token>ANY</token>.
   <token>IN</token> is equivalent to <literal>= ANY</literal>.
7589 7590 7591 7592
  </para>

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

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

<synopsis>
7605 7606
(<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>)
7607 7608 7609
</synopsis>

  <para>
7610
   The right-hand side of this form of <token>ANY</token> is a parenthesized
7611 7612 7613 7614
   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,
7615
   only <literal>=</literal> and <literal>&lt;&gt;</literal> operators are allowed
7616
   in row-wise <token>ANY</token> constructs.
7617
   The result of <token>ANY</token> is <quote>true</> if any equal or unequal row is
7618
   found, respectively.
7619
   The result is <quote>false</> if no such row is found (including the special
7620 7621 7622 7623
   case where the subquery returns no rows).
  </para>

  <para>
7624
   As usual, null values in the rows are combined per
7625
   the normal rules of SQL Boolean expressions.  Two rows are considered
7626 7627
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
7628 7629 7630
   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. 
7631
  </para>
7632
  </sect2>
7633

7634
  <sect2>
7635
   <title><literal>ALL</literal></title>
7636 7637

<synopsis>
7638
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
7639 7640 7641
</synopsis>

  <para>
7642
   The right-hand side is a parenthesized
7643 7644
   subquery, which must return exactly one column.  The left-hand expression
   is evaluated and compared to each row of the subquery result using the
7645
   given <replaceable>operator</replaceable>, which must yield a Boolean
7646
   result.
7647
   The result of <token>ALL</token> is <quote>true</> if all rows yield true
7648
   (including the special case where the subquery returns no rows).
7649
   The result is <quote>false</> if any false result is found.
7650 7651 7652
  </para>

  <para>
7653
   <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
7654 7655 7656 7657
  </para>

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

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

7669
<synopsis>
7670
(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
7671
</synopsis>
7672 7673

  <para>
7674
   The right-hand side of this form of <token>ALL</token> is a parenthesized
7675 7676 7677 7678
   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,
7679 7680
   only <literal>=</literal> and <literal>&lt;&gt;</literal> operators are allowed
   in row-wise <token>ALL</token> queries.
7681
   The result of <token>ALL</token> is <quote>true</> if all subquery rows are equal
7682 7683
   or unequal, respectively (including the special
   case where the subquery returns no rows).
7684
   The result is <quote>false</> if any row is found to be unequal or equal,
7685 7686 7687 7688
   respectively.
  </para>

  <para>
7689
   As usual, null values in the rows are combined per
7690
   the normal rules of SQL Boolean expressions.  Two rows are considered
7691 7692
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
7693 7694 7695
   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. 
7696
  </para>
7697
  </sect2>
7698

7699 7700
  <sect2>
   <title>Row-wise Comparison</title>
7701

7702
<synopsis>
7703
(<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
7704
</synopsis>
7705 7706

  <para>
7707 7708
   The left-hand side is a list of scalar expressions.  The right-hand side is
   a parenthesized subquery, which must return exactly as many columns as there
7709 7710
   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
7711
   be null.)  The left-hand side is evaluated and compared row-wise to the
7712 7713 7714 7715 7716 7717 7718 7719 7720 7721 7722 7723 7724 7725 7726 7727 7728 7729 7730 7731 7732 7733 7734 7735 7736 7737 7738 7739 7740 7741 7742 7743 7744 7745 7746 7747 7748 7749 7750 7751 7752 7753 7754 7755 7756 7757 7758 7759 7760 7761 7762 7763 7764 7765 7766 7767 7768 7769 7770 7771 7772 7773 7774 7775 7776 7777 7778 7779 7780 7781 7782 7783 7784 7785 7786 7787 7788 7789 7790 7791 7792 7793 7794 7795 7796 7797 7798 7799 7800 7801 7802 7803 7804 7805 7806 7807 7808 7809 7810 7811 7812 7813 7814 7815 7816 7817 7818 7819 7820 7821 7822 7823 7824 7825 7826 7827 7828 7829 7830 7831 7832 7833 7834 7835 7836 7837 7838 7839 7840 7841 7842 7843 7844 7845 7846 7847 7848 7849 7850 7851 7852 7853 7854 7855 7856 7857 7858 7859 7860 7861 7862 7863 7864 7865 7866 7867 7868 7869 7870 7871 7872 7873 7874 7875 7876 7877 7878 7879 7880 7881 7882 7883 7884 7885 7886 7887 7888 7889 7890 7891
   single subquery result row.
   Presently, only <literal>=</literal> and <literal>&lt;&gt;</literal> operators are allowed
   in row-wise comparisons.
   The result is <quote>true</> if the two rows are equal or unequal, respectively.
  </para>

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


 <sect1 id="functions-comparisons">
  <title>Row and Array Comparisons</title>

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

  <para>
   This section describes several specialized constructs for making
   multiple comparisons between groups of values.  These forms are
   syntactically related to the subquery forms of the previous section,
   but do not involve subqueries.
   The forms involving array subexpressions are
   <productname>PostgreSQL</productname> extensions; the rest are
   <acronym>SQL</acronym>-compliant.
   All of the expression forms documented in this section return
   Boolean (true/false) results.
  </para>

  <sect2>
   <title><literal>IN</literal></title>

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

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

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

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

  <sect2>
   <title><literal>NOT IN</literal></title>

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

  <para>
   The right-hand side is a parenthesized list
   of scalar expressions.  The result is <quote>true</quote> if the left-hand expression's
   result is unequal to all of the right-hand expressions.  This is a shorthand
   notation for

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

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

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

  <sect2>
   <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>

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

  <para>
   The right-hand side is a parenthesized expression, which must yield an
   array value.
   The left-hand expression
   is evaluated and compared to each element of the array using the
   given <replaceable>operator</replaceable>, which must yield a Boolean
   result.
   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
   case where the array has zero elements).
  </para>

  <para>
   <token>SOME</token> is a synonym for <token>ANY</token>.
  </para>
  </sect2>

  <sect2>
   <title><literal>ALL</literal> (array)</title>

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

  <para>
   The right-hand side is a parenthesized expression, which must yield an
   array value.
   The left-hand expression
   is evaluated and compared to each element of the array using the
   given <replaceable>operator</replaceable>, which must yield a Boolean
   result.
   The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
   (including the special case where the array has zero elements).
   The result is <quote>false</> if any false result is found.
  </para>
  </sect2>

  <sect2>
   <title>Row-wise Comparison</title>

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

  <para>
   Each side is a list of scalar expressions; the two lists must be
   of the same length.  Each side is evaluated and they are compared
   row-wise.
7892
   Presently, only <literal>=</literal> and <literal>&lt;&gt;</literal> operators are allowed
7893
   in row-wise comparisons.
7894
   The result is <quote>true</> if the two rows are equal or unequal, respectively.
7895 7896 7897
  </para>

  <para>
7898
   As usual, null values in the rows are combined per
7899
   the normal rules of SQL Boolean expressions.  Two rows are considered
7900 7901
   equal if all their corresponding members are non-null and equal; the rows
   are unequal if any corresponding members are non-null and unequal;
7902
   otherwise the result of the row comparison is unknown (null).
7903
  </para>
7904
  </sect2>
7905 7906
 </sect1>

7907
</chapter>
7908

7909 7910
<!-- Keep this comment at the end of the file
Local variables:
Thomas G. Lockhart's avatar
Thomas G. Lockhart committed
7911
mode:sgml
7912
sgml-omittag:nil
7913 7914 7915 7916 7917 7918 7919 7920
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
7921
sgml-local-catalogs:("/usr/lib/sgml/catalog")
7922 7923 7924
sgml-local-ecat-files:nil
End:
-->