select.sgml 42.4 KB
Newer Older
1
<!--
2
$Header: /cvsroot/pgsql/doc/src/sgml/ref/select.sgml,v 1.66 2003/03/25 16:15:44 petere Exp $
3
PostgreSQL documentation
4 5
-->

6 7
<refentry id="SQL-SELECT">
 <refmeta>
8
  <refentrytitle id="sql-select-title">SELECT</refentrytitle>
9 10 11 12
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>
 <refnamediv>
  <refname>
13
   SELECT
14 15
  </refname>
  <refpurpose>
16
   retrieve rows from a table or view
17 18 19
  </refpurpose></refnamediv>
 <refsynopsisdiv>
  <refsynopsisdivinfo>
20
   <date>2000-12-11</date>
21 22
  </refsynopsisdivinfo>
  <synopsis>
23
SELECT [ ALL | DISTINCT [ ON ( <replaceable class="PARAMETER">expression</replaceable> [, ...] ) ] ]
24 25
    * | <replaceable class="PARAMETER">expression</replaceable> [ AS <replaceable class="PARAMETER">output_name</replaceable> ] [, ...]
    [ FROM <replaceable class="PARAMETER">from_item</replaceable> [, ...] ]
26
    [ WHERE <replaceable class="PARAMETER">condition</replaceable> ]
27
    [ GROUP BY <replaceable class="PARAMETER">expression</replaceable> [, ...] ]
28
    [ HAVING <replaceable class="PARAMETER">condition</replaceable> [, ...] ]
29
    [ { UNION | INTERSECT | EXCEPT } [ ALL ] <replaceable class="PARAMETER">select</replaceable> ]
30
    [ ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...] ]
31
    [ LIMIT { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
B
Bruce Momjian 已提交
32
    [ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
33
    [ FOR UPDATE [ OF <replaceable class="PARAMETER">tablename</replaceable> [, ...] ] ]
34 35 36 37 38 39 40 41 42

where <replaceable class="PARAMETER">from_item</replaceable> can be:

[ ONLY ] <replaceable class="PARAMETER">table_name</replaceable> [ * ]
    [ [ AS ] <replaceable class="PARAMETER">alias</replaceable> [ ( <replaceable class="PARAMETER">column_alias_list</replaceable> ) ] ]
|
( <replaceable class="PARAMETER">select</replaceable> )
    [ AS ] <replaceable class="PARAMETER">alias</replaceable> [ ( <replaceable class="PARAMETER">column_alias_list</replaceable> ) ]
|
43
<replaceable class="PARAMETER">table_function_name</replaceable> ( [ <replaceable class="parameter">argument</replaceable> [, ...] ] )
44 45
    [ AS ] <replaceable class="PARAMETER">alias</replaceable> [ ( <replaceable class="PARAMETER">column_alias_list</replaceable> | <replaceable class="PARAMETER">column_definition_list</replaceable> ) ]
|
46
<replaceable class="PARAMETER">table_function_name</replaceable> ( [ <replaceable class="parameter">argument</replaceable> [, ...] ] )
47 48
    AS ( <replaceable class="PARAMETER">column_definition_list</replaceable> )
|
49 50 51 52 53
<!-- 
   FIXME: this syntax is incorrect if the join type is an INNER or
   OUTER join (in which case one of NATURAL, ON ..., or USING ... is
   mandatory, not optional). What's the best way to fix this?
-->
54 55
<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_list</replaceable> ) ]
56 57 58 59
  </synopsis>
  
  <refsect2 id="R2-SQL-SELECT-1">
   <refsect2info>
60
    <date>2000-12-11</date>
61 62 63 64
   </refsect2info>
   <title>
    Inputs
   </title>
65

66 67 68
   <para>
    <variablelist>
     <varlistentry>
69
      <term><replaceable class="PARAMETER">expression</replaceable></term>
70 71 72 73 74 75 76 77
      <listitem>
       <para>
	The name of a table's column or an expression.
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
78
      <term><replaceable class="PARAMETER">output_name</replaceable></term>
79 80
      <listitem>
       <para>
81
	Specifies another name for an output column using
82 83 84
	the AS clause.  This name is primarily used to label the column
	for display.  It can also be used to refer to the column's value in
	ORDER BY and GROUP BY clauses.  But the
85
	<replaceable class="PARAMETER">output_name</replaceable>
86 87
	cannot be used in the WHERE or HAVING clauses; write out the
	expression instead.
88 89 90 91 92
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
93
      <term><replaceable class="PARAMETER">from_item</replaceable></term>
94 95
      <listitem>
       <para>
96
        A table reference, sub-SELECT, table function, or JOIN clause.  See below for details.
97 98 99 100 101
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
102
      <term><replaceable class="PARAMETER">condition</replaceable></term>
103 104
      <listitem>
       <para>
105
	A Boolean expression giving a result of true or false.
106
	See the WHERE and HAVING clause descriptions below.
107 108 109 110 111
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
112
      <term><replaceable class="PARAMETER">select</replaceable></term>
113 114
      <listitem>
       <para>
115 116 117
	A select statement with all features except the ORDER BY, 
	LIMIT/OFFSET, and FOR UPDATE clauses (even those can be used when the 
	select is parenthesized).
118 119 120 121
       </para>
      </listitem>
     </varlistentry>
     
122 123 124 125 126 127 128
    </variablelist>
   </para>

   <para>
    FROM items can contain:
    <variablelist>
     
129
     <varlistentry>
130
      <term><replaceable class="PARAMETER">table_name</replaceable></term>
131 132
      <listitem>
       <para>
133 134 135 136 137 138
	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
139 140 141
	before 7.1, <literal>ONLY</> was the default behavior.)  The
	default behavior can be modified by changing the
	<option>SQL_INHERITANCE</option> configuration option.
