syntax.sgml 41.7 KB
Newer Older
1
<!--
2
$Header: /cvsroot/pgsql/doc/src/sgml/syntax.sgml,v 1.71 2002/10/20 05:05:46 tgl Exp $
3 4
-->

5 6
<chapter id="sql-syntax">
 <title>SQL Syntax</title>
7

8 9 10 11 12
 <indexterm zone="sql-syntax">
  <primary>syntax</primary>
  <secondary>SQL</secondary>
 </indexterm>

13 14 15 16 17 18 19 20 21 22 23 24
 <para>
  This chapter describes the syntax of SQL.  It forms the foundation
  for understanding the following chapters which will go into detail
  about how the SQL commands are applied to define and modify data.
 </para>

 <para>
  We also advise users who are already familiar with SQL to read this
  chapter carefully because there are several rules and concepts that
  are implemented inconsistently among SQL databases or that are
  specific to <productname>PostgreSQL</productname>.
 </para>
25

26 27 28
 <sect1 id="sql-syntax-lexical">
  <title>Lexical Structure</title>

29
  <para>
30 31
   SQL input consists of a sequence of
   <firstterm>commands</firstterm>.  A command is composed of a
32 33 34 35
   sequence of <firstterm>tokens</firstterm>, terminated by a
   semicolon (<quote>;</quote>).  The end of the input stream also
   terminates a command.  Which tokens are valid depends on the syntax
   of the particular command.
36 37
  </para>

38 39 40 41 42 43 44 45 46
  <para>
   A token can be a <firstterm>key word</firstterm>, an
   <firstterm>identifier</firstterm>, a <firstterm>quoted
   identifier</firstterm>, a <firstterm>literal</firstterm> (or
   constant), or a special character symbol.  Tokens are normally
   separated by whitespace (space, tab, newline), but need not be if
   there is no ambiguity (which is generally only the case if a
   special character is adjacent to some other token type).
  </para>
47

48 49 50 51 52 53
  <para>
   Additionally, <firstterm>comments</firstterm> can occur in SQL
   input.  They are not tokens, they are effectively equivalent to
   whitespace.
  </para>

54
   <para>
55
    For example, the following is (syntactically) valid SQL input:
56 57 58 59 60 61 62
<programlisting>
SELECT * FROM MY_TABLE;
UPDATE MY_TABLE SET A = 5;
INSERT INTO MY_TABLE VALUES (3, 'hi there');
</programlisting>
    This is a sequence of three commands, one per line (although this
    is not required; more than one command can be on a line, and
63
    commands can usefully be split across lines).
64
   </para>
65 66 67 68 69 70 71 72 73 74 75

  <para>
   The SQL syntax is not very consistent regarding what tokens
   identify commands and which are operands or parameters.  The first
   few tokens are generally the command name, so in the above example
   we would usually speak of a <quote>SELECT</quote>, an
   <quote>UPDATE</quote>, and an <quote>INSERT</quote> command.  But
   for instance the <command>UPDATE</command> command always requires
   a <token>SET</token> token to appear in a certain position, and
   this particular variation of <command>INSERT</command> also
   requires a <token>VALUES</token> in order to be complete.  The
76 77
   precise syntax rules for each command are described in
   &cite-reference;.
78 79 80 81
  </para>

  <sect2 id="sql-syntax-identifiers">
   <title>Identifiers and Key Words</title>
82

83 84 85 86 87 88 89 90 91
   <indexterm zone="sql-syntax-identifiers">
    <primary>identifiers</primary>
   </indexterm>

   <indexterm zone="sql-syntax-identifiers">
    <primary>key words</primary>
    <secondary>syntax</secondary>
   </indexterm>

92
   <para>
93 94 95 96 97 98 99 100 101 102 103 104 105
    Tokens such as <token>SELECT</token>, <token>UPDATE</token>, or
    <token>VALUES</token> in the example above are examples of
    <firstterm>key words</firstterm>, that is, words that have a fixed
    meaning in the SQL language.  The tokens <token>MY_TABLE</token>
    and <token>A</token> are examples of
    <firstterm>identifiers</firstterm>.  They identify names of
    tables, columns, or other database objects, depending on the
    command they are used in.  Therefore they are sometimes simply
    called <quote>names</quote>.  Key words and identifiers have the
    same lexical structure, meaning that one cannot know whether a
    token is an identifier or a key word without knowing the language.
    A complete list of key words can be found in <xref
    linkend="sql-keywords-appendix">.
106 107 108
   </para>

   <para>
109
    SQL identifiers and key words must begin with a letter
P
Peter Eisentraut 已提交
110 111
    (<literal>a</literal>-<literal>z</literal>, but also letters with
    diacritical marks and non-Latin letters) or an underscore
112 113 114 115
    (<literal>_</literal>).  Subsequent characters in an identifier or
    key word can be letters, digits
    (<literal>0</literal>-<literal>9</literal>), or underscores,
    although the SQL standard will not define a key word that contains
116
    digits or starts or ends with an underscore.
117 118
   </para>

119
   <para>
120 121 122
    The system uses no more than <symbol>NAMEDATALEN</symbol>-1
    characters of an identifier; longer names can be written in
    commands, but they will be truncated.  By default,
123 124
    <symbol>NAMEDATALEN</symbol> is 64 so the maximum identifier length
    is 63 (but at the time the system is built,
125 126
    <symbol>NAMEDATALEN</symbol> can be changed in
    <filename>src/include/postgres_ext.h</filename>).
127
   </para>
128

129
   <para>
130 131 132 133
    <indexterm>
     <primary>case sensitivity</primary>
     <secondary>SQL commands</secondary>
    </indexterm>
