select.sgml 45.7 KB
Newer Older
1
<!--
2
$PostgreSQL: pgsql/doc/src/sgml/ref/select.sgml,v 1.94 2006/12/01 20:49:53 tgl Exp $
3
PostgreSQL documentation
4 5
-->

6 7
<refentry id="SQL-SELECT">
 <refmeta>
8
  <refentrytitle id="sql-select-title">SELECT</refentrytitle>
9 10
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>
11

12
 <refnamediv>
13 14 15 16
  <refname>SELECT</refname>
  <refpurpose>retrieve rows from a table or view</refpurpose>
 </refnamediv>

P
Peter Eisentraut 已提交
17 18 19 20
 <indexterm zone="sql-select">
  <primary>SELECT</primary>
 </indexterm>

21
 <refsynopsisdiv>
22 23 24 25 26 27 28 29 30 31 32
<synopsis>
SELECT [ ALL | DISTINCT [ ON ( <replaceable class="parameter">expression</replaceable> [, ...] ) ] ]
    * | <replaceable class="parameter">expression</replaceable> [ AS <replaceable class="parameter">output_name</replaceable> ] [, ...]
    [ FROM <replaceable class="parameter">from_item</replaceable> [, ...] ]
    [ WHERE <replaceable class="parameter">condition</replaceable> ]
    [ GROUP BY <replaceable class="parameter">expression</replaceable> [, ...] ]
    [ HAVING <replaceable class="parameter">condition</replaceable> [, ...] ]
    [ { UNION | INTERSECT | EXCEPT } [ ALL ] <replaceable class="parameter">select</replaceable> ]
    [ ORDER BY <replaceable class="parameter">expression</replaceable> [ ASC | DESC | USING <replaceable class="parameter">operator</replaceable> ] [, ...] ]
    [ LIMIT { <replaceable class="parameter">count</replaceable> | ALL } ]
    [ OFFSET <replaceable class="parameter">start</replaceable> ]
33
    [ FOR { UPDATE | SHARE } [ OF <replaceable class="parameter">table_name</replaceable> [, ...] ] [ NOWAIT ] [...] ]
34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49