142 143 144 145 146 147 148 149
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
      <term><replaceable class="PARAMETER">alias</replaceable></term>
      <listitem>
       <para>
150
	A substitute name for the FROM item containing the alias.
151
	An alias is used for brevity or to eliminate ambiguity for self-joins
152 153 154 155 156 157
	(where the same table is scanned multiple times).  When an alias
	is provided, it completely hides the actual name of the table or
	table function; for example given <literal>FROM foo AS f</>, the
	remainder of the SELECT must refer to this FROM item as <literal>f</>
	not <literal>foo</>.
	If an alias is
158 159
	written, a column alias list can also be written to provide
	substitute names for one or more columns of the table.
160 161 162 163 164
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
165
      <term><replaceable class="PARAMETER">select</replaceable></term>
166 167
      <listitem>
       <para>
168 169 170 171 172 173 174 175
	A sub-SELECT can appear in the FROM clause.  This acts as though
	its output were created as a temporary table for the duration of
	this single SELECT command.  Note that the sub-SELECT must be
	surrounded by parentheses, and an alias <emphasis>must</emphasis>
	be provided for it.
       </para>
      </listitem>
     </varlistentry>
176 177 178 179 180 181 182 183

     <varlistentry>
      <term><replaceable class="PARAMETER">table function</replaceable></term>
      <listitem>
       <para>
	A table function can appear in the FROM clause.  This acts as though
	its output were created as a temporary table for the duration of
	this single SELECT command. An alias may also be used. If an alias is
184 185 186 187 188 189 190 191 192
	written, a column alias list can also be written to provide substitute
	names for one or more columns of the table function. If the table
	function has been defined as returning the <type>record</> data type,
	an alias, or the keyword <literal>AS</>, must be present, followed by
	a column definition list in the form ( <replaceable
	class="PARAMETER">column_name</replaceable> <replaceable
	class="PARAMETER">data_type</replaceable> [, ... ] ).
	The column definition list must match the actual number and types
	of columns returned by the function.
193 194 195
       </para>
      </listitem>
     </varlistentry>
196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221
     
     <varlistentry>
      <term><replaceable class="PARAMETER">join_type</replaceable></term>
      <listitem>
       <para>
       One of
       <command>[ INNER ] JOIN</command>,
       <command>LEFT [ OUTER ] JOIN</command>,
       <command>RIGHT [ OUTER ] JOIN</command>,
       <command>FULL [ OUTER ] JOIN</command>, or
       <command>CROSS JOIN</command>.
       For INNER and OUTER join types, exactly one of NATURAL,
       ON <replaceable class="PARAMETER">join_condition</replaceable>, or
       USING ( <replaceable class="PARAMETER">join_column_list</replaceable> )
       must appear.  For CROSS JOIN, none of these items may appear.
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
      <term><replaceable class="PARAMETER">join_condition</replaceable></term>
      <listitem>
       <para>
       A qualification condition.  This is similar to the WHERE condition
       except that it only applies to the two from_items being joined in
       this JOIN clause.
222 223 224 225
       </para>
      </listitem>
     </varlistentry>
     
226 227 228 229 230 231 232 233 234 235
     <varlistentry>
      <term><replaceable class="PARAMETER">join_column_list</replaceable></term>
      <listitem>
       <para>
       A USING column list ( a, b, ... ) is shorthand for the ON condition
       left_table.a = right_table.a AND left_table.b = right_table.b ...
       </para>
      </listitem>
     </varlistentry>

236 237 238 239 240 241
    </variablelist>
   </para>
  </refsect2>
  
  <refsect2 id="R2-SQL-SELECT-2">
   <refsect2info>
242
    <date>1998-09-24</date>
243 244 245 246
   </refsect2info>
   <title>
    Outputs
   </title>
247
   <para>
248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269

    <variablelist>
     <varlistentry>
      <term>Rows</term>
      <listitem>
       <para>
	The complete set of rows resulting from the query specification.
       </para>
      </listitem>
     </varlistentry>

     <varlistentry>
      <term>
       <returnvalue><replaceable>count</replaceable></returnvalue>
      </term>
      <listitem>
       <para>
	The count of rows returned by the query.
       </para>
      </listitem>
     </varlistentry>
    </variablelist>
270
   </para>
271 272
  </refsect2>
 </refsynopsisdiv>
273

274 275
 <refsect1 id="R1-SQL-SELECT-1">
  <refsect1info>
276
   <date>2000-12-11</date>
277 278 279 280 281
  </refsect1info>
  <title>
   Description
  </title>
  <para>
282 283
   <command>SELECT</command> will return rows from one or more tables.
   Candidates for selection are rows which satisfy the WHERE condition;
284
   if WHERE is omitted, all rows are candidates.
285
   (See <xref linkend="sql-where" endterm="sql-where-title">.)
286
  </para>
287

288
  <para>
289 290 291 292 293 294 295
   Actually, the returned rows are not directly the rows produced by the
   FROM/WHERE/GROUP BY/HAVING clauses; rather, the output rows are formed
   by computing the SELECT output expressions for each selected row.
   <command>*</command> can be written in the output list as a shorthand
   for all the columns of the selected rows.  Also, one can write
   <replaceable class="PARAMETER">table_name</replaceable><command>.*</command>
   as a shorthand for the columns coming from just that table.
296
  </para>
297

298
  <para>