134 135 136 137 138 139 140 141
    Identifier and key word names are case insensitive.  Therefore
<programlisting>
UPDATE MY_TABLE SET A = 5;
</programlisting>
    can equivalently be written as
<programlisting>
uPDaTE my_TabLE SeT a = 5;
</programlisting>
142
    A convention often used is to write key words in upper
143 144 145 146
    case and names in lower case, e.g.,
<programlisting>
UPDATE my_table SET a = 5;
</programlisting>
147 148 149
   </para>

   <para>
150 151 152 153
    <indexterm>
     <primary>quotes</primary>
     <secondary>and identifiers</secondary>
    </indexterm>
154 155 156 157 158 159 160 161
    There is a second kind of identifier:  the <firstterm>delimited
    identifier</firstterm> or <firstterm>quoted
    identifier</firstterm>.  It is formed by enclosing an arbitrary
    sequence of characters in double-quotes
    (<literal>"</literal>). <!-- " font-lock mania --> A delimited
    identifier is always an identifier, never a key word.  So
    <literal>"select"</literal> could be used to refer to a column or
    table named <quote>select</quote>, whereas an unquoted
162
    <literal>select</literal> would be taken as a key word and
163 164
    would therefore provoke a parse error when used where a table or
    column name is expected.  The example can be written with quoted
165
    identifiers like this:
166 167 168
<programlisting>
UPDATE "my_table" SET "a" = 5;
</programlisting>
169 170 171
   </para>

   <para>
172 173 174 175
    Quoted identifiers can contain any character other than a double
    quote itself.  This allows constructing table or column names that
    would otherwise not be possible, such as ones containing spaces or
    ampersands.  The length limitation still applies.
176
   </para>
177 178

   <para>
179 180 181 182
    Quoting an identifier also makes it case-sensitive, whereas
    unquoted names are always folded to lower case.  For example, the
    identifiers <literal>FOO</literal>, <literal>foo</literal> and
    <literal>"foo"</literal> are considered the same by
183
    <productname>PostgreSQL</productname>, but <literal>"Foo"</literal>
184 185 186 187
    and <literal>"FOO"</literal> are different from these three and
    each other.
    <footnote>
     <para>
188 189
      The folding of unquoted names to lower case in <productname>PostgreSQL</>
      is incompatible with the SQL standard, which says that unquoted
190 191 192 193 194
      names should be folded to upper case.  Thus, <literal>foo</literal>
      should be equivalent to <literal>"FOO"</literal> not
      <literal>"foo"</literal> according to the standard.  If you want to
      write portable applications you are advised to always quote a particular
      name or never quote it.
195 196
     </para>
    </footnote>
197
   </para>
198 199
  </sect2>

200

201
  <sect2 id="sql-syntax-constants">
202 203
   <title>Constants</title>

204 205 206 207
   <indexterm zone="sql-syntax-constants">
    <primary>constants</primary>
   </indexterm>

208
   <para>
209
    There are three kinds of <firstterm>implicitly-typed
210
    constants</firstterm> in <productname>PostgreSQL</productname>:
211
    strings, bit strings, and numbers.
212 213 214
    Constants can also be specified with explicit types, which can
    enable more accurate representation and more efficient handling by
    the system. The implicit constants are described below; explicit
215
    constants are discussed afterwards.
216 217
   </para>

218
   <sect3 id="sql-syntax-strings">
219 220
    <title>String Constants</title>

221 222 223 224 225
    <indexterm zone="sql-syntax-strings">
     <primary>character strings</primary>
     <secondary>constants</secondary>
    </indexterm>

226
    <para>
227 228 229 230
     <indexterm>
      <primary>quotes</primary>
      <secondary>escaping</secondary>
     </indexterm>
231 232 233 234 235
     A string constant in SQL is an arbitrary sequence of characters
     bounded by single quotes (<quote>'</quote>), e.g., <literal>'This
     is a string'</literal>.  SQL allows single quotes to be embedded
     in strings by typing two adjacent single quotes (e.g.,
     <literal>'Dianne''s horse'</literal>).  In
236
     <productname>PostgreSQL</productname> single quotes may
237 238 239 240 241 242 243 244 245 246 247 248 249
     alternatively be escaped with a backslash (<quote>\</quote>,
     e.g., <literal>'Dianne\'s horse'</literal>).
    </para>

    <para>
     C-style backslash escapes are also available:
     <literal>\b</literal> is a backspace, <literal>\f</literal> is a
     form feed, <literal>\n</literal> is a newline,
     <literal>\r</literal> is a carriage return, <literal>\t</literal>
     is a tab, and <literal>\<replaceable>xxx</replaceable></literal>,
     where <replaceable>xxx</replaceable> is an octal number, is the
     character with the corresponding ASCII code.  Any other character
     following a backslash is taken literally.  Thus, to include a
250
     backslash in a string constant, type two backslashes.
251 252
    </para>

253 254 255
    <para>
     The character with the code zero cannot be in a string constant.
    </para>
256

257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273
    <para>
     Two string constants that are only separated by whitespace
     <emphasis>with at least one newline</emphasis> are concatenated
     and effectively treated as if the string had been written in one
     constant.  For example:
<programlisting>
SELECT 'foo'
'bar';
</programlisting>
     is equivalent to
<programlisting>
SELECT 'foobar';
</programlisting>
     but
<programlisting>
SELECT 'foo'      'bar';
</programlisting>
274 275 276
     is not valid syntax.  (This slightly bizarre behavior is specified
     by <acronym>SQL9x</acronym>; <productname>PostgreSQL</productname> is
     following the standard.)
277 278 279
    </para>
   </sect3>

280
   <sect3 id="sql-syntax-bit-strings">
P
Peter Eisentraut 已提交
281
    <title>Bit-String Constants</title>
282

283 284 285 286 287
    <indexterm zone="sql-syntax-bit-strings">
     <primary>bit strings</primary>
     <secondary>constants</secondary>
    </indexterm>

288
    <para>
P
Peter Eisentraut 已提交
289
     Bit-string constants look like string constants with a
290 291 292
     <literal>B</literal> (upper or lower case) immediately before the
     opening quote (no intervening whitespace), e.g.,
     <literal>B'1001'</literal>.  The only characters allowed within
P
Peter Eisentraut 已提交
293
     bit-string constants are <literal>0</literal> and
294
     <literal>1</literal>.
295
    </para>
296

297 298 299 300 301 302
    <para>
     Alternatively, bit-string constants can be specified in hexadecimal
     notation, using a leading <literal>X</literal> (upper or lower case),
     e.g., <literal>X'1FF'</literal>.  This notation is equivalent to
     a bit-string constant with four binary digits for each hex digit.
    </para>
303 304

    <para>
305 306
     Both forms of bit-string constant can be continued
     across lines in the same way as regular string constants.
307 308
    </para>
   </sect3>
309

310
   <sect3>
311
    <title>Numeric Constants</title>
312

313
    <indexterm>
314
     <primary>numeric</primary>
315 316 317
     <secondary>constants</secondary>
    </indexterm>

318
    <para>
319
     Numeric constants are accepted in these general forms:
320
<synopsis>
321
<replaceable>digits</replaceable>
322 323 324 325 326
<replaceable>digits</replaceable>.<optional><replaceable>digits</replaceable></optional><optional>e<optional>+-</optional><replaceable>digits</replaceable></optional>
<optional><replaceable>digits</replaceable></optional>.<replaceable>digits</replaceable><optional>e<optional>+-</optional><replaceable>digits</replaceable></optional>
<replaceable>digits</replaceable>e<optional>+-</optional><replaceable>digits</replaceable>
</synopsis>
     where <replaceable>digits</replaceable> is one or more decimal
327 328 329 330 331 332 333
     digits (0 through 9).  At least one digit must be before or after the
     decimal point, if one is used.  At least one digit must follow the
     exponent marker (<literal>e</literal>), if one is present.
     There may not be any spaces or other characters embedded in the
     constant.  Notice that any leading plus or minus sign is not actually
     considered part of the constant; it is an operator applied to the
     constant.
334 335
    </para>

336
    <para>
337
     These are some examples of valid numeric constants:
338
<literallayout>
339
42
340 341 342 343 344
3.5
4.
.001
5e2
1.925e-3
345 346
</literallayout>
    </para>
347

348
    <para>
349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367
     A numeric constant that contains neither a decimal point nor an
     exponent is initially presumed to be type <type>integer</> if its
     value fits in type <type>integer</> (32 bits); otherwise it is
     presumed to be type <type>bigint</> if its
     value fits in type <type>bigint</> (64 bits); otherwise it is
     taken to be type <type>numeric</>.  Constants that contain	decimal
     points and/or exponents are always initially presumed to be type
     <type>numeric</>.
    </para>

    <para>
     The initially assigned data type of a numeric constant is just a
     starting point for the type resolution algorithms.  In most
     cases the constant will be automatically coerced to the most
     appropriate type depending on context.  When necessary, you
     can force a numeric value to be interpreted as a specific
     data type by casting it.  For example, you can force a numeric
     value to be treated as type <type>real</> (<type>float4</>)
     by writing
368

369
<programlisting>
370
REAL '1.23'  -- string style
371
1.23::REAL   -- PostgreSQL (historical) style
372
</programlisting>
373 374
     </para>
    </sect3>
375

376
   <sect3 id="sql-syntax-constants-generic">
377
    <title>Constants of Other Types</title>
378

379 380 381 382 383
    <indexterm>
     <primary>data types</primary>
     <secondary>constants</secondary>
    </indexterm>

384
    <para>
385 386 387
     A constant of an <emphasis>arbitrary</emphasis> type can be
     entered using any one of the following notations:
<synopsis>
388 389
<replaceable>type</replaceable> '<replaceable>string</replaceable>'
'<replaceable>string</replaceable>'::<replaceable>type</replaceable>
390
CAST ( '<replaceable>string</replaceable>' AS <replaceable>type</replaceable> )
391
</synopsis>
392
     The string's text is passed to the input conversion
393 394 395 396 397 398
     routine for the type called <replaceable>type</replaceable>. The
     result is a constant of the indicated type.  The explicit type
     cast may be omitted if there is no ambiguity as to the type the
     constant must be (for example, when it is passed as an argument
     to a non-overloaded function), in which case it is automatically
     coerced.
399
    </para>
400 401 402 403

    <para>
     It is also possible to specify a type coercion using a function-like
     syntax:
404
<synopsis>
405
<replaceable>typename</replaceable> ( '<replaceable>string</replaceable>' )
406
</synopsis>
407 408
     but not all type names may be used in this way; see <xref
     linkend="sql-syntax-type-casts"> for details.
409 410 411
    </para>

    <para>
412
     The <literal>::</literal>, <literal>CAST()</literal>, and
413
     function-call syntaxes can also be used to specify run-time type
414 415 416 417 418 419 420 421
     conversions of arbitrary expressions, as discussed in <xref
     linkend="sql-syntax-type-casts">.  But the form
     <replaceable>type</replaceable> '<replaceable>string</replaceable>'
     can only be used to specify the type of a literal constant.
     Another restriction on
     <replaceable>type</replaceable> '<replaceable>string</replaceable>'
     is that it does not work for array types; use <literal>::</literal>
     or <literal>CAST()</literal> to specify the type of an array constant.
422
    </para>
423
   </sect3>
424

425
   <sect3>
426 427
    <title>Array constants</title>

428 429 430 431 432
    <indexterm>
     <primary>arrays</primary>
     <secondary>constants</secondary>
    </indexterm>

433
    <para>
434
     The general format of an array constant is the following:
435 436 437 438 439 440
<synopsis>
'{ <replaceable>val1</replaceable> <replaceable>delim</replaceable> <replaceable>val2</replaceable> <replaceable>delim</replaceable> ... }'
</synopsis>
     where <replaceable>delim</replaceable> is the delimiter character
     for the type, as recorded in its <literal>pg_type</literal>
     entry.  (For all built-in types, this is the comma character
441
     <quote><literal>,</literal></>.)  Each <replaceable>val</replaceable> is either a constant
P
Peter Eisentraut 已提交
442
     of the array element type, or a subarray.  An example of an
443 444 445 446
     array constant is
<programlisting>
'{{1,2,3},{4,5,6},{7,8,9}}'
</programlisting>
P
Peter Eisentraut 已提交
447 448
     This constant is a two-dimensional, 3-by-3 array consisting of three
     subarrays of integers.
449 450 451
    </para>

    <para>
452
     Individual array elements can be placed between double-quote
453
     marks (<literal>"</literal>) <!-- " --> to avoid ambiguity
P
Peter Eisentraut 已提交
454 455
     problems with respect to whitespace.  Without quote marks, the
     array-value parser will skip leading whitespace.
456 457
    </para>

458 459 460 461 462 463 464 465 466 467 468 469 470 471
    <para>
     (Array constants are actually only a special case of the generic
     type constants discussed in the previous section.  The constant
     is initially treated as a string and passed to the array input
     conversion routine.  An explicit type specification might be
     necessary.)
    </para>
   </sect3>
  </sect2>


  <sect2 id="sql-syntax-operators">
   <title>Operators</title>

472 473 474 475 476
   <indexterm zone="sql-syntax-operators">
    <primary>operators</primary>
    <secondary>syntax</secondary>
   </indexterm>

477 478
   <para>
    An operator is a sequence of up to <symbol>NAMEDATALEN</symbol>-1
479
    (63 by default) characters from the following list:
480 481 482 483 484 485 486 487
<literallayout>
+ - * / &lt; &gt; = ~ ! @ # % ^ &amp; | ` ? $
</literallayout>

    There are a few restrictions on operator names, however:
    <itemizedlist>
     <listitem>
      <para>
488
       <literal>$</> (dollar) cannot be a single-character operator, although it
489
       can be part of a multiple-character operator name.
490 491 492 493 494 495 496 497 498 499 500 501 502
      </para>
     </listitem>

     <listitem>
      <para>
       <literal>--</literal> and <literal>/*</literal> cannot appear
       anywhere in an operator name, since they will be taken as the
       start of a comment.
      </para>
     </listitem>

     <listitem>
      <para>
503
       A multiple-character operator name cannot end in <literal>+</> or <literal>-</>,
504 505 506 507 508 509
       unless the name also contains at least one of these characters:
<literallayout>
~ ! @ # % ^ &amp; | ` ? $
</literallayout>
       For example, <literal>@-</literal> is an allowed operator name,
       but <literal>*-</literal> is not.  This restriction allows
510
       <productname>PostgreSQL</productname> to parse SQL-compliant
511 512 513 514 515 516 517 518 519
       queries without requiring spaces between tokens.
      </para>
     </listitem>
    </itemizedlist>
   </para>

   <para>
    When working with non-SQL-standard operator names, you will usually
    need to separate adjacent operators with spaces to avoid ambiguity.
P
Peter Eisentraut 已提交
520
    For example, if you have defined a left unary operator named <literal>@</literal>,
521 522
    you cannot write <literal>X*@Y</literal>; you must write
    <literal>X* @Y</literal> to ensure that
523
    <productname>PostgreSQL</productname> reads it as two operator names
524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574
    not one.
   </para>
  </sect2>

  <sect2>
   <title>Special Characters</title>

  <para>
   Some characters that are not alphanumeric have a special meaning
   that is different from being an operator.  Details on the usage can
   be found at the location where the respective syntax element is
   described.  This section only exists to advise the existence and
   summarize the purposes of these characters.

   <itemizedlist>
    <listitem>
     <para>
      A dollar sign (<literal>$</literal>) followed by digits is used
      to represent the positional parameters in the body of a function
      definition.  In other contexts the dollar sign may be part of an
      operator name.
     </para>
    </listitem>

    <listitem>
     <para>
      Parentheses (<literal>()</literal>) have their usual meaning to
      group expressions and enforce precedence.  In some cases
      parentheses are required as part of the fixed syntax of a
      particular SQL command.
     </para>
    </listitem>

    <listitem>
     <para>
      Brackets (<literal>[]</literal>) are used to select the elements
      of an array.  See <xref linkend="arrays"> for more information
      on arrays.
     </para>
    </listitem>

    <listitem>
     <para>
      Commas (<literal>,</literal>) are used in some syntactical
      constructs to separate the elements of a list.
     </para>
    </listitem>

    <listitem>
     <para>
      The semicolon (<literal>;</literal>) terminates an SQL command.
575 576
      It cannot appear anywhere within a command, except within a
      string constant or quoted identifier.
577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598
     </para>
    </listitem>

    <listitem>
     <para>
      The colon (<literal>:</literal>) is used to select
      <quote>slices</quote> from arrays. (See <xref
      linkend="arrays">.)  In certain SQL dialects (such as Embedded
      SQL), the colon is used to prefix variable names.
     </para>
    </listitem>

    <listitem>
     <para>
      The asterisk (<literal>*</literal>) has a special meaning when
      used in the <command>SELECT</command> command or with the
      <function>COUNT</function> aggregate function.
     </para>
    </listitem>

    <listitem>
     <para>
P
Peter Eisentraut 已提交
599
      The period (<literal>.</literal>) is used in floating-point
600
      constants, and to separate schema, table, and column names.
601 602 603 604 605 606 607 608 609 610
     </para>
    </listitem>
   </itemizedlist>

   </para>
  </sect2>

  <sect2 id="sql-syntax-comments">
   <title>Comments</title>

611 612 613 614 615
   <indexterm zone="sql-syntax-comments">
    <primary>comments</primary>
    <secondary>in SQL</secondary>
   </indexterm>

616 617 618 619 620 621 622 623 624 625 626
   <para>
    A comment is an arbitrary sequence of characters beginning with
    double dashes and extending to the end of the line, e.g.:
<programlisting>
-- This is a standard SQL92 comment
</programlisting>
   </para>

   <para>
    Alternatively, C-style block comments can be used:
<programlisting>
627
/* multiline comment
628 629 630 631 632 633 634 635 636 637 638 639 640 641 642
 * with nesting: /* nested block comment */
 */
</programlisting>
    where the comment begins with <literal>/*</literal> and extends to
    the matching occurrence of <literal>*/</literal>. These block
    comments nest, as specified in SQL99 but unlike C, so that one can
    comment out larger blocks of code that may contain existing block
    comments.
   </para>

   <para>
    A comment is removed from the input stream before further syntax
    analysis and is effectively replaced by whitespace.
   </para>
  </sect2>
643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733

  <sect2 id="sql-precedence">
   <title>Lexical Precedence</title>

   <indexterm zone="sql-precedence">
    <primary>operators</primary>
    <secondary>precedence</secondary>
   </indexterm>

   <para>
    The precedence and associativity of the operators is hard-wired
    into the parser.  Most operators have the same precedence and are
    left-associative.  This may lead to non-intuitive behavior; for
    example the Boolean operators <literal>&lt;</> and <literal>&gt;</> have a different
    precedence than the Boolean operators <literal>&lt;=</> and <literal>&gt;=</>.  Also,
    you will sometimes need to add parentheses when using combinations
    of binary and unary operators.  For instance
<programlisting>
SELECT 5 ! - 6;
</programlisting>
   will be parsed as
<programlisting>
SELECT 5 ! (- 6);
</programlisting>
    because the parser has no idea -- until it is too late -- that
    <token>!</token> is defined as a postfix operator, not an infix one.
    To get the desired behavior in this case, you must write
<programlisting>
SELECT (5 !) - 6;
</programlisting>
    This is the price one pays for extensibility.
   </para>

   <table tocentry="1">
    <title>Operator Precedence (decreasing)</title>

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

     <tbody>
      <row>
       <entry><token>.</token></entry>
       <entry>left</entry>
       <entry>table/column name separator</entry>
      </row>

      <row>
       <entry><token>::</token></entry>
       <entry>left</entry>
       <entry><productname>PostgreSQL</productname>-style typecast</entry>
      </row>

      <row>
       <entry><token>[</token> <token>]</token></entry>
       <entry>left</entry>
       <entry>array element selection</entry>
      </row>

      <row>
       <entry><token>-</token></entry>
       <entry>right</entry>
       <entry>unary minus</entry>
      </row>

      <row>
       <entry><token>^</token></entry>
       <entry>left</entry>
       <entry>exponentiation</entry>
      </row>

      <row>
       <entry><token>*</token> <token>/</token> <token>%</token></entry>
       <entry>left</entry>
       <entry>multiplication, division, modulo</entry>
      </row>

      <row>
       <entry><token>+</token> <token>-</token></entry>
       <entry>left</entry>
       <entry>addition, subtraction</entry>
      </row>

      <row>
       <entry><token>IS</token></entry>
       <entry></entry>
P
Peter Eisentraut 已提交
734
       <entry><literal>IS TRUE</>, <literal>IS FALSE</>, <literal>IS UNKNOWN</>, <literal>IS NULL</></entry>
735 736 737 738 739
      </row>

      <row>
       <entry><token>ISNULL</token></entry>
       <entry></entry>
P
Peter Eisentraut 已提交
740
       <entry>test for null</entry>
741 742 743 744 745
      </row>

      <row>
       <entry><token>NOTNULL</token></entry>
       <entry></entry>
P
Peter Eisentraut 已提交
746
       <entry>test for not null</entry>
747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773
      </row>

      <row>
       <entry>(any other)</entry>
       <entry>left</entry>
       <entry>all other native and user-defined operators</entry>
      </row>

      <row>
       <entry><token>IN</token></entry>
       <entry></entry>
       <entry>set membership</entry>
      </row>

      <row>
       <entry><token>BETWEEN</token></entry>
       <entry></entry>
       <entry>containment</entry>
      </row>

      <row>
       <entry><token>OVERLAPS</token></entry>
       <entry></entry>
       <entry>time interval overlap</entry>
      </row>

      <row>
774
       <entry><token>LIKE</token> <token>ILIKE</token> <token>SIMILAR</token></entry>
775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819
       <entry></entry>
       <entry>string pattern matching</entry>
      </row>

      <row>
       <entry><token>&lt;</token> <token>&gt;</token></entry>
       <entry></entry>
       <entry>less than, greater than</entry>
      </row>

      <row>
       <entry><token>=</token></entry>
       <entry>right</entry>
       <entry>equality, assignment</entry>
      </row>

      <row>
       <entry><token>NOT</token></entry>
       <entry>right</entry>
       <entry>logical negation</entry>
      </row>

      <row>
       <entry><token>AND</token></entry>
       <entry>left</entry>
       <entry>logical conjunction</entry>
      </row>

      <row>
       <entry><token>OR</token></entry>
       <entry>left</entry>
       <entry>logical disjunction</entry>
      </row>
     </tbody>
    </tgroup>
   </table>

   <para>
    Note that the operator precedence rules also apply to user-defined
    operators that have the same names as the built-in operators
    mentioned above.  For example, if you define a
    <quote>+</quote> operator for some custom data type it will have
    the same precedence as the built-in <quote>+</quote> operator, no
    matter what yours does.
   </para>
820 821 822 823 824 825 826 827 828 829 830

   <para>
    When a schema-qualified operator name is used in the
    <literal>OPERATOR</> syntax, as for example in
<programlisting>
SELECT 3 OPERATOR(pg_catalog.+) 4;
</programlisting>
    the <literal>OPERATOR</> construct is taken to have the default precedence
    shown above for <quote>any other</> operator.  This is true no matter
    which specific operator name appears inside <literal>OPERATOR()</>.
   </para>
831
  </sect2>
832 833
 </sect1>

834 835
 <sect1 id="sql-expressions">
  <title>Value Expressions</title>
836

837
  <para>
838
   Value expressions are used in a variety of contexts, such
839 840 841 842 843 844 845 846 847 848 849
   as in the target list of the <command>SELECT</command> command, as
   new column values in <command>INSERT</command> or
   <command>UPDATE</command>, or in search conditions in a number of
   commands.  The result of a value expression is sometimes called a
   <firstterm>scalar</firstterm>, to distinguish it from the result of
   a table expression (which is a table).  Value expressions are
   therefore also called <firstterm>scalar expressions</firstterm> (or
   even simply <firstterm>expressions</firstterm>).  The expression
   syntax allows the calculation of values from primitive parts using
   arithmetic, logical, set, and other operations.
  </para>
850

851 852
  <para>
   A value expression is one of the following:
853

854 855 856 857 858 859
   <itemizedlist>
    <listitem>
     <para>
      A constant or literal value; see <xref linkend="sql-syntax-constants">.
     </para>
    </listitem>
860

861 862
    <listitem>
     <para>
863
      A column reference.
864 865
     </para>
    </listitem>
866

867 868
    <listitem>
     <para>
869
      A positional parameter reference, in the body of a function declaration.
870 871
     </para>
    </listitem>
872

873
    <listitem>
874
     <para>
875
      An operator invocation.
876 877
     </para>
    </listitem>
878

879 880
    <listitem>
     <para>
881
      A function call.
882 883
     </para>
    </listitem>
884

885 886
    <listitem>
     <para>
887
      An aggregate expression.
888 889
     </para>
    </listitem>
890

891 892
    <listitem>
     <para>
893
      A type cast.
894 895
     </para>
    </listitem>
896

897 898
    <listitem>
     <para>
899 900 901 902 903 904 905 906
      A scalar subquery.
     </para>
    </listitem>

    <listitem>
<synopsis>( <replaceable>expression</replaceable> )</synopsis>
     <para>
      Parentheses are used to group subexpressions and override precedence.
907 908 909 910
     </para>
    </listitem>
   </itemizedlist>
  </para>
911

912
  <para>
913
   In addition to this list, there are a number of constructs that can
914 915 916 917 918 919
   be classified as an expression but do not follow any general syntax
   rules.  These generally have the semantics of a function or
   operator and are explained in the appropriate location in <xref
   linkend="functions">.  An example is the <literal>IS NULL</literal>
   clause.
  </para>
920

921 922 923 924 925
  <para>
   We have already discussed constants in <xref
   linkend="sql-syntax-constants">.  The following sections discuss
   the remaining options.
  </para>
926

927 928
  <sect2>
   <title>Column References</title>
929

930 931 932
   <para>
    A column can be referenced in the form:
<synopsis>
933
<replaceable>correlation</replaceable>.<replaceable>columnname</replaceable> `['<replaceable>subscript</replaceable>`]'
934
</synopsis>
935

T
Tom Lane 已提交
936 937 938
    <replaceable>correlation</replaceable> is the name of a
    table (possibly qualified), or an alias for a table defined by means of a
    FROM clause, or 
P
Peter Eisentraut 已提交
939
    the key words <literal>NEW</literal> or <literal>OLD</literal>.
940
    (NEW and OLD can only appear in rules,
941
    while other correlation names can be used in any SQL statement.)
942 943
    The correlation name and separating dot may be omitted if the column name
    is unique 
944 945 946
    across all the tables being used in the current query.  If
    <replaceable>column</replaceable> is of an array type, then the
    optional <replaceable>subscript</replaceable> selects a specific
947 948 949
    element or elements in the array.  If no subscript is provided, then the
    whole array is selected.  (See <xref linkend="arrays"> for more about
    arrays.)
950 951
   </para>
  </sect2>
952

953 954
  <sect2>
   <title>Positional Parameters</title>
955

956 957
   <para>
    A positional parameter reference is used to indicate a parameter
958 959 960
    that is supplied externally to an SQL statement.  Parameters are
    used in SQL function definitions and in prepared queries.
    The form of a parameter reference is:
961 962 963 964
<synopsis>
$<replaceable>number</replaceable>
</synopsis>
   </para>
965

966 967 968
   <para>
    For example, consider the definition of a function,
    <function>dept</function>, as
969

970 971
<programlisting>
CREATE FUNCTION dept (text) RETURNS dept
972
  AS 'SELECT * FROM dept WHERE name = $1'
P
Peter Eisentraut 已提交
973
  LANGUAGE SQL;
974
</programlisting>
975

976 977 978 979
    Here the <literal>$1</literal> will be replaced by the first
    function argument when the function is invoked.
   </para>
  </sect2>
980

981 982 983 984 985 986 987 988 989 990 991
  <sect2>
   <title>Operator Invocations</title>

   <para>
    There are three possible syntaxes for an operator invocation:
    <simplelist>
     <member><replaceable>expression</replaceable> <replaceable>operator</replaceable> <replaceable>expression</replaceable> (binary infix operator)</member>
     <member><replaceable>operator</replaceable> <replaceable>expression</replaceable> (unary prefix operator)</member>
     <member><replaceable>expression</replaceable> <replaceable>operator</replaceable> (unary postfix operator)</member>
    </simplelist>
    where the <replaceable>operator</replaceable> token follows the syntax
T
Tom Lane 已提交
992 993 994 995 996 997 998
    rules of <xref linkend="sql-syntax-operators">, or is one of the
    keywords <token>AND</token>, <token>OR</token>, and
    <token>NOT</token>, or is a qualified operator name
<synopsis>
    <literal>OPERATOR(</><replaceable>schema</><literal>.</><replaceable>operatorname</><literal>)</>
</synopsis>
    Which particular operators exist and whether
999 1000 1001 1002 1003 1004
    they are unary or binary depends on what operators have been
    defined by the system or the user.  <xref linkend="functions">
    describes the built-in operators.
   </para>
  </sect2>

1005 1006
  <sect2>
   <title>Function Calls</title>
1007

1008
   <para>
1009
    The syntax for a function call is the name of a function
T
Tom Lane 已提交
1010
    (possibly qualified with a schema name), followed by its argument list
1011
    enclosed in parentheses:
1012

1013 1014 1015 1016
<synopsis>
<replaceable>function</replaceable> (<optional><replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ... </optional></optional> )
</synopsis>
   </para>
1017

1018 1019 1020 1021 1022 1023
   <para>
    For example, the following computes the square root of 2:
<programlisting>
sqrt(2)
</programlisting>
   </para>
1024

1025 1026 1027 1028 1029
   <para>
    The list of built-in functions is in <xref linkend="functions">.
    Other functions may be added by the user.
   </para>
  </sect2>
1030

1031 1032
  <sect2 id="syntax-aggregates">
   <title>Aggregate Expressions</title>
1033

1034 1035 1036 1037
   <indexterm zone="syntax-aggregates">
    <primary>aggregate functions</primary>
   </indexterm>

1038 1039 1040 1041 1042 1043
   <para>
    An <firstterm>aggregate expression</firstterm> represents the
    application of an aggregate function across the rows selected by a
    query.  An aggregate function reduces multiple inputs to a single
    output value, such as the sum or average of the inputs.  The
    syntax of an aggregate expression is one of the following:
1044

1045 1046 1047 1048 1049 1050
    <simplelist>
     <member><replaceable>aggregate_name</replaceable> (<replaceable>expression</replaceable>)</member>
     <member><replaceable>aggregate_name</replaceable> (ALL <replaceable>expression</replaceable>)</member>
     <member><replaceable>aggregate_name</replaceable> (DISTINCT <replaceable>expression</replaceable>)</member>
     <member><replaceable>aggregate_name</replaceable> ( * )</member>
    </simplelist>
1051

1052
    where <replaceable>aggregate_name</replaceable> is a previously
T
Tom Lane 已提交
1053 1054
    defined aggregate (possibly a qualified name), and
    <replaceable>expression</replaceable> is 
1055
    any value expression that does not itself contain an aggregate
1056 1057
    expression.
   </para>
1058

1059 1060 1061
   <para>
    The first form of aggregate expression invokes the aggregate
    across all input rows for which the given expression yields a
P
Peter Eisentraut 已提交
1062 1063
    non-null value.  (Actually, it is up to the aggregate function
    whether to ignore null values or not --- but all the standard ones do.)
1064
    The second form is the same as the first, since
1065
    <literal>ALL</literal> is the default.  The third form invokes the
P
Peter Eisentraut 已提交
1066
    aggregate for all distinct non-null values of the expression found
1067
    in the input rows.  The last form invokes the aggregate once for
P
Peter Eisentraut 已提交
1068
    each input row regardless of null or non-null values; since no
1069 1070 1071
    particular input value is specified, it is generally only useful
    for the <function>count()</function> aggregate function.
   </para>
1072

1073 1074 1075
   <para>
    For example, <literal>count(*)</literal> yields the total number
    of input rows; <literal>count(f1)</literal> yields the number of
P
Peter Eisentraut 已提交
1076
    input rows in which <literal>f1</literal> is non-null;
1077
    <literal>count(distinct f1)</literal> yields the number of
P
Peter Eisentraut 已提交
1078
    distinct non-null values of <literal>f1</literal>.
1079
   </para>
1080

1081 1082
   <para>
    The predefined aggregate functions are described in <xref
1083 1084
    linkend="functions-aggregate">.  Other aggregate functions may be added
    by the user. 
1085 1086
   </para>
  </sect2>
1087 1088 1089 1090 1091 1092 1093 1094 1095 1096

  <sect2 id="sql-syntax-type-casts">
   <title>Type Casts</title>

    <indexterm>
     <primary>data types</primary>
     <secondary>type casts</secondary>
    </indexterm>

   <para>
P
Peter Eisentraut 已提交
1097
    A type cast specifies a conversion from one data type to another.
1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116
    <productname>PostgreSQL</productname> accepts two equivalent syntaxes
    for type casts:
<synopsis>
CAST ( <replaceable>expression</replaceable> AS <replaceable>type</replaceable> )
<replaceable>expression</replaceable>::<replaceable>type</replaceable>
</synopsis>
    The <literal>CAST</> syntax conforms to SQL92; the syntax with
    <literal>::</literal> is historical <productname>PostgreSQL</productname>
    usage.
   </para>

   <para>
    When a cast is applied to a value expression of a known type, it
    represents a run-time type conversion.  The cast will succeed only
    if a suitable type conversion function is available.  Notice that this
    is subtly different from the use of casts with constants, as shown in
    <xref linkend="sql-syntax-constants-generic">.  A cast applied to an
    unadorned string literal represents the initial assignment of a type
    to a literal constant value, and so it will succeed for any type
P
Peter Eisentraut 已提交
1117 1118
    (if the contents of the string literal are acceptable input syntax for the
    data type).
1119 1120 1121
   </para>

   <para>
T
Tom Lane 已提交
1122 1123
    An explicit type cast may usually be omitted if there is no ambiguity as
    to the type that a value expression must produce (for example, when it is
1124
    assigned to a table column); the system will automatically apply a
T
Tom Lane 已提交
1125
    type cast in such cases.  However, automatic casting is only done for
P
Peter Eisentraut 已提交
1126
    cast functions that are marked <quote>OK to apply implicitly</>
T
Tom Lane 已提交
1127 1128 1129
    in the system catalogs.  Other cast functions must be invoked with
    explicit casting syntax.  This restriction is intended to prevent
    surprising conversions from being applied silently.
1130 1131 1132 1133 1134 1135 1136 1137 1138 1139 1140 1141 1142
   </para>

   <para>
    It is also possible to specify a type cast using a function-like
    syntax:
<synopsis>
<replaceable>typename</replaceable> ( <replaceable>expression</replaceable> )
</synopsis>
    However, this only works for types whose names are also valid as
    function names.  For example, <literal>double precision</literal>
    can't be used this way, but the equivalent <literal>float8</literal>
    can.  Also, the names <literal>interval</>, <literal>time</>, and
    <literal>timestamp</> can only be used in this fashion if they are
T
Tom Lane 已提交
1143
    double-quoted, because of syntactic conflicts.  Therefore, the use of
1144 1145 1146 1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157 1158 1159
    the function-like cast syntax leads to inconsistencies and should
    probably be avoided in new applications.
   </para>
  </sect2>

  <sect2>
   <title>Scalar Subqueries</title>

   <para>
    A scalar subquery is an ordinary
    <command>SELECT</command> in parentheses that returns exactly one
    row with one column.  The <command>SELECT</command> query is executed
    and the single returned value is used in the surrounding value expression.
    It is an error to use a query that
    returns more than one row or more than one column as a scalar subquery.
    (But if, during a particular execution, the subquery returns no rows,
P
Peter Eisentraut 已提交
1160
    there is no error; the scalar result is taken to be null.)
1161 1162 1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 1174
    The subquery can refer to variables from the surrounding query,
    which will act as constants during any one evaluation of the subquery.
    See also <xref linkend="functions-subquery">.
   </para>

   <para>
    For example, the following finds the largest city population in each
    state:
<programlisting>
SELECT name, (SELECT max(pop) FROM cities WHERE cities.state = states.name)
FROM states;
</programlisting>
   </para>
  </sect2>
1175

1176 1177
  <sect2>
   <title>Expression Evaluation</title>
1178

1179 1180
   <para>
    The order of evaluation of subexpressions is not defined.  In
1181 1182
    particular, the inputs of an operator or function are not necessarily
    evaluated left-to-right or in any other fixed order.
1183
   </para>
1184

1185
   <para>
1186
    Furthermore, if the result of an expression can be determined by
1187
    evaluating only some parts of it, then other subexpressions
1188
    might not be evaluated at all.  For instance, if one wrote
1189
<programlisting>
1190
SELECT true OR somefunc();
1191
</programlisting>
1192 1193
    then <literal>somefunc()</literal> would (probably) not be called
    at all. The same would be the case if one wrote
1194
<programlisting>
1195
SELECT somefunc() OR true;
1196
</programlisting>
1197 1198 1199
    Note that this is not the same as the left-to-right
    <quote>short-circuiting</quote> of Boolean operators that is found
    in some programming languages.
1200 1201 1202
   </para>

   <para>
1203
    As a consequence, it is unwise to use functions with side effects
1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216
    as part of complex expressions.  It is particularly dangerous to
    rely on side effects or evaluation order in WHERE and HAVING clauses,
    since those clauses are extensively reprocessed as part of
    developing an execution plan.  Boolean
    expressions (AND/OR/NOT combinations) in those clauses may be reorganized
    in any manner allowed by the laws of Boolean algebra.
   </para>

   <para>
    When it is essential to force evaluation order, a CASE construct may
    be used.  For example, this is an untrustworthy way of trying to
    avoid division by zero in a WHERE clause:
<programlisting>
T
Tom Lane 已提交
1217
SELECT ... WHERE x &lt;&gt; 0 AND y/x &gt; 1.5;
1218 1219 1220
</programlisting>
    but this is safe:
<programlisting>
T
Tom Lane 已提交
1221
SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
1222 1223 1224
</programlisting>
    A CASE construct used in this fashion will defeat optimization attempts,
    so it should only be done when necessary.
1225
   </para>
1226 1227
  </sect2>
 </sect1>
1228 1229

</chapter>
1230 1231 1232

<!-- Keep this comment at the end of the file
Local variables:
1233
mode:sgml
1234 1235 1236 1237 1238 1239 1240 1241 1242
sgml-omittag:nil
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
1243
sgml-local-catalogs:("/usr/lib/sgml/catalog")
1244 1245 1246
sgml-local-ecat-files:nil
End:
-->