where <replaceable class="parameter">from_item</replaceable> can be one of:

    [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [ [ AS ] <replaceable class="parameter">alias</replaceable> [ ( <replaceable class="parameter">column_alias</replaceable> [, ...] ) ] ]
    ( <replaceable class="parameter">select</replaceable> ) [ AS ] <replaceable class="parameter">alias</replaceable> [ ( <replaceable class="parameter">column_alias</replaceable> [, ...] ) ]
    <replaceable class="parameter">function_name</replaceable> ( [ <replaceable class="parameter">argument</replaceable> [, ...] ] ) [ AS ] <replaceable class="parameter">alias</replaceable> [ ( <replaceable class="parameter">column_alias</replaceable> [, ...] | <replaceable class="parameter">column_definition</replaceable> [, ...] ) ]
    <replaceable class="parameter">function_name</replaceable> ( [ <replaceable class="parameter">argument</replaceable> [, ...] ] ) AS ( <replaceable class="parameter">column_definition</replaceable> [, ...] )
    <replaceable class="parameter">from_item</replaceable> [ NATURAL ] <replaceable class="parameter">join_type</replaceable> <replaceable class="parameter">from_item</replaceable> [ ON <replaceable class="parameter">join_condition</replaceable> | USING ( <replaceable class="parameter">join_column</replaceable> [, ...] ) ]
</synopsis>

 </refsynopsisdiv>

 <refsect1>
  <title>Description</title>

  <para>
B
Bruce Momjian 已提交
50
   <command>SELECT</command> retrieves rows from zero or more tables.
51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83
   The general processing of <command>SELECT</command> is as follows:

   <orderedlist>
    <listitem>
     <para>
      All elements in the <literal>FROM</literal> list are computed.
      (Each element in the <literal>FROM</literal> list is a real or
      virtual table.)  If more than one element is specified in the
      <literal>FROM</literal> list, they are cross-joined together.
      (See <xref linkend="sql-from" endterm="sql-from-title"> below.)
     </para>
    </listitem>

    <listitem>
     <para>
      If the <literal>WHERE</literal> clause is specified, all rows
      that do not satisfy the condition are eliminated from the
      output.  (See <xref linkend="sql-where"
      endterm="sql-where-title"> below.)
     </para>
    </listitem>

    <listitem>
     <para>
      If the <literal>GROUP BY</literal> clause is specified, the
      output is divided into groups of rows that match on one or more
      values.  If the <literal>HAVING</literal> clause is present, it
      eliminates groups that do not satisfy the given condition.  (See
      <xref linkend="sql-groupby" endterm="sql-groupby-title"> and
      <xref linkend="sql-having" endterm="sql-having-title"> below.)
     </para>
    </listitem>

T
Tom Lane 已提交
84 85 86 87 88 89 90 91 92 93
    <listitem>
     <para>
      The actual output rows are computed using the
      <command>SELECT</command> output expressions for each selected
      row.  (See
      <xref linkend="sql-select-list" endterm="sql-select-list-title">
      below.)
     </para>
    </listitem>

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
    <listitem>
     <para>
      Using the operators <literal>UNION</literal>,
      <literal>INTERSECT</literal>, and <literal>EXCEPT</literal>, the
      output of more than one <command>SELECT</command> statement can
      be combined to form a single result set.  The
      <literal>UNION</literal> operator returns all rows that are in
      one or both of the result sets.  The
      <literal>INTERSECT</literal> operator returns all rows that are
      strictly in both result sets.  The <literal>EXCEPT</literal>
      operator returns the rows that are in the first result set but
      not in the second.  In all three cases, duplicate rows are
      eliminated unless <literal>ALL</literal> is specified. (See
      <xref linkend="sql-union" endterm="sql-union-title">, <xref
      linkend="sql-intersect" endterm="sql-intersect-title">, and
      <xref linkend="sql-except" endterm="sql-except-title"> below.)
     </para>
    </listitem>

    <listitem>
     <para>
      If the <literal>ORDER BY</literal> clause is specified, the
      returned rows are sorted in the specified order.  If
      <literal>ORDER BY</literal> is not given, the rows are returned
      in whatever order the system finds fastest to produce.  (See
      <xref linkend="sql-orderby" endterm="sql-orderby-title"> below.)
     </para>
    </listitem>

    <listitem>
     <para>
      <literal>DISTINCT</literal> eliminates duplicate rows from the
      result.  <literal>DISTINCT ON</literal> eliminates rows that
      match on all the specified expressions.  <literal>ALL</literal>
      (the default) will return all candidate rows, including
      duplicates.  (See <xref linkend="sql-distinct"
      endterm="sql-distinct-title"> below.)
     </para>
    </listitem>

T
Tom Lane 已提交
134 135 136 137 138 139 140 141 142
    <listitem>
     <para>
      If the <literal>LIMIT</literal> or <literal>OFFSET</literal>
      clause is specified, the <command>SELECT</command> statement
      only returns a subset of the result rows. (See <xref
      linkend="sql-limit" endterm="sql-limit-title"> below.)
     </para>
    </listitem>

143 144
    <listitem>
     <para>
145 146
      If <literal>FOR UPDATE</literal> or <literal>FOR SHARE</literal>
      is specified, the
147 148 149
      <command>SELECT</command> statement locks the selected rows
      against concurrent updates.  (See <xref linkend="sql-for-update-share"
      endterm="sql-for-update-share-title"> below.)
150 151 152 153
     </para>
    </listitem>
   </orderedlist>
  </para>
154

155 156
  <para>
   You must have <literal>SELECT</literal> privilege on a table to
157 158
   read its values.  The use of <literal>FOR UPDATE</literal> or
   <literal>FOR SHARE</literal> requires
159 160 161 162 163 164 165 166 167
   <literal>UPDATE</literal> privilege as well.
  </para>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

  <refsect2 id="SQL-FROM">
   <title id="sql-from-title"><literal>FROM</literal> Clause</title>
168

169
   <para>
170 171 172 173 174 175 176 177 178
    The <literal>FROM</literal> clause specifies one or more source
    tables for the <command>SELECT</command>.  If multiple sources are
    specified, the result is the Cartesian product (cross join) of all
    the sources.  But usually qualification conditions
    are added to restrict the returned rows to a small subset of the
    Cartesian product.
   </para>

   <para>
179 180
    The <literal>FROM</literal> clause can contain the following
    elements:
181

182 183
    <variablelist>
     <varlistentry>
184
      <term><replaceable class="parameter">table_name</replaceable></term>
185 186
      <listitem>
       <para>
187 188 189 190 191 192 193 194
        The name (optionally schema-qualified) of an existing table or
        view.  If <literal>ONLY</> is specified, only that table is
        scanned.  If <literal>ONLY</> is not specified, the table and
        all its descendant tables (if any) are scanned.  <literal>*</>
        can be appended to the table name to indicate that descendant
        tables are to be scanned, but in the current version, this is
        the default behavior.  (In releases before 7.1,
        <literal>ONLY</> was the default behavior.)  The default
195 196
        behavior can be modified by changing the <xref
        linkend="guc-sql-inheritance"> configuration option.
197 198 199 200 201
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
202
      <term><replaceable class="parameter">alias</replaceable></term>
203 204
      <listitem>
       <para>
205 206 207 208 209 210 211 212 213 214
        A substitute name for the <literal>FROM</> item containing the
        alias.  An alias is used for brevity or to eliminate ambiguity
        for self-joins (where the same table is scanned multiple
        times).  When an alias is provided, it completely hides the
        actual name of the table or function; for example given
        <literal>FROM foo AS f</>, the remainder of the
        <command>SELECT</command> must refer to this <literal>FROM</>
        item as <literal>f</> not <literal>foo</>.  If an alias is
        written, a column alias list can also be written to provide
        substitute names for one or more columns of the table.
215 216 217 218 219
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
220
      <term><replaceable class="parameter">select</replaceable></term>
221 222
      <listitem>
       <para>
223 224 225 226 227 228
        A sub-<command>SELECT</command> can appear in the
        <literal>FROM</literal> clause.  This acts as though its
        output were created as a temporary table for the duration of
        this single <command>SELECT</command> command.  Note that the
        sub-<command>SELECT</command> must be surrounded by
        parentheses, and an alias <emphasis>must</emphasis> be
229 230 231
        provided for it.  A
        <xref linkend="sql-values" endterm="sql-values-title"> command
        can also be used here.
232 233 234
       </para>
      </listitem>
     </varlistentry>
235

236
     <varlistentry>
237
      <term><replaceable class="parameter">function_name</replaceable></term>
238 239
      <listitem>
       <para>
240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255
        Function calls can appear in the <literal>FROM</literal>
        clause.  (This is especially useful for functions that return
        result sets, but any function can be used.)  This acts as
        though its output were created as a temporary table for the
        duration of this single <command>SELECT</command> command. An
        alias may also be used. If an alias is written, a column alias
        list can also be written to provide substitute names for one
        or more attributes of the function's composite return type. If
        the function has been defined as returning the <type>record</>
        data type, then an alias or the key word <literal>AS</> must
        be present, followed by a column definition list in the form
        <literal>( <replaceable
        class="parameter">column_name</replaceable> <replaceable
        class="parameter">data_type</replaceable> <optional>, ... </>
        )</literal>.  The column definition list must match the actual
        number and types of columns returned by the function.
256 257 258 259 260
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
261
      <term><replaceable class="parameter">join_type</replaceable></term>
262 263
      <listitem>
       <para>
264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290
        One of
        <itemizedlist>
         <listitem>
          <para><literal>[ INNER ] JOIN</literal></para>
         </listitem>
         <listitem>
          <para><literal>LEFT [ OUTER ] JOIN</literal></para>
         </listitem>
         <listitem>
          <para><literal>RIGHT [ OUTER ] JOIN</literal></para>
         </listitem>
         <listitem>
          <para><literal>FULL [ OUTER ] JOIN</literal></para>
         </listitem>
         <listitem>
          <para><literal>CROSS JOIN</literal></para>
         </listitem>
        </itemizedlist>

        For the <literal>INNER</> and <literal>OUTER</> join types, a
        join condition must be specified, namely exactly one of
        <literal>NATURAL</>, <literal>ON <replaceable
        class="parameter">join_condition</replaceable></literal>, or
        <literal>USING (<replaceable
        class="parameter">join_column</replaceable> [, ...])</literal>.
        See below for the meaning.  For <literal>CROSS JOIN</literal>,
        none of these clauses may appear.
291
       </para>
292

293
       <para>
T
Tom Lane 已提交
294 295 296
        A <literal>JOIN</literal> clause combines two
        <literal>FROM</> items.  Use parentheses if necessary to
        determine the order of nesting.  In the absence of parentheses,
297 298 299
        <literal>JOIN</literal>s nest left-to-right.  In any case
        <literal>JOIN</literal> binds more tightly than the commas
        separating <literal>FROM</> items.
300
       </para>
301

302
       <para>
303
        <literal>CROSS JOIN</> and <literal>INNER JOIN</literal>
T
Tom Lane 已提交
304 305
        produce a simple Cartesian product, the same result as you get from
        listing the two items at the top level of <literal>FROM</>,
306
        but restricted by the join condition (if any).
307
        <literal>CROSS JOIN</> is equivalent to <literal>INNER JOIN ON
T
Tom Lane 已提交
308
        (TRUE)</>, that is, no rows are removed by qualification.
309 310 311
        These join types are just a notational convenience, since they
        do nothing you couldn't do with plain <literal>FROM</> and
        <literal>WHERE</>.
312
       </para>
313

314
       <para>
315 316 317 318 319 320 321
        <literal>LEFT OUTER JOIN</> returns all rows in the qualified
        Cartesian product (i.e., all combined rows that pass its join
        condition), plus one copy of each row in the left-hand table
        for which there was no right-hand row that passed the join
        condition.  This left-hand row is extended to the full width
        of the joined table by inserting null values for the
        right-hand columns.  Note that only the <literal>JOIN</>
T
Tom Lane 已提交
322
        clause's own condition is considered while deciding which rows
323
        have matches.  Outer conditions are applied afterwards.
324
       </para>
325 326

       <para>
327 328 329 330 331
        Conversely, <literal>RIGHT OUTER JOIN</> returns all the
        joined rows, plus one row for each unmatched right-hand row
        (extended with nulls on the left).  This is just a notational
        convenience, since you could convert it to a <literal>LEFT
        OUTER JOIN</> by switching the left and right inputs.
332
       </para>
333

334
       <para>
335 336 337 338
        <literal>FULL OUTER JOIN</> returns all the joined rows, plus
        one row for each unmatched left-hand row (extended with nulls
        on the right), plus one row for each unmatched right-hand row
        (extended with nulls on the left).
339 340 341 342 343
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
344
      <term><literal>ON <replaceable class="parameter">join_condition</replaceable></literal></term>
345 346
      <listitem>
       <para>
347 348 349 350 351
        <replaceable class="parameter">join_condition</replaceable> is
        an expression resulting in a value of type
        <type>boolean</type> (similar to a <literal>WHERE</literal>
        clause) that specifies which rows in a join are considered to
        match.
352 353 354 355
       </para>
      </listitem>
     </varlistentry>
     
356
     <varlistentry>
357
      <term><literal>USING (<replaceable class="parameter">join_column</replaceable> [, ...])</literal></term>
358 359
      <listitem>
       <para>
360 361 362 363 364 365
        A clause of the form <literal>USING ( a, b, ... )</literal> is
        shorthand for <literal>ON left_table.a = right_table.a AND
        left_table.b = right_table.b ...</literal>.  Also,
        <literal>USING</> implies that only one of each pair of
        equivalent columns will be included in the join output, not
        both.
366 367 368 369
       </para>
      </listitem>
     </varlistentry>

370
     <varlistentry>
371
      <term><literal>NATURAL</literal></term>
372 373
      <listitem>
       <para>
374 375 376
        <literal>NATURAL</literal> is shorthand for a
        <literal>USING</> list that mentions all columns in the two
        tables that have the same names.
377 378 379 380
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
381
   </para>
382
  </refsect2>
383
   
384 385
  <refsect2 id="SQL-WHERE">
   <title id="sql-where-title"><literal>WHERE</literal> Clause</title>
386 387

   <para>
388 389 390 391 392 393 394 395 396 397
    The optional <literal>WHERE</literal> clause has the general form
<synopsis>
WHERE <replaceable class="parameter">condition</replaceable>
</synopsis>
    where <replaceable class="parameter">condition</replaceable> is
    any expression that evaluates to a result of type
    <type>boolean</type>.  Any row that does not satisfy this
    condition will be eliminated from the output.  A row satisfies the
    condition if it returns true when the actual row values are
    substituted for any variable references.
398
   </para>
399 400 401 402
  </refsect2>
  
  <refsect2 id="SQL-GROUPBY">
   <title id="sql-groupby-title"><literal>GROUP BY</literal> Clause</title>
403 404

   <para>
405 406 407 408
    The optional <literal>GROUP BY</literal> clause has the general form
<synopsis>
GROUP BY <replaceable class="parameter">expression</replaceable> [, ...]
</synopsis>
409 410 411
   </para>

   <para>
412 413 414 415 416
    <literal>GROUP BY</literal> will condense into a single row all
    selected rows that share the same values for the grouped
    expressions.  <replaceable
    class="parameter">expression</replaceable> can be an input column
    name, or the name or ordinal number of an output column
T
Tom Lane 已提交
417
    (<command>SELECT</command> list item), or an arbitrary
418 419 420
    expression formed from input-column values.  In case of ambiguity,
    a <literal>GROUP BY</literal> name will be interpreted as an
    input-column name rather than an output column name.
421 422
   </para>

423
   <para>
424 425 426 427 428 429 430 431 432
    Aggregate functions, if any are used, are computed across all rows
    making up each group, producing a separate value for each group
    (whereas without <literal>GROUP BY</literal>, an aggregate
    produces a single value computed across all the selected rows).
    When <literal>GROUP BY</literal> is present, it is not valid for
    the <command>SELECT</command> list expressions to refer to
    ungrouped columns except within aggregate functions, since there
    would be more than one possible value to return for an ungrouped
    column.
433
   </para>
434
  </refsect2>
435

436 437
  <refsect2 id="SQL-HAVING">
   <title id="sql-having-title"><literal>HAVING</literal> Clause</title>
438

439
   <para>
440 441 442 443 444 445
    The optional <literal>HAVING</literal> clause has the general form
<synopsis>
HAVING <replaceable class="parameter">condition</replaceable>
</synopsis>
    where <replaceable class="parameter">condition</replaceable> is
    the same as specified for the <literal>WHERE</literal> clause.
446
   </para>
447
    
448
   <para>
449 450 451 452 453 454 455 456 457
    <literal>HAVING</literal> eliminates group rows that do not
    satisfy the condition.  <literal>HAVING</literal> is different
    from <literal>WHERE</literal>: <literal>WHERE</literal> filters
    individual rows before the application of <literal>GROUP
    BY</literal>, while <literal>HAVING</literal> filters group rows
    created by <literal>GROUP BY</literal>.  Each column referenced in
    <replaceable class="parameter">condition</replaceable> must
    unambiguously reference a grouping column, unless the reference
    appears within an aggregate function.
458
   </para>
459 460 461 462 463 464 465 466 467 468 469
    
   <para>
    The presence of <literal>HAVING</literal> turns a query into a grouped
    query even if there is no <literal>GROUP BY</> clause.  This is the
    same as what happens when the query contains aggregate functions but
    no <literal>GROUP BY</> clause.  All the selected rows are considered to
    form a single group, and the <command>SELECT</command> list and
    <literal>HAVING</literal> clause can only reference table columns from
    within aggregate functions.  Such a query will emit a single row if the
    <literal>HAVING</literal> condition is true, zero rows if it is not true.
   </para>
470
  </refsect2>
T
Tom Lane 已提交
471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498

  <refsect2 id="sql-select-list">
   <title id="sql-select-list-title"><command>SELECT</command> List</title>

   <para>
    The <command>SELECT</command> list (between the key words
    <literal>SELECT</> and <literal>FROM</>) specifies expressions
    that form the output rows of the <command>SELECT</command>
    statement.  The expressions can (and usually do) refer to columns
    computed in the <literal>FROM</> clause.  Using the clause
    <literal>AS <replaceable
    class="parameter">output_name</replaceable></literal>, another
    name can be specified for an output column.  This name is
    primarily used to label the column for display.  It can also be
    used to refer to the column's value in <literal>ORDER BY</> and
    <literal>GROUP BY</> clauses, but not in the <literal>WHERE</> or
    <literal>HAVING</> clauses; there you must write out the
    expression instead.
   </para>

   <para>
    Instead of an expression, <literal>*</literal> can be written in
    the output list as a shorthand for all the columns of the selected
    rows.  Also, one can write <literal><replaceable
    class="parameter">table_name</replaceable>.*</literal> as a
    shorthand for the columns coming from just that table.
   </para>
  </refsect2>
499 500 501
  
  <refsect2 id="SQL-UNION">
   <title id="sql-union-title"><literal>UNION</literal> Clause</title>
502 503

   <para>
504 505 506 507 508 509
    The <literal>UNION</literal> clause has this general form:
<synopsis>
<replaceable class="parameter">select_statement</replaceable> UNION [ ALL ] <replaceable class="parameter">select_statement</replaceable>
</synopsis>
    <replaceable class="parameter">select_statement</replaceable> is
    any <command>SELECT</command> statement without an <literal>ORDER
510
    BY</>, <literal>LIMIT</>, <literal>FOR UPDATE</literal>, or
511
    <literal>FOR SHARE</literal> clause.
512 513 514 515 516
    (<literal>ORDER BY</> and <literal>LIMIT</> can be attached to a
    subexpression if it is enclosed in parentheses.  Without
    parentheses, these clauses will be taken to apply to the result of
    the <literal>UNION</literal>, not to its right-hand input
    expression.)
517
   </para>
518
    
519
   <para>
520 521 522 523 524 525 526 527
    The <literal>UNION</literal> operator computes the set union of
    the rows returned by the involved <command>SELECT</command>
    statements.  A row is in the set union of two result sets if it
    appears in at least one of the result sets.  The two
    <command>SELECT</command> statements that represent the direct
    operands of the <literal>UNION</literal> must produce the same
    number of columns, and corresponding columns must be of compatible
    data types.
528
   </para>
529
    
530
   <para>
531 532
    The result of <literal>UNION</> does not contain any duplicate
    rows unless the <literal>ALL</> option is specified.
T
Tom Lane 已提交
533 534 535
    <literal>ALL</> prevents elimination of duplicates.  (Therefore,
    <literal>UNION ALL</> is usually significantly quicker than
    <literal>UNION</>; use <literal>ALL</> when you can.)
536
   </para>
537
    
538
   <para>
539 540 541
    Multiple <literal>UNION</> operators in the same
    <command>SELECT</command> statement are evaluated left to right,
    unless otherwise indicated by parentheses.
542
   </para>
543 544
    
   <para>
545 546 547
    Currently, <literal>FOR UPDATE</> and <literal>FOR SHARE</> may not be
    specified either for a <literal>UNION</> result or for any input of a
    <literal>UNION</>.
548
   </para>
549
  </refsect2>
550

551 552
  <refsect2 id="SQL-INTERSECT">
   <title id="sql-intersect-title"><literal>INTERSECT</literal> Clause</title>
553 554

   <para>
555 556 557 558 559 560
    The <literal>INTERSECT</literal> clause has this general form:
<synopsis>
<replaceable class="parameter">select_statement</replaceable> INTERSECT [ ALL ] <replaceable class="parameter">select_statement</replaceable>
</synopsis>
    <replaceable class="parameter">select_statement</replaceable> is
    any <command>SELECT</command> statement without an <literal>ORDER
561 562
    BY</>, <literal>LIMIT</>, <literal>FOR UPDATE</literal>, or
    <literal>FOR SHARE</literal> clause.
563
   </para>
564

565
   <para>
566 567 568 569
    The <literal>INTERSECT</literal> operator computes the set
    intersection of the rows returned by the involved
    <command>SELECT</command> statements.  A row is in the
    intersection of two result sets if it appears in both result sets.
570
   </para>
571 572
    
   <para>
573 574
    The result of <literal>INTERSECT</literal> does not contain any
    duplicate rows unless the <literal>ALL</> option is specified.
T
Tom Lane 已提交
575 576 577
    With <literal>ALL</>, a row that has <replaceable>m</> duplicates in the
    left table and <replaceable>n</> duplicates in the right table will appear
    min(<replaceable>m</>,<replaceable>n</>) times in the result set.
578
   </para>
579
    
580
   <para>
581 582 583 584 585 586 587
    Multiple <literal>INTERSECT</literal> operators in the same
    <command>SELECT</command> statement are evaluated left to right,
    unless parentheses dictate otherwise.
    <literal>INTERSECT</literal> binds more tightly than
    <literal>UNION</literal>.  That is, <literal>A UNION B INTERSECT
    C</literal> will be read as <literal>A UNION (B INTERSECT
    C)</literal>.
588
   </para>
T
Tom Lane 已提交
589 590
    
   <para>
591 592 593
    Currently, <literal>FOR UPDATE</> and <literal>FOR SHARE</> may not be
    specified either for an <literal>INTERSECT</> result or for any input of
    an <literal>INTERSECT</>.
T
Tom Lane 已提交
594
   </para>
595
  </refsect2>
596 597 598 599

  <refsect2 id="SQL-EXCEPT">
   <title id="sql-except-title"><literal>EXCEPT</literal> Clause</title>

600
   <para>
601 602 603 604 605 606
    The <literal>EXCEPT</literal> clause has this general form:
<synopsis>
<replaceable class="parameter">select_statement</replaceable> EXCEPT [ ALL ] <replaceable class="parameter">select_statement</replaceable>
</synopsis>
    <replaceable class="parameter">select_statement</replaceable> is
    any <command>SELECT</command> statement without an <literal>ORDER
607 608
    BY</>, <literal>LIMIT</>, <literal>FOR UPDATE</literal>, or
    <literal>FOR SHARE</literal> clause.
609
   </para>
610

611
   <para>
612 613 614 615
    The <literal>EXCEPT</literal> operator computes the set of rows
    that are in the result of the left <command>SELECT</command>
    statement but not in the result of the right one.
   </para>
616 617
    
   <para>
618 619
    The result of <literal>EXCEPT</literal> does not contain any
    duplicate rows unless the <literal>ALL</> option is specified.
T
Tom Lane 已提交
620 621 622
    With <literal>ALL</>, a row that has <replaceable>m</> duplicates in the
    left table and <replaceable>n</> duplicates in the right table will appear
    max(<replaceable>m</>-<replaceable>n</>,0) times in the result set.
623 624 625
   </para>
    
   <para>
626 627 628 629
    Multiple <literal>EXCEPT</literal> operators in the same
    <command>SELECT</command> statement are evaluated left to right,
    unless parentheses dictate otherwise.  <literal>EXCEPT</> binds at
    the same level as <literal>UNION</>.
630
   </para>
T
Tom Lane 已提交
631
    
632
   <para>
633 634 635
    Currently, <literal>FOR UPDATE</> and <literal>FOR SHARE</> may not be
    specified either for an <literal>EXCEPT</> result or for any input of
    an <literal>EXCEPT</>.
636
   </para>
637 638 639 640
  </refsect2>

  <refsect2 id="SQL-ORDERBY">
   <title id="sql-orderby-title"><literal>ORDER BY</literal> Clause</title>
641

642
   <para>
643 644 645 646 647 648
    The optional <literal>ORDER BY</literal> clause has this general form:
<synopsis>
ORDER BY <replaceable class="parameter">expression</replaceable> [ ASC | DESC | USING <replaceable class="parameter">operator</replaceable> ] [, ...]
</synopsis>
    <replaceable class="parameter">expression</replaceable> can be the
    name or ordinal number of an output column
T
Tom Lane 已提交
649
    (<command>SELECT</command> list item), or it can be an arbitrary
650
    expression formed from input-column values.
651 652
   </para>

653
   <para>
654 655 656 657 658
    The <literal>ORDER BY</literal> clause causes the result rows to
    be sorted according to the specified expressions.  If two rows are
    equal according to the leftmost expression, the are compared
    according to the next expression and so on.  If they are equal
    according to all specified expressions, they are returned in
T
Tom Lane 已提交
659
    an implementation-dependent order.
660
   </para>
661

662
   <para>
663 664 665 666 667 668
    The ordinal number refers to the ordinal (left-to-right) position
    of the result column. This feature makes it possible to define an
    ordering on the basis of a column that does not have a unique
    name.  This is never absolutely necessary because it is always
    possible to assign a name to a result column using the
    <literal>AS</> clause.
669
   </para>
670 671
    
   <para>
672 673 674 675 676 677 678 679 680 681 682
    It is also possible to use arbitrary expressions in the
    <literal>ORDER BY</literal> clause, including columns that do not
    appear in the <command>SELECT</command> result list.  Thus the
    following statement is valid:
<programlisting>
SELECT name FROM distributors ORDER BY code;
</programlisting>
    A limitation of this feature is that an <literal>ORDER BY</>
    clause applying to the result of a <literal>UNION</>,
    <literal>INTERSECT</>, or <literal>EXCEPT</> clause may only
    specify an output column name or number, not an expression.
683
   </para>
684

685
   <para>
686 687 688 689 690 691
    If an <literal>ORDER BY</> expression is a simple name that
    matches both a result column name and an input column name,
    <literal>ORDER BY</> will interpret it as the result column name.
    This is the opposite of the choice that <literal>GROUP BY</> will
    make in the same situation.  This inconsistency is made to be
    compatible with the SQL standard.
692 693 694
   </para>
    
   <para>
695
    Optionally one may add the key word <literal>ASC</> (ascending) or
T
Tom Lane 已提交
696
    <literal>DESC</> (descending) after any expression in the
697 698 699
    <literal>ORDER BY</> clause.  If not specified, <literal>ASC</> is
    assumed by default.  Alternatively, a specific ordering operator
    name may be specified in the <literal>USING</> clause.
700 701
    <literal>ASC</> is usually equivalent to <literal>USING &lt;</> and
    <literal>DESC</> is usually equivalent to <literal>USING &gt;</>.
702
    (But the creator of a user-defined data type can define exactly what the
703 704
    default sort ordering is, and it might correspond to operators with other
    names.)
705 706
   </para>

707
   <para>
708 709 710
    The null value sorts higher than any other value. In other words,
    with ascending sort order, null values sort at the end, and with
    descending sort order, null values sort at the beginning.
711 712
   </para>

713
   <para>
714
    Character-string data is sorted according to the locale-specific
715 716
    collation order that was established when the database cluster
    was initialized.
717
   </para>
718
  </refsect2>
719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757

  <refsect2 id="sql-distinct">
   <title id="sql-distinct-title"><literal>DISTINCT</literal> Clause</title>

   <para>
    If <literal>DISTINCT</> is specified, all duplicate rows are
    removed from the result set (one row is kept from each group of
    duplicates).  <literal>ALL</> specifies the opposite: all rows are
    kept; that is the default.
   </para>

   <para>
    <literal>DISTINCT ON ( <replaceable
    class="parameter">expression</replaceable> [, ...] )</literal>
    keeps only the first row of each set of rows where the given
    expressions evaluate to equal.  The <literal>DISTINCT ON</literal>
    expressions are interpreted using the same rules as for
    <literal>ORDER BY</> (see above).  Note that the <quote>first
    row</quote> of each set is unpredictable unless <literal>ORDER
    BY</> is used to ensure that the desired row appears first.  For
    example,
<programlisting>
SELECT DISTINCT ON (location) location, time, report
    FROM weather_reports
    ORDER BY location, time DESC;
</programlisting>
    retrieves the most recent weather report for each location.  But
    if we had not used <literal>ORDER BY</> to force descending order
    of time values for each location, we'd have gotten a report from
    an unpredictable time for each location.
   </para>

   <para>
    The <literal>DISTINCT ON</> expression(s) must match the leftmost
    <literal>ORDER BY</> expression(s).  The <literal>ORDER BY</> clause
    will normally contain additional expression(s) that determine the
    desired precedence of rows within each <literal>DISTINCT ON</> group.
   </para>
  </refsect2>
758 759 760
  
  <refsect2 id="SQL-LIMIT">
   <title id="sql-limit-title"><literal>LIMIT</literal> Clause</title>
761 762

   <para>
763
    The <literal>LIMIT</literal> clause consists of two independent
T
Tom Lane 已提交
764
    sub-clauses:
765 766 767 768 769
<synopsis>
LIMIT { <replaceable class="parameter">count</replaceable> | ALL }
OFFSET <replaceable class="parameter">start</replaceable>
</synopsis>
    <replaceable class="parameter">count</replaceable> specifies the
T
Tom Lane 已提交
770
    maximum number of rows to return, while <replaceable
771
    class="parameter">start</replaceable> specifies the number of rows
T
Tom Lane 已提交
772 773 774 775
    to skip before starting to return rows.  When both are specified,
    <replaceable class="parameter">start</replaceable> rows are skipped
    before starting to count the <replaceable
    class="parameter">count</replaceable> rows to be returned.
776 777
   </para>

778
   <para>
779 780 781
    When using <literal>LIMIT</>, it is a good idea to use an
    <literal>ORDER BY</> clause that constrains the result rows into a
    unique order.  Otherwise you will get an unpredictable subset of
T
Tom Lane 已提交
782
    the query's rows &mdash; you may be asking for the tenth through
783 784
    twentieth rows, but tenth through twentieth in what ordering?  You
    don't know what ordering unless you specify <literal>ORDER BY</>.
785 786 787
   </para>

   <para>
788 789 790 791 792 793 794 795 796 797 798
    The query planner takes <literal>LIMIT</> into account when
    generating a query plan, so you are very likely to get different
    plans (yielding different row orders) depending on what you use
    for <literal>LIMIT</> and <literal>OFFSET</>.  Thus, using
    different <literal>LIMIT</>/<literal>OFFSET</> values to select
    different subsets of a query result <emphasis>will give
    inconsistent results</emphasis> unless you enforce a predictable
    result ordering with <literal>ORDER BY</>.  This is not a bug; it
    is an inherent consequence of the fact that SQL does not promise
    to deliver the results of a query in any particular order unless
    <literal>ORDER BY</> is used to constrain the order.
799
   </para>
800
  </refsect2>
801

802 803
  <refsect2 id="SQL-FOR-UPDATE-SHARE">
   <title id="sql-for-update-share-title"><literal>FOR UPDATE</literal>/<literal>FOR SHARE</literal> Clause</title>
804

805
   <para>
806 807
    The <literal>FOR UPDATE</literal> clause has this form:
<synopsis>
808
FOR UPDATE [ OF <replaceable class="parameter">table_name</replaceable> [, ...] ] [ NOWAIT ]
809
</synopsis>
810 811
   </para>

812 813 814
   <para>
    The closely related <literal>FOR SHARE</literal> clause has this form:
<synopsis>
815
FOR SHARE [ OF <replaceable class="parameter">table_name</replaceable> [, ...] ] [ NOWAIT ]
816 817 818
</synopsis>
   </para>

819
   <para>
820 821 822 823 824 825 826 827 828 829
    <literal>FOR UPDATE</literal> causes the rows retrieved by the
    <command>SELECT</command> statement to be locked as though for
    update.  This prevents them from being modified or deleted by
    other transactions until the current transaction ends.  That is,
    other transactions that attempt <command>UPDATE</command>,
    <command>DELETE</command>, or <command>SELECT FOR UPDATE</command>
    of these rows will be blocked until the current transaction ends.
    Also, if an <command>UPDATE</command>, <command>DELETE</command>,
    or <command>SELECT FOR UPDATE</command> from another transaction
    has already locked a selected row or rows, <command>SELECT FOR
830 831
    UPDATE</command> will wait for the other transaction to complete,
    and will then lock and return the updated row (or no row, if the
832 833
    row was deleted).  For further discussion see <xref
    linkend="mvcc">.
834 835
   </para>

836 837 838 839 840 841 842 843 844 845 846 847
   <para>
    To prevent the operation from waiting for other transactions to commit,
    use the <literal>NOWAIT</> option.  <command>SELECT FOR UPDATE
    NOWAIT</command> reports an error, rather than waiting, if a selected row
    cannot be locked immediately.  Note that <literal>NOWAIT</> applies only
    to the row-level lock(s) &mdash; the required <literal>ROW SHARE</literal>
    table-level lock is still taken in the ordinary way (see
    <xref linkend="mvcc">).  You can use the <literal>NOWAIT</> option of
    <xref linkend="sql-lock" endterm="sql-lock-title">
    if you need to acquire the table-level lock without waiting.
   </para>

848
   <para>
849 850 851 852 853 854 855 856 857 858 859
    <literal>FOR SHARE</literal> behaves similarly, except that it
    acquires a shared rather than exclusive lock on each retrieved
    row.  A shared lock blocks other transactions from performing
    <command>UPDATE</command>, <command>DELETE</command>, or <command>SELECT
    FOR UPDATE</command> on these rows, but it does not prevent them
    from performing <command>SELECT FOR SHARE</command>.
   </para>

   <para>
    If specific tables are named in <literal>FOR UPDATE</literal>
    or <literal>FOR SHARE</literal>,
860 861
    then only rows coming from those tables are locked; any other
    tables used in the <command>SELECT</command> are simply read as
862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877
    usual.  A <literal>FOR UPDATE</literal> or <literal>FOR SHARE</literal>
    clause without a table list affects all tables used in the command.
    If <literal>FOR UPDATE</literal> or <literal>FOR SHARE</literal> is
    applied to a view or sub-query, it affects all tables used in
    the view or sub-query.
   </para>

   <para>
    Multiple <literal>FOR UPDATE</literal> and <literal>FOR SHARE</literal>
    clauses can be written if it is necessary to specify different locking
    behavior for different tables.  If the same table is mentioned (or
    implicitly affected) by both <literal>FOR UPDATE</literal> and
    <literal>FOR SHARE</literal> clauses, then it is processed as
    <literal>FOR UPDATE</literal>.  Similarly, a table is processed
    as <literal>NOWAIT</> if that is specified in any of the clauses
    affecting it.
878 879 880
   </para>

   <para>
881 882 883
    <literal>FOR UPDATE</literal> and <literal>FOR SHARE</literal> cannot be
    used in contexts where returned rows can't be clearly identified with
    individual table rows; for example they can't be used with aggregation.
T
Tom Lane 已提交
884 885
   </para>

886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910
  <caution>
   <para>
    Avoid locking a row and then modifying it within a later savepoint or
    <application>PL/pgSQL</application> exception block.  A subsequent
    rollback would cause the lock to be lost.  For example,
<programlisting>
BEGIN;
SELECT * FROM mytable WHERE key = 1 FOR UPDATE;
SAVEPOINT s;
UPDATE mytable SET ... WHERE key = 1;
ROLLBACK TO s;
</programlisting>
    After the <command>ROLLBACK</>, the row is effectively unlocked, rather
    than returned to its pre-savepoint state of being locked but not modified.
    This hazard occurs if a row locked in the current transaction is updated
    or deleted, or if a shared lock is upgraded to exclusive: in all these
    cases, the former lock state is forgotten.  If the transaction is then
    rolled back to a state between the original locking command and the
    subsequent change, the row will appear not to be locked at all.  This is
    an implementation deficiency which will be addressed in a future release
    of <productname>PostgreSQL</productname>.
   </para>
  </caution>

  <caution>
T
Tom Lane 已提交
911
   <para>
912 913
    It is possible for a <command>SELECT</> command using both
    <literal>LIMIT</literal> and  <literal>FOR UPDATE/SHARE</literal>
914
    clauses to return fewer rows than specified by <literal>LIMIT</literal>.
915 916 917 918 919 920
    This is because <literal>LIMIT</> is applied first.  The command
    selects the specified number of rows,
    but might then block trying to obtain lock on one or more of them.
    Once the <literal>SELECT</> unblocks, the row might have been deleted
    or updated so that it does not meet the query <literal>WHERE</> condition
    anymore, in which case it will not be returned.
921
   </para>
922
  </caution>
923
  </refsect2>
924
 </refsect1>
925

926 927
 <refsect1>
  <title>Examples</title>
928

929 930 931
  <para>
   To join the table <literal>films</literal> with the table
   <literal>distributors</literal>:
932

933
<programlisting>
934 935 936
SELECT f.title, f.did, d.name, f.date_prod, f.kind
    FROM distributors d, films f
    WHERE f.did = d.did
937

938 939 940 941 942
       title       | did |     name     | date_prod  |   kind
-------------------+-----+--------------+------------+----------
 The Third Man     | 101 | British Lion | 1949-12-23 | Drama
 The African Queen | 101 | British Lion | 1951-08-11 | Romantic
 ...
943
</programlisting>
944 945
  </para>

946 947
  <para>
   To sum the column <literal>len</literal> of all films and group
948
   the results by <literal>kind</literal>:
949

950
<programlisting>
951
SELECT kind, sum(len) AS total FROM films GROUP BY kind;
952

953 954 955 956 957 958 959 960
   kind   | total
----------+-------
 Action   | 07:34
 Comedy   | 02:58
 Drama    | 14:28
 Musical  | 06:42
 Romantic | 04:38
</programlisting>
961
  </para>
962 963 964

  <para>
   To sum the column <literal>len</literal> of all films, group
965
   the results by <literal>kind</literal> and show those group totals
966
   that are less than 5 hours:
967

968
<programlisting>
969
SELECT kind, sum(len) AS total
970 971
    FROM films
    GROUP BY kind
972
    HAVING sum(len) &lt; interval '5 hours';
973

974
   kind   | total
975 976 977 978
----------+-------
 Comedy   | 02:58
 Romantic | 04:38
</programlisting>
979 980
  </para>

981
  <para>
982
   The following two examples are identical ways of sorting the individual
983 984
   results according to the contents of the second column
   (<literal>name</literal>):
985

986
<programlisting>
987 988
SELECT * FROM distributors ORDER BY name;
SELECT * FROM distributors ORDER BY 2;
989

990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005
 did |       name
-----+------------------
 109 | 20th Century Fox
 110 | Bavaria Atelier
 101 | British Lion
 107 | Columbia
 102 | Jean Luc Godard
 113 | Luso films
 104 | Mosfilm
 103 | Paramount
 106 | Toho
 105 | United Artists
 111 | Walt Disney
 112 | Warner Bros.
 108 | Westward
</programlisting>
1006
  </para>
1007 1008

  <para>
T
Tom Lane 已提交
1009
   The next example shows how to obtain the union of the tables
1010 1011
   <literal>distributors</literal> and
   <literal>actors</literal>, restricting the results to those that begin
T
Tom Lane 已提交
1012
   with the letter W in each table.  Only distinct rows are wanted, so the
1013
   key word <literal>ALL</literal> is omitted.
1014

1015 1016 1017 1018 1019 1020 1021 1022
<programlisting>
distributors:               actors:
 did |     name              id |     name
-----+--------------        ----+----------------
 108 | Westward               1 | Woody Allen
 111 | Walt Disney            2 | Warren Beatty
 112 | Warner Bros.           3 | Walter Matthau
 ...                         ...
1023

1024
SELECT distributors.name
1025 1026
    FROM distributors
    WHERE distributors.name LIKE 'W%'
1027 1028
UNION
SELECT actors.name
1029 1030
    FROM actors
    WHERE actors.name LIKE 'W%';
1031

1032 1033 1034 1035 1036 1037 1038 1039
      name
----------------
 Walt Disney
 Walter Matthau
 Warner Bros.
 Warren Beatty
 Westward
 Woody Allen
1040 1041 1042 1043
</programlisting>
  </para>

  <para>
1044
   This example shows how to use a function in the <literal>FROM</>
T
Tom Lane 已提交
1045
   clause, both with and without a column definition list:
1046 1047

<programlisting>
1048
CREATE FUNCTION distributors(int) RETURNS SETOF distributors AS $$
1049
    SELECT * FROM distributors WHERE did = $1;
1050
$$ LANGUAGE SQL;
1051 1052 1053 1054 1055 1056

SELECT * FROM distributors(111);
 did |    name
-----+-------------
 111 | Walt Disney

1057
CREATE FUNCTION distributors_2(int) RETURNS SETOF record AS $$
1058
    SELECT * FROM distributors WHERE did = $1;
1059
$$ LANGUAGE SQL;
1060 1061 1062 1063 1064

SELECT * FROM distributors_2(111) AS (f1 int, f2 text);
 f1  |     f2
-----+-------------
 111 | Walt Disney
1065
</programlisting>
1066
  </para>
1067 1068
 </refsect1>
 
1069 1070 1071 1072 1073 1074 1075 1076
 <refsect1>
  <title>Compatibility</title>

  <para>
   Of course, the <command>SELECT</command> statement is compatible
   with the SQL standard.  But there are some extensions and some
   missing features.
  </para>
1077
  
1078 1079
  <refsect2>
   <title>Omitted <literal>FROM</literal> Clauses</title>
1080 1081

   <para>
1082 1083 1084 1085
    <productname>PostgreSQL</productname> allows one to omit the
    <literal>FROM</literal> clause.  It has a straightforward use to
    compute the results of simple expressions:
<programlisting>
1086 1087 1088 1089 1090
SELECT 2+2;

 ?column?
----------
        4
1091 1092 1093 1094 1095
</programlisting>
    Some other <acronym>SQL</acronym> databases cannot do this except
    by introducing a dummy one-row table from which to do the
    <command>SELECT</command>.
   </para>
1096

1097
   <para>
1098 1099 1100
    Note that if a <literal>FROM</literal> clause is not specified,
    the query cannot reference any database tables. For example, the
    following query is invalid:
1101
<programlisting>
1102
SELECT distributors.* WHERE distributors.name = 'Westward';
1103
</programlisting>
1104 1105 1106 1107 1108 1109 1110 1111 1112
    <productname>PostgreSQL</productname> releases prior to
    8.1 would accept queries of this form, and add an implicit entry
    to the query's <literal>FROM</literal> clause for each table
    referenced by the query. This is no longer the default behavior,
    because it does not comply with the SQL standard, and is
    considered by many to be error-prone. For compatibility with
    applications that rely on this behavior the <xref
    linkend="guc-add-missing-from"> configuration variable can be
    enabled.
1113 1114 1115 1116 1117
   </para>
  </refsect2>

  <refsect2>
   <title>The <literal>AS</literal> Key Word</title>
1118

1119 1120 1121 1122 1123
   <para>
    In the SQL standard, the optional key word <literal>AS</> is just
    noise and can be omitted without affecting the meaning.  The
    <productname>PostgreSQL</productname> parser requires this key
    word when renaming output columns because the type extensibility
1124
    features lead to parsing ambiguities without it.
1125 1126
    <literal>AS</literal> is optional in <literal>FROM</literal>
    items, however.
1127
   </para>
1128 1129 1130 1131
  </refsect2>

  <refsect2>
   <title>Namespace Available to <literal>GROUP BY</literal> and <literal>ORDER BY</literal></title>
1132 1133

   <para>
1134
    In the SQL-92 standard, an <literal>ORDER BY</literal> clause may
1135 1136 1137 1138 1139 1140 1141 1142 1143
    only use result column names or numbers, while a <literal>GROUP
    BY</literal> clause may only use expressions based on input column
    names.  <productname>PostgreSQL</productname> extends each of
    these clauses to allow the other choice as well (but it uses the
    standard's interpretation if there is ambiguity).
    <productname>PostgreSQL</productname> also allows both clauses to
    specify arbitrary expressions.  Note that names appearing in an
    expression will always be taken as input-column names, not as
    result-column names.
1144
   </para>
1145 1146

   <para>
1147 1148
    SQL:1999 and later use a slightly different definition which is not
    entirely upward compatible with SQL-92.  
1149
    In most cases, however, <productname>PostgreSQL</productname>
1150
    will interpret an <literal>ORDER BY</literal> or <literal>GROUP
1151
    BY</literal> expression the same way SQL:1999 does.
1152
   </para>
1153
  </refsect2>
1154

1155 1156 1157
  <refsect2>
   <title>Nonstandard Clauses</title>

1158
   <para>
1159 1160 1161
    The clauses <literal>DISTINCT ON</literal>,
    <literal>LIMIT</literal>, and <literal>OFFSET</literal> are not
    defined in the SQL standard.
1162 1163 1164 1165
   </para>
  </refsect2>
 </refsect1>
</refentry>