299 300
   DISTINCT will eliminate duplicate rows from the result.  ALL (the
   default) will return all candidate rows, including duplicates.
301
  </para>
302

303
  <para>
304
   DISTINCT ON eliminates rows that match on all the
305
   specified expressions, keeping only the first row of each set of
306 307
   duplicates.  The DISTINCT ON expressions are interpreted using the
   same rules as for ORDER BY items; see below.
308
   Note that the <quote>first row</quote> of each set is unpredictable
309
   unless ORDER BY is used to ensure that the desired
310 311 312 313 314 315 316 317 318 319 320 321
   row appears first.  For example,
   <programlisting>
        SELECT DISTINCT ON (location) location, time, report
        FROM weatherReports
        ORDER BY location, time DESC;
   </programlisting>
   retrieves the most recent weather report for each location.  But if
   we had not used ORDER BY to force descending order of time values
   for each location, we'd have gotten a report of unpredictable age
   for each location.
  </para>

322
  <para>
323
   The GROUP BY clause allows a user to divide a table
324
   into groups of rows that match on one or more values.
325
   (See <xref linkend="sql-groupby" endterm="sql-groupby-title">.)
326 327
  </para>

328
  <para>
329 330
   The HAVING clause allows selection of only those groups of rows
   meeting the specified condition.
331
   (See <xref linkend="sql-having" endterm="sql-having-title">.)
332
  </para>
333 334
   
  <para>
335 336 337
   The ORDER BY clause causes the returned rows to be sorted in a specified
   order.  If ORDER BY is not given, the rows are returned in whatever order
   the system finds cheapest to produce.
338
   (See <xref linkend="sql-orderby" endterm="sql-orderby-title">.)
339
  </para>
340 341
   
  <para>
342 343 344
   <command>SELECT</command> queries can be combined using UNION,
   INTERSECT, and EXCEPT operators.  Use parentheses if necessary to
   determine the ordering of these operators.
345 346 347 348
  </para>
   
  <para>
   The UNION operator computes the collection of rows
349
   returned by the queries involved.
350
   Duplicate rows are eliminated unless ALL is specified.
351
   (See <xref linkend="sql-union" endterm="sql-union-title">.)
352
  </para>
353 354
   
  <para>
355 356
   The INTERSECT operator computes the rows that are common to both queries.
   Duplicate rows are eliminated unless ALL is specified.
357
   (See <xref linkend="sql-intersect" endterm="sql-intersect-title">.)
358
  </para>
359 360
   
  <para>
361
   The EXCEPT operator computes the rows returned by the first query but
362
   not the second query.
363
   Duplicate rows are eliminated unless ALL is specified.
364
   (See <xref linkend="sql-except" endterm="sql-except-title">.)
365
  </para>
366
   
367
  <para>
368 369 370
   The LIMIT clause allows a subset of the rows produced by the query
   to be returned to the user.
   (See <xref linkend="sql-limit" endterm="sql-limit-title">.)
371
  </para>
372

373
  <para>
374 375
   The FOR UPDATE clause causes the <command>SELECT</command>
   statement to lock the selected rows against concurrent updates.
376 377
  </para>
   
378
  <para>
379
   You must have SELECT privilege to a table to read its values
380
   (See the <command>GRANT</command>/<command>REVOKE</command> statements).
T
Tom Lane 已提交
381
   Use of FOR UPDATE requires UPDATE privilege as well.
382
  </para>
383
   
384 385 386 387 388 389 390 391 392
  <refsect2 id="SQL-FROM">
   <refsect2info>
    <date>2000-12-11</date>
   </refsect2info>
   <title id="sql-from-title">
    FROM Clause
   </title>

   <para>
393 394 395 396 397 398
    The FROM clause specifies one or more source tables for the
    <command>SELECT</command>.  If multiple sources are specified, the
    result is conceptually the Cartesian product of all the rows in
    all the sources --- but usually qualification conditions are added
    to restrict the returned rows to a small subset of the Cartesian
    product.
399 400 401 402
   </para>

   <para>
    When a FROM item is a simple table name, it implicitly includes rows
403
    from sub-tables (inheritance children) of the table.
404
    <command>ONLY</command> will
405
    suppress rows from sub-tables of the table.  Before
406
    <Productname>PostgreSQL</Productname> 7.1,
407
    this was the default result, and adding sub-tables was done
408
    by appending <command>*</command> to the table name.
409
    This old behavior is available via the command 
410
    <command>SET SQL_Inheritance TO OFF</command>.
411 412 413
   </para>

   <para>
414 415 416 417 418
    A FROM item can also be a parenthesized
    sub-<command>SELECT</command> (note that an alias clause is
    required for a sub-<command>SELECT</command>!).  This is an
    extremely useful feature since it's the only way to get multiple
    levels of grouping, aggregation, or sorting in a single query.
419 420
   </para>

421
   <para>
422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437
    A FROM item can be a table function (typically, a function that returns
    multiple rows and/or columns, though actually any function can be used).
    The function is invoked with the given argument value(s), and then its
    output is scanned as though it were a table.
   </para>

   <para>
    In some cases it is useful to define table functions that can return
    different column sets depending on how they are invoked.  To support this,
    the table function can be declared as returning the pseudo-type
    <type>record</>.  When such a function is used in FROM, it must be
    followed by an alias, or the keyword <literal>AS</> alone,
    and then by a parenthesized list of column names and types. This provides
    a query-time composite type definition. The composite type definition
    must match the actual composite type returned from the function, or an
    error will be reported at run-time.
438 439
   </para>

440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456
   <para>
    Finally, a FROM item can be a JOIN clause, which combines two simpler
    FROM items.  (Use parentheses if necessary to determine the order
    of nesting.)
   </para>

   <para>
    A CROSS JOIN or INNER JOIN is a simple Cartesian product,
    the same as you get from listing the two items at the top level of FROM.
    CROSS JOIN is equivalent to INNER JOIN ON (TRUE), that is, no rows are
    removed by qualification.  These join types are just a notational
    convenience, since they do nothing you couldn't do with plain FROM and
    WHERE.
   </para>

   <para>
    LEFT OUTER JOIN returns all rows in the qualified Cartesian product
P
Peter Eisentraut 已提交
457
    (i.e., all combined rows that pass its ON condition), plus one copy of each
458 459
    row in the left-hand table for which there was no right-hand row that
    passed the ON condition.  This left-hand row is extended to the full
P
Peter Eisentraut 已提交
460 461
    width of the joined table by inserting null values for the right-hand columns.
    Note that only the <literal>JOIN</>'s own ON or USING condition is considered while
462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493
    deciding which rows have matches.  Outer ON or WHERE conditions are
    applied afterwards.
   </para>

   <para>
    Conversely, 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 LEFT OUTER JOIN by switching
    the left and right inputs.
   </para>

   <para>
    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).
   </para>

   <para>
    For all the JOIN types except CROSS JOIN, you must write exactly one of
    ON <replaceable class="PARAMETER">join_condition</replaceable>,
    USING ( <replaceable class="PARAMETER">join_column_list</replaceable> ),
    or NATURAL.  ON is the most general case: you can write any qualification
    expression involving the two tables to be joined.
    A USING column list ( a, b, ... ) is shorthand for the ON condition
    left_table.a = right_table.a AND left_table.b = right_table.b ...
    Also, USING implies that only one of each pair of equivalent columns will
    be included in the JOIN output, not both.  NATURAL is shorthand for
    a USING list that mentions all similarly-named columns in the tables.
   </para>
  </refsect2>
   
494
  <refsect2 id="SQL-WHERE">
495
   <refsect2info>
496
    <date>2000-03-15</date>
497
   </refsect2info>
498
   <title id="sql-where-title">
499
    WHERE Clause
500
   </title>
501

502 503 504 505
   <para>
    The optional WHERE condition has the general form:
    
    <synopsis>
506
WHERE <replaceable class="PARAMETER">boolean_expr</replaceable>
507 508
    </synopsis>
    
509
    <replaceable class="PARAMETER">boolean_expr</replaceable>
510
    can consist of any expression which evaluates to a Boolean value.
B
Bruce Momjian 已提交
511
    In many cases, this expression will be:
512 513 514 515 516 517 518 519 520 521 522 523 524 525

    <synopsis>
     <replaceable class="PARAMETER">expr</replaceable> <replaceable class="PARAMETER">cond_op</replaceable> <replaceable class="PARAMETER">expr</replaceable>
    </synopsis>

    or

    <synopsis>
     <replaceable class="PARAMETER">log_op</replaceable> <replaceable class="PARAMETER">expr</replaceable>
    </synopsis>

    where <replaceable class="PARAMETER">cond_op</replaceable>
    can be one of: =, &lt;, &lt;=, &gt;, &gt;= or &lt;&gt;,
    a conditional operator like ALL, ANY, IN, LIKE, or a
B
Bruce Momjian 已提交
526
    locally defined operator, 
527 528
    and <replaceable class="PARAMETER">log_op</replaceable> can be one 
    of: AND, OR, NOT.
529 530
    SELECT will ignore all rows for which the WHERE condition does not return
    TRUE.
531 532 533
   </para>
  </refsect2>
  
534
  <refsect2 id="SQL-GROUPBY">
535
   <refsect2info>
536
    <date>2000-03-15</date>
537
   </refsect2info>
538
   <title id="sql-groupby-title">
539
    GROUP BY Clause
540 541
   </title>
   <para>
542
    GROUP BY specifies a grouped table derived by the application
543
    of this clause:
544
    <synopsis>
545
GROUP BY <replaceable class="PARAMETER">expression</replaceable> [, ...]
546 547 548 549
    </synopsis>
   </para>

   <para>
550 551 552 553 554 555 556
    GROUP BY will condense into a single row all selected rows that
    share the same values for the grouped columns.  Aggregate
    functions, if any, are computed across all rows making up each
    group, producing a separate value for each group (whereas without
    GROUP BY, an aggregate produces a single value computed across all
    the selected rows).  When GROUP BY is present, it is not valid for
    the <command>SELECT</command> output expression(s) to refer to
557
    ungrouped columns except within aggregate functions, since there
558 559
    would be more than one possible value to return for an ungrouped
    column.
560
   </para>
561 562

   <para>
563 564 565 566 567 568
    A GROUP BY item can be an input column name, or the name or
    ordinal number of an output column (<command>SELECT</command>
    expression), or it can be an arbitrary expression formed from
    input-column values.  In case of ambiguity, a GROUP BY name will
    be interpreted as an input-column name rather than an output
    column name.
569
   </para>
570 571
  </refsect2>

572
  <refsect2 id="SQL-HAVING">
573
   <refsect2info>
574
    <date>2000-03-15</date>
575
   </refsect2info>
576
   <title id="sql-having-title">
577
    HAVING Clause
578 579 580 581 582
   </title>
   <para>
    The optional HAVING condition has the general form:
    
    <synopsis>
583
HAVING <replaceable class="PARAMETER">boolean_expr</replaceable>
584 585
    </synopsis>
    
586
    where <replaceable class="PARAMETER">boolean_expr</replaceable> is the same
587 588
    as specified for the WHERE clause.
   </para>
589 590
    
   <para>
591
    HAVING specifies a grouped table derived by the elimination
592
    of group rows that do not satisfy the
593
    <replaceable class="PARAMETER">boolean_expr</replaceable>.
594 595 596 597
    HAVING is different from WHERE:
    WHERE filters individual rows before application of GROUP BY,
    while HAVING filters group rows created by GROUP BY.
   </para>
598

599
   <para>
600
    Each column referenced in 
601
    <replaceable class="PARAMETER">boolean_expr</replaceable> shall unambiguously
602 603
    reference a grouping column, unless the reference appears within an
    aggregate function.
604 605 606
   </para>
  </refsect2>
  
607
  <refsect2 id="SQL-ORDERBY">
608
   <refsect2info>
609
    <date>2000-03-15</date>
610
   </refsect2info>
611
   <title id="sql-orderby-title">
612
    ORDER BY Clause
613 614 615
   </title>
   <para>
    <synopsis>
616
ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...]
617 618 619
    </synopsis></para>
    
   <para>
620 621 622 623 624
    An ORDER BY item can be the name or ordinal number of an output
    column (<command>SELECT</command> expression), or it can be an
    arbitrary expression formed from input-column values.  In case of
    ambiguity, an ORDER BY name will be interpreted as an
    output-column name.
625
   </para>
626
   <para>
627
    The ordinal number refers to the ordinal (left-to-right) position
628
    of the result column. This feature makes it possible to define an ordering
629
    on the basis of a column that does not have a unique name.
630
    This is never absolutely necessary because it is always possible
631
    to assign a name to a result column using the AS clause, e.g.:
632
    <programlisting>
633
SELECT title, date_prod + 1 AS newlen FROM films ORDER BY newlen;
634 635 636
    </programlisting></para>
    
   <para>
637 638 639
    It is also possible to ORDER BY
    arbitrary expressions (an extension to SQL92),
    including fields that do not appear in the
640
    SELECT result list.
641
    Thus the following statement is legal:
642
    <programlisting>
643
SELECT name FROM distributors ORDER BY code;
644
    </programlisting>
645 646 647 648 649 650
    A limitation of this feature is that an ORDER BY clause applying to the
    result of a UNION, INTERSECT, or EXCEPT query may only specify an output
    column name or number, not an expression.
   </para>
    
   <para>
651 652 653 654 655
    Note that if an ORDER BY item is a simple name that matches both
    a result column name and an input column name, ORDER BY will interpret
    it as the result column name.  This is the opposite of the choice that
    GROUP BY will make in the same situation.  This inconsistency is
    mandated by the SQL92 standard.
656
   </para>
657 658
    
   <para>
P
Peter Eisentraut 已提交
659 660 661 662 663 664 665
    Optionally one may add the key word <literal>DESC</> (descending)
    or <literal>ASC</> (ascending) after each column name in the
    <literal>ORDER BY</> clause.  If not specified, <literal>ASC</> is
    assumed by default.  Alternatively, a specific ordering operator
    name may be specified.  <literal>ASC</> is equivalent to
    <literal>USING &lt;</> and <literal>DESC</> is equivalent to
    <literal>USING &gt;</>.
666
   </para>
667 668 669 670 671 672 673

   <para>
   The null value sorts higher than any other value in a domain. In other
   words, with ascending sort order nulls sort at the end and with
   descending sort order nulls sort at the beginning.
   </para>

674 675 676 677 678 679
   <para>
    Data of character types is sorted according to the locale-specific
    collation order that was established when the database cluster
    was initialized.
   </para>

680 681
  </refsect2>
  
682
  <refsect2 id="SQL-UNION">
683
   <refsect2info>
684
    <date>2000-12-11</date>
685
   </refsect2info>
686
   <title id="sql-union-title">
687
    UNION Clause
688 689 690
   </title>
   <para>
    <synopsis>
691
<replaceable class="PARAMETER">table_query</replaceable> UNION [ ALL ] <replaceable class="PARAMETER">table_query</replaceable>
692
    [ ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...] ]
693
    [ LIMIT { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
B
Bruce Momjian 已提交
694
    [ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
695
    </synopsis>
696

697 698
    where
    <replaceable class="PARAMETER">table_query</replaceable>
699 700
    specifies any select expression without an ORDER BY, LIMIT, or FOR UPDATE
    clause.  (ORDER BY and LIMIT can be attached to a sub-expression
701 702 703
    if it is enclosed in parentheses.  Without parentheses, these clauses
    will be taken to apply to the result of the UNION, not to its right-hand
    input expression.)
704
   </para>
705 706
    
   <para>
707
    The UNION operator computes the collection (set union) of the rows
708 709 710 711
    returned by the queries involved.  The two
    <command>SELECT</command> statements that represent the direct
    operands of the UNION must produce the same number of columns, and
    corresponding columns must be of compatible data types.
712
   </para>
713 714
    
   <para>
715 716 717
    The result of UNION does not contain any duplicate rows
    unless the ALL option is specified.  ALL prevents elimination of
    duplicates.
718
   </para>
719 720
    
   <para>
721 722 723
    Multiple UNION operators in the same <command>SELECT</command>
    statement are evaluated left to right, unless otherwise indicated
    by parentheses.
724 725 726 727 728
   </para>
    
   <para>
    Currently, FOR UPDATE may not be specified either for a UNION result
    or for the inputs of a UNION.
729 730
   </para>

731 732
  </refsect2>

733
  <refsect2 id="SQL-INTERSECT">
734
   <refsect2info>
735
    <date>2000-12-11</date>
736
   </refsect2info>
737
   <title id="sql-intersect-title">
738 739 740 741
    INTERSECT Clause
   </title>
   <para>
    <synopsis>
742 743
<replaceable class="PARAMETER">table_query</replaceable> INTERSECT [ ALL ] <replaceable class="PARAMETER">table_query</replaceable>
    [ ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...] ]
744
    [ LIMIT { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
B
Bruce Momjian 已提交
745
    [ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
746 747 748 749
    </synopsis>
    
    where
    <replaceable class="PARAMETER">table_query</replaceable>
750 751
    specifies any select expression without an ORDER BY, LIMIT, or 
    FOR UPDATE clause.
752 753
   </para>

754
   <para>
755 756 757 758 759 760 761 762
    INTERSECT is similar to UNION, except that it produces only rows that
    appear in both query outputs, rather than rows that appear in either.
   </para>
    
   <para>
    The result of INTERSECT does not contain any duplicate rows
    unless the ALL option is specified.  With ALL, a row that has
    m duplicates in L and n duplicates in R will appear min(m,n) times.
763
   </para>
764 765 766
    
   <para>
    Multiple INTERSECT operators in the same SELECT statement are
767
    evaluated left to right, unless parentheses dictate otherwise.
768 769 770
    INTERSECT binds more tightly than UNION --- that is,
    A UNION B INTERSECT C will be read as 
    A UNION (B INTERSECT C) unless otherwise specified by parentheses.
771
   </para>
772 773
  </refsect2>

774
  <refsect2 id="SQL-EXCEPT">
775
   <refsect2info>
776
    <date>2000-12-11</date>
777
   </refsect2info>
778
   <title id="sql-except-title">
779 780 781 782
    EXCEPT Clause
   </title>
   <para>
    <synopsis>
783 784
<replaceable class="PARAMETER">table_query</replaceable> EXCEPT [ ALL ] <replaceable class="PARAMETER">table_query</replaceable>
    [ ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...] ]
785
    [ LIMIT { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
B
Bruce Momjian 已提交
786
    [ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
787
    </synopsis>
788
    
789 790
    where
    <replaceable class="PARAMETER">table_query</replaceable>
791 792
    specifies any select expression without an ORDER BY, LIMIT,
    or FOR UPDATE clause.
793 794
   </para>

795
   <para>
796 797
    EXCEPT is similar to UNION, except that it produces only rows that
    appear in the left query's output but not in the right query's output.
798
   </para>
799 800 801 802 803 804 805
    
   <para>
    The result of EXCEPT does not contain any duplicate rows
    unless the ALL option is specified.  With ALL, a row that has
    m duplicates in L and n duplicates in R will appear max(m-n,0) times.
   </para>
    
806 807
   <para>
    Multiple EXCEPT operators in the same SELECT statement are
808
    evaluated left to right, unless parentheses dictate otherwise.
809
    EXCEPT binds at the same level as UNION.
810 811 812 813 814 815 816 817 818 819 820 821
   </para>
  </refsect2>

  <refsect2 id="SQL-LIMIT">
   <refsect2info>
    <date>2000-02-20</date>
   </refsect2info>
   <title id="sql-limit-title">
    LIMIT Clause
   </title>
   <para>
    <synopsis>
822
    LIMIT { <replaceable class="PARAMETER">count</replaceable> | ALL }
823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842
    OFFSET <replaceable class="PARAMETER">start</replaceable>
    </synopsis>
    
    where
    <replaceable class="PARAMETER">count</replaceable> specifies the
    maximum number of rows to return, and
    <replaceable class="PARAMETER">start</replaceable> specifies the
    number of rows to skip before starting to return rows.
   </para>

   <para>
    LIMIT allows you to retrieve just a portion of the rows that are generated
    by the rest of the query.  If a limit count is given, no more than that
    many rows will be returned.  If an offset is given, that many rows will
    be skipped before starting to return rows.
   </para>

   <para>
    When using LIMIT, it is a good idea to use an ORDER BY clause that
    constrains the result rows into a unique order.  Otherwise you will get
B
Bruce Momjian 已提交
843
    an unpredictable subset of the query's rows---you may be asking for
844
    the tenth through twentieth rows, but tenth through twentieth in what
B
Bruce Momjian 已提交
845
    ordering?  You don't know what ordering unless you specify ORDER BY.
846 847 848
   </para>

   <para>
849
    As of <productname>PostgreSQL</productname> 7.0, the
850 851
    query optimizer takes LIMIT into account when generating a query plan,
    so you are very likely to get different plans (yielding different row
B
Bruce Momjian 已提交
852
    orders) depending on what you use for LIMIT and OFFSET.  Thus, using
853 854 855 856 857 858
    different LIMIT/OFFSET values to select different subsets of a query
    result <emphasis>will give inconsistent results</emphasis> unless
    you enforce a predictable result ordering with 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 ORDER BY is used to constrain the order.
859
   </para>
860
  </refsect2>
861 862 863 864 865 866 867 868 869 870 871 872 873 874 875

  <refsect2 id="SQL-FOR-UPDATE">
   <refsect2info>
    <date>2002-08-28</date>
   </refsect2info>
   <title id="sql-for-update-title">
    FOR UPDATE Clause
   </title>
   <para>
    <synopsis>
    FOR UPDATE [ OF <replaceable class="PARAMETER">tablename</replaceable> [, ...] ]
    </synopsis>
   </para>

   <para>
876 877 878 879 880 881 882 883 884 885 886 887
    FOR UPDATE causes the rows retrieved by the query 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
    UPDATE</command> will wait for the other transaction to complete,
    and will then lock and return the updated row (or no row, if the
888
    row was deleted).  For further discussion see <xref linkend="mvcc">.
889 890 891
   </para>

   <para>
892 893 894
    If specific tables are named in FOR UPDATE, then only rows coming
    from those tables are locked; any other tables used in the
    <command>SELECT</command> are simply read as usual.
895 896 897 898 899
   </para>

   <para>
    FOR UPDATE cannot be used in contexts where returned rows can't be clearly
    identified with individual table rows; for example it can't be used with
T
Tom Lane 已提交
900 901 902 903 904 905 906
    aggregation.
   </para>

   <para>
    FOR UPDATE may appear before LIMIT for compatibility with
    pre-7.3 applications.  However, it effectively executes after LIMIT,
    and so that is the recommended place to write it.
907 908 909
   </para>
  </refsect2>

910
 </refsect1>
911

912 913 914 915
 <refsect1 id="R1-SQL-SELECT-2">
  <title>
   Usage
  </title>
916

917 918 919
  <para>
   To join the table <literal>films</literal> with the table
   <literal>distributors</literal>:
920 921

   <programlisting>
922 923 924
SELECT f.title, f.did, d.name, f.date_prod, f.kind
    FROM distributors d, films f
    WHERE f.did = d.did
925

926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946
           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
 Une Femme est une Femme   | 102 | Jean Luc Godard  | 1961-03-12 | Romantic
 Vertigo                   | 103 | Paramount        | 1958-11-14 | Action
 Becket                    | 103 | Paramount        | 1964-02-03 | Drama
 48 Hrs                    | 103 | Paramount        | 1982-10-22 | Action
 War and Peace             | 104 | Mosfilm          | 1967-02-12 | Drama
 West Side Story           | 105 | United Artists   | 1961-01-03 | Musical
 Bananas                   | 105 | United Artists   | 1971-07-13 | Comedy
 Yojimbo                   | 106 | Toho             | 1961-06-16 | Drama
 There's a Girl in my Soup | 107 | Columbia         | 1970-06-11 | Comedy
 Taxi Driver               | 107 | Columbia         | 1975-05-15 | Action
 Absence of Malice         | 107 | Columbia         | 1981-11-15 | Action
 Storia di una donna       | 108 | Westward         | 1970-08-15 | Romantic
 The King and I            | 109 | 20th Century Fox | 1956-08-11 | Musical
 Das Boot                  | 110 | Bavaria Atelier  | 1981-11-11 | Drama
 Bed Knobs and Broomsticks | 111 | Walt Disney      |            | Musical
(17 rows)
</programlisting>
947 948
  </para>

949 950
  <para>
   To sum the column <literal>len</literal> of all films and group
951
   the results by <literal>kind</literal>:
952

953
<programlisting>
954
SELECT kind, SUM(len) AS total FROM films GROUP BY kind;
955

956 957 958 959 960 961 962 963 964
   kind   | total
----------+-------
 Action   | 07:34
 Comedy   | 02:58
 Drama    | 14:28
 Musical  | 06:42
 Romantic | 04:38
(5 rows)
</programlisting>
965
  </para>
966 967 968

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

972
<programlisting>
973 974 975 976
SELECT kind, SUM(len) AS total
    FROM films
    GROUP BY kind
    HAVING SUM(len) < INTERVAL '5 hour';
977

978 979 980 981 982 983
 kind     | total
----------+-------
 Comedy   | 02:58
 Romantic | 04:38
(2 rows)
</programlisting>
984 985
  </para>

986
  <para>
987
   The following two examples are identical ways of sorting the individual
988 989
   results according to the contents of the second column
   (<literal>name</literal>):
990 991

   <programlisting>
992 993
SELECT * FROM distributors ORDER BY name;
SELECT * FROM distributors ORDER BY 2;
994

995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011
 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
(13 rows)
</programlisting>
1012
  </para>
1013 1014 1015 1016 1017

  <para>
   This example shows how to obtain the union of the tables
   <literal>distributors</literal> and
   <literal>actors</literal>, restricting the results to those that begin
1018
   with letter W in each table.  Only distinct rows are wanted, so the
1019
   ALL keyword is omitted:
1020

1021 1022 1023 1024 1025 1026 1027 1028
<programlisting>
distributors:               actors:
 did |     name              id |     name
-----+--------------        ----+----------------
 108 | Westward               1 | Woody Allen
 111 | Walt Disney            2 | Warren Beatty
 112 | Warner Bros.           3 | Walter Matthau
 ...                         ...
1029

1030
SELECT distributors.name
1031 1032
    FROM   distributors
    WHERE  distributors.name LIKE 'W%'
1033 1034 1035
UNION
SELECT actors.name
    FROM   actors
T
Tatsuo Ishii 已提交
1036
    WHERE  actors.name LIKE 'W%';
1037

1038 1039 1040 1041 1042 1043 1044 1045
      name
----------------
 Walt Disney
 Walter Matthau
 Warner Bros.
 Warren Beatty
 Westward
 Woody Allen
1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082
</programlisting>
  </para>

  <para>
   This example shows how to use a table function, both with and without
   a column definition list.

<programlisting>
distributors:
 did |     name
-----+--------------
 108 | Westward
 111 | Walt Disney
 112 | Warner Bros.
 ...

CREATE FUNCTION distributors(int)
  RETURNS SETOF distributors AS '
  SELECT * FROM distributors WHERE did = $1;
  ' LANGUAGE SQL;

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

CREATE FUNCTION distributors_2(int)
  RETURNS SETOF RECORD AS '
  SELECT * FROM distributors WHERE did = $1;
  ' LANGUAGE SQL;

SELECT * FROM distributors_2(111) AS (f1 int, f2 text);
 f1  |     f2
-----+-------------
 111 | Walt Disney
(1 row)
1083
</programlisting>
1084
  </para>
1085 1086 1087 1088 1089 1090 1091 1092
 </refsect1>
 
 <refsect1 id="R1-SQL-SELECT-3">
  <title>
   Compatibility
  </title>
  
  <refsect2 id="R2-SQL-SELECT-4">
1093 1094 1095
   <refsect2info>
    <date>1998-09-24</date>
   </refsect2info>
1096
   <title>Extensions</title>
1097 1098

   <para>
1099
<productname>PostgreSQL</productname> allows one to omit 
1100
the <command>FROM</command> clause from a query. This feature
P
Peter Eisentraut 已提交
1101
was retained from the original PostQUEL query language.  It has
1102
a straightforward use to compute the results of simple expressions:
1103 1104 1105 1106 1107 1108 1109 1110 1111

  <programlisting>
SELECT 2+2;

 ?column?
----------
        4
  </programlisting>

1112 1113 1114
Some other <acronym>SQL</acronym> databases cannot do this except by
introducing a dummy one-row table to do the select from.  A less
obvious use is to abbreviate a normal select from one or more tables:
1115

1116
  <programlisting>
1117
SELECT distributors.* WHERE distributors.name = 'Westward';
1118

1119 1120 1121
 did | name
-----+----------
 108 | Westward
1122
  </programlisting>
1123 1124 1125 1126 1127 1128 1129 1130 1131 1132 1133 1134 1135 1136 1137 1138

This works because an implicit FROM item is added for each table that is
referenced in the query but not mentioned in FROM.  While this is a convenient
shorthand, it's easy to misuse.  For example, the query
  <programlisting>
SELECT distributors.* FROM distributors d;
  </programlisting>
is probably a mistake; most likely the user meant
  <programlisting>
SELECT d.* FROM distributors d;
  </programlisting>
rather than the unconstrained join
  <programlisting>
SELECT distributors.* FROM distributors d, distributors distributors;
  </programlisting>
that he will actually get.  To help detect this sort of mistake,
1139
<Productname>PostgreSQL</Productname> 7.1
1140 1141 1142
and later will warn if the implicit-FROM feature is used in a query that also
contains an explicit FROM clause.

1143
   </para>
1144 1145 1146 1147 1148

   <para>
    The table-function feature is a <productname>PostgreSQL</productname>
    extension.
   </para>
1149
  </refsect2>
1150 1151

  <refsect2 id="R2-SQL-SELECT-5">
1152
   <refsect2info>
1153
    <date>1998-09-24</date>
1154 1155 1156 1157 1158 1159 1160 1161 1162 1163 1164 1165
   </refsect2info>
   <title>
    <acronym>SQL92</acronym>
   </title>
   <para>
   </para>
   
   <refsect3 id="R3-SQL-SELECT-1">
    <refsect3info>
     <date>1998-04-15</date>
    </refsect3info>
    <title>
1166
     SELECT Clause
1167 1168
    </title>
    <para>
1169
     In the <acronym>SQL92</acronym> standard, the optional keyword <literal>AS</>
1170 1171
     is just noise and can be 
     omitted without affecting the meaning.
1172
     The <productname>PostgreSQL</productname> parser requires this keyword when
1173
     renaming output columns because the type extensibility features lead to
1174
     parsing ambiguities
1175
     in this context.  <literal>AS</literal> is optional in FROM items, however.</para>
1176
     
1177 1178
    <para>
     The DISTINCT ON phrase is not part of <acronym>SQL92</acronym>.
1179
     Nor are LIMIT and OFFSET.
1180
    </para>
1181 1182 1183 1184 1185
     
    <para>
     In <acronym>SQL92</acronym>, an ORDER BY clause may only use result
     column names or numbers, while a GROUP BY clause may only use input
     column names.
1186
     <productname>PostgreSQL</productname> extends each of these clauses to
1187 1188
     allow the other choice as well (but it uses the standard's interpretation
     if there is ambiguity).
1189
     <productname>PostgreSQL</productname> also allows both clauses to specify
1190 1191 1192
     arbitrary expressions.  Note that names appearing in an expression will
     always be taken as input-column names, not as result-column names.
    </para>
1193 1194 1195 1196
   </refsect3>

   <refsect3 id="R3-SQL-UNION-1">
    <refsect3info>
1197
     <date>1998-09-24</date>
1198 1199
    </refsect3info>
    <title>
1200
     UNION/INTERSECT/EXCEPT Clause
1201 1202
    </title>
    <para>
1203 1204
     The <acronym>SQL92</acronym> syntax for UNION/INTERSECT/EXCEPT allows an
     additional CORRESPONDING BY option:
1205 1206 1207 1208 1209 1210 1211 1212
     <synopsis> 
<replaceable class="PARAMETER">table_query</replaceable> UNION [ALL]
    [CORRESPONDING [BY (<replaceable class="PARAMETER">column</replaceable> [,...])]]
    <replaceable class="PARAMETER">table_query</replaceable>
     </synopsis></para>

    <para>
     The CORRESPONDING BY clause is not supported by
1213
     <productname>PostgreSQL</productname>.
1214 1215 1216 1217 1218 1219 1220 1221 1222 1223
    </para>
   </refsect3>
   
  </refsect2>
 </refsect1>
</refentry>

<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
1224
sgml-omittag:nil
1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235
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
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
1236
-->