select.sgml 36.4 KB
Newer Older
1
<!--
B
Bruce Momjian 已提交
2
$Header: /cvsroot/pgsql/doc/src/sgml/ref/select.sgml,v 1.47 2001/09/23 03:39:01 momjian Exp $
3 4 5
Postgres documentation
-->

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 30
    [ { UNION | INTERSECT | EXCEPT [ ALL ] } <replaceable class="PARAMETER">select</replaceable> ]
    [ ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...] ]
31
    [ FOR UPDATE [ OF <replaceable class="PARAMETER">tablename</replaceable> [, ...] ] ]
B
Bruce Momjian 已提交
32 33
    [ LIMIT [ <replaceable class="PARAMETER">start</replaceable> , ] { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
    [ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
34 35 36 37 38 39 40 41 42 43 44

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> ) ]
|
<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> ) ]
45 46 47 48
  </synopsis>
  
  <refsect2 id="R2-SQL-SELECT-1">
   <refsect2info>
49
    <date>2000-12-11</date>
50 51 52 53
   </refsect2info>
   <title>
    Inputs
   </title>
54

55 56 57
   <para>
    <variablelist>
     <varlistentry>
58
      <term><replaceable class="PARAMETER">expression</replaceable></term>
59 60 61 62 63 64 65 66
      <listitem>
       <para>
	The name of a table's column or an expression.
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
67
      <term><replaceable class="PARAMETER">output_name</replaceable></term>
68 69
      <listitem>
       <para>
70
	Specifies another name for an output column using
71 72 73
	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
74
	<replaceable class="PARAMETER">output_name</replaceable>
75 76
	cannot be used in the WHERE or HAVING clauses; write out the
	expression instead.
77 78 79 80 81
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
82
      <term><replaceable class="PARAMETER">from_item</replaceable></term>
83 84
      <listitem>
       <para>
85
        A table reference, sub-SELECT, or JOIN clause.  See below for details.
86 87 88 89 90
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
91
      <term><replaceable class="PARAMETER">condition</replaceable></term>
92 93
      <listitem>
       <para>
94 95
	A boolean expression giving a result of true or false.
	See the WHERE and HAVING clause descriptions below.
96 97 98 99 100
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
101
      <term><replaceable class="PARAMETER">select</replaceable></term>
102 103
      <listitem>
       <para>
104 105 106
	A select statement with all features except the ORDER BY, FOR UPDATE,
	and LIMIT clauses (even those can be used when the select is
	parenthesized).
107 108 109 110
       </para>
      </listitem>
     </varlistentry>
     
111 112 113 114 115 116 117
    </variablelist>
   </para>

   <para>
    FROM items can contain:
    <variablelist>
     
118
     <varlistentry>
119
      <term><replaceable class="PARAMETER">table_name</replaceable></term>
120 121
      <listitem>
       <para>
122 123 124 125
	The name of an existing table or view.  If ONLY is specified, only that
	table is scanned.  If ONLY is not specified, the table and all its
	descendant tables (if any) are scanned.  * can be appended to the
	table name to indicate that descendant tables are to be scanned,
126 127
	but in the current version, this is the default behavior.
	(In releases before 7.1, ONLY was the default behavior.)
128 129 130 131 132 133 134 135 136 137 138 139 140 141
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
      <term><replaceable class="PARAMETER">alias</replaceable></term>
      <listitem>
       <para>
	A substitute name for the preceding
	<replaceable class="PARAMETER">table_name</replaceable>.
	An alias is used for brevity or to eliminate ambiguity for self-joins
	(where the same table is scanned multiple times).  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.
142 143 144 145 146
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
147
      <term><replaceable class="PARAMETER">select</replaceable></term>
148 149
      <listitem>
       <para>
150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183
	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>
     
     <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.
184 185 186 187
       </para>
      </listitem>
     </varlistentry>
     
188 189 190 191 192 193 194 195 196 197
     <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>

198 199 200 201 202 203
    </variablelist>
   </para>
  </refsect2>
  
  <refsect2 id="R2-SQL-SELECT-2">
   <refsect2info>
204
    <date>1998-09-24</date>
205 206 207 208
   </refsect2info>
   <title>
    Outputs
   </title>
209
   <para>
210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231

    <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>
232
   </para>
233 234
  </refsect2>
 </refsynopsisdiv>
235

236 237
 <refsect1 id="R1-SQL-SELECT-1">
  <refsect1info>
238
   <date>2000-12-11</date>
239 240 241 242 243
  </refsect1info>
  <title>
   Description
  </title>
  <para>
244 245
   <command>SELECT</command> will return rows from one or more tables.
   Candidates for selection are rows which satisfy the WHERE condition;
246
   if WHERE is omitted, all rows are candidates.
247
   (See <xref linkend="sql-where" endterm="sql-where-title">.)
248
  </para>
249

250
  <para>
251 252 253 254 255 256 257
   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.
258
  </para>
259

260
  <para>
261
   <command>DISTINCT</command> will eliminate duplicate rows from the
262
   result.
263
   <command>ALL</command> (the default) will return all candidate rows,
264 265
   including duplicates.
  </para>
266

267 268 269
  <para>
   <command>DISTINCT ON</command> eliminates rows that match on all the
   specified expressions, keeping only the first row of each set of
270 271
   duplicates.  The DISTINCT ON expressions are interpreted using the
   same rules as for ORDER BY items; see below.
272
   Note that the <quote>first row</quote> of each set is unpredictable
273 274 275 276 277 278 279 280 281 282 283 284 285
   unless <command>ORDER BY</command> is used to ensure that the desired
   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>

286
  <para>
287
   The GROUP BY clause allows a user to divide a table
288
   into groups of rows that match on one or more values.
289
   (See <xref linkend="sql-groupby" endterm="sql-groupby-title">.)
290 291
  </para>

292
  <para>
293 294
   The HAVING clause allows selection of only those groups of rows
   meeting the specified condition.
295
   (See <xref linkend="sql-having" endterm="sql-having-title">.)
296
  </para>
297 298
   
  <para>
299 300 301
   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.
302
   (See <xref linkend="sql-orderby" endterm="sql-orderby-title">.)
303
  </para>
304 305
   
  <para>
306 307 308 309 310 311 312
   SELECT queries can be combined using UNION, INTERSECT, and EXCEPT
   operators.  Use parentheses if necessary to determine the ordering
   of these operators.
  </para>
   
  <para>
   The UNION operator computes the collection of rows
313
   returned by the queries involved.
314
   Duplicate rows are eliminated unless ALL is specified.
315
   (See <xref linkend="sql-union" endterm="sql-union-title">.)
316
  </para>
317 318
   
  <para>
319 320
   The INTERSECT operator computes the rows that are common to both queries.
   Duplicate rows are eliminated unless ALL is specified.
321
   (See <xref linkend="sql-intersect" endterm="sql-intersect-title">.)
322
  </para>
323 324
   
  <para>
325
   The EXCEPT operator computes the rows returned by the first query but
326
   not the second query.
327
   Duplicate rows are eliminated unless ALL is specified.
328
   (See <xref linkend="sql-except" endterm="sql-except-title">.)
329
  </para>
330
   
331 332 333
  <para>
   The FOR UPDATE clause allows the SELECT statement to perform 
   exclusive locking of selected rows.
334
  </para>
335 336
   
  <para>
337 338 339
   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">.)
340
  </para>
341

342
  <para>
343
   You must have SELECT privilege to a table to read its values
344 345
   (See the <command>GRANT</command>/<command>REVOKE</command> statements).
  </para>
346
   
347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364
  <refsect2 id="SQL-FROM">
   <refsect2info>
    <date>2000-12-11</date>
   </refsect2info>
   <title id="sql-from-title">
    FROM Clause
   </title>

   <para>
    The FROM clause specifies one or more source tables for the SELECT.
    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.
   </para>

   <para>
    When a FROM item is a simple table name, it implicitly includes rows
365
    from sub-tables (inheritance children) of the table.
366
    <command>ONLY</command> will
367
    suppress rows from sub-tables of the table.  Before
368
    <Productname>Postgres</Productname> 7.1,
369
    this was the default result, and adding sub-tables was done
370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398
    by appending <command>*</command> to the table name.
    This old behaviour is available via the command 
    <command>SET SQL_Inheritance TO OFF;</command>
   </para>

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

   <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 已提交
399
    (i.e., all combined rows that pass its ON condition), plus one copy of each
400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435
    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
    width of the joined table by inserting NULLs for the right-hand columns.
    Note that only the JOIN's own ON or USING condition is considered while
    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>
   
436
  <refsect2 id="SQL-WHERE">
437
   <refsect2info>
438
    <date>2000-03-15</date>
439
   </refsect2info>
440
   <title id="sql-where-title">
441
    WHERE Clause
442
   </title>
443

444 445 446 447
   <para>
    The optional WHERE condition has the general form:
    
    <synopsis>
448
WHERE <replaceable class="PARAMETER">boolean_expr</replaceable>
449 450
    </synopsis>
    
451 452
    <replaceable class="PARAMETER">boolean_expr</replaceable>
    can consist of any expression which evaluates to a boolean value.
B
Bruce Momjian 已提交
453
    In many cases, this expression will be:
454 455 456 457 458 459 460 461 462 463 464 465 466 467

    <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 已提交
468
    locally defined operator, 
469 470
    and <replaceable class="PARAMETER">log_op</replaceable> can be one 
    of: AND, OR, NOT.
471 472
    SELECT will ignore all rows for which the WHERE condition does not return
    TRUE.
473 474 475
   </para>
  </refsect2>
  
476
  <refsect2 id="SQL-GROUPBY">
477
   <refsect2info>
478
    <date>2000-03-15</date>
479
   </refsect2info>
480
   <title id="sql-groupby-title">
481
    GROUP BY Clause
482 483
   </title>
   <para>
484
    GROUP BY specifies a grouped table derived by the application
485
    of this clause:
486
    <synopsis>
487
GROUP BY <replaceable class="PARAMETER">expression</replaceable> [, ...]
488 489 490 491
    </synopsis>
   </para>

   <para>
492
    GROUP BY will condense into a single row all selected rows that share the
493 494 495 496
    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
497 498
    rows).  When GROUP BY is present, it is not valid for the SELECT
    output expression(s) to refer to
499 500
    ungrouped columns except within aggregate functions, since there
    would be more than one possible value to return for an ungrouped column.
501
   </para>
502 503

   <para>
504 505 506 507
    A GROUP BY item can be an input column name, or the name or ordinal
    number of an output column (SELECT expression), or it can be an arbitrary
    expression formed from input-column values.  In case of ambiguity, a GROUP
    BY name will 
508 509
    be interpreted as an input-column name rather than an output column name.
   </para>
510 511
  </refsect2>

512
  <refsect2 id="SQL-HAVING">
513
   <refsect2info>
514
    <date>2000-03-15</date>
515
   </refsect2info>
516
   <title id="sql-having-title">
517
    HAVING Clause
518 519 520 521 522
   </title>
   <para>
    The optional HAVING condition has the general form:
    
    <synopsis>
523
HAVING <replaceable class="PARAMETER">boolean_expr</replaceable>
524 525
    </synopsis>
    
526
    where <replaceable class="PARAMETER">boolean_expr</replaceable> is the same
527 528
    as specified for the WHERE clause.
   </para>
529 530
    
   <para>
531
    HAVING specifies a grouped table derived by the elimination
532
    of group rows that do not satisfy the
533
    <replaceable class="PARAMETER">boolean_expr</replaceable>.
534 535 536 537
    HAVING is different from WHERE:
    WHERE filters individual rows before application of GROUP BY,
    while HAVING filters group rows created by GROUP BY.
   </para>
538

539
   <para>
540
    Each column referenced in 
541
    <replaceable class="PARAMETER">boolean_expr</replaceable> shall unambiguously
542 543
    reference a grouping column, unless the reference appears within an
    aggregate function.
544 545 546
   </para>
  </refsect2>
  
547
  <refsect2 id="SQL-ORDERBY">
548
   <refsect2info>
549
    <date>2000-03-15</date>
550
   </refsect2info>
551
   <title id="sql-orderby-title">
552
    ORDER BY Clause
553 554 555
   </title>
   <para>
    <synopsis>
556
ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...]
557 558 559
    </synopsis></para>
    
   <para>
560 561 562 563
    An ORDER BY item can be the name or ordinal
    number of an output column (SELECT 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.
564
   </para>
565
   <para>
566
    The ordinal number refers to the ordinal (left-to-right) position
567
    of the result column. This feature makes it possible to define an ordering
568
    on the basis of a column that does not have a proper name.
569
    This is never absolutely necessary because it is always possible
570
    to assign a name to a result column using the AS clause, e.g.:
571
    <programlisting>
572
SELECT title, date_prod + 1 AS newlen FROM films ORDER BY newlen;
573 574 575
    </programlisting></para>
    
   <para>
576 577 578
    It is also possible to ORDER BY
    arbitrary expressions (an extension to SQL92),
    including fields that do not appear in the
579
    SELECT result list.
580
    Thus the following statement is legal:
581
    <programlisting>
582
SELECT name FROM distributors ORDER BY code;
583
    </programlisting>
584 585 586 587 588 589
    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>
590 591 592 593 594
    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.
595
   </para>
596 597
    
   <para>
598 599
    Optionally one may add the keyword DESC (descending)
    or ASC (ascending) after each column name in the ORDER BY clause.
600 601
    If not specified, ASC is assumed by default.  Alternatively, a
    specific ordering operator name may be specified.  ASC is equivalent
602
    to USING &lt; and DESC is equivalent to USING &gt;.
603
   </para>
604 605
  </refsect2>
  
606
  <refsect2 id="SQL-UNION">
607
   <refsect2info>
608
    <date>2000-12-11</date>
609
   </refsect2info>
610
   <title id="sql-union-title">
611
    UNION Clause
612 613 614
   </title>
   <para>
    <synopsis>
615
<replaceable class="PARAMETER">table_query</replaceable> UNION [ ALL ] <replaceable class="PARAMETER">table_query</replaceable>
616
    [ ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...] ]
B
Bruce Momjian 已提交
617 618
    [ LIMIT [ <replaceable class="PARAMETER">start</replaceable> , ] { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
    [ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
619
    </synopsis>
620

621 622
    where
    <replaceable class="PARAMETER">table_query</replaceable>
623 624 625 626 627
    specifies any select expression without an ORDER BY, FOR UPDATE,
    or LIMIT clause.  (ORDER BY and LIMIT can be attached to a sub-expression
    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.)
628
   </para>
629 630
    
   <para>
631
    The UNION operator computes the collection (set union) of the rows
632 633 634
    returned by the queries involved.
    The two SELECTs that represent the direct operands of the UNION must
    produce the same number of columns, and corresponding columns must be
635 636
    of compatible data types.
   </para>
637 638
    
   <para>
639 640 641
    The result of UNION does not contain any duplicate rows
    unless the ALL option is specified.  ALL prevents elimination of
    duplicates.
642
   </para>
643 644
    
   <para>
645
    Multiple UNION operators in the same SELECT statement are
646 647 648 649 650 651
    evaluated left to right, unless otherwise indicated by parentheses.
   </para>
    
   <para>
    Currently, FOR UPDATE may not be specified either for a UNION result
    or for the inputs of a UNION.
652 653
   </para>

654 655
  </refsect2>

656
  <refsect2 id="SQL-INTERSECT">
657
   <refsect2info>
658
    <date>2000-12-11</date>
659
   </refsect2info>
660
   <title id="sql-intersect-title">
661 662 663 664
    INTERSECT Clause
   </title>
   <para>
    <synopsis>
665 666
<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> ] [, ...] ]
B
Bruce Momjian 已提交
667 668
    [ LIMIT [ <replaceable class="PARAMETER">start</replaceable> , ] { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
    [ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
669 670 671 672
    </synopsis>
    
    where
    <replaceable class="PARAMETER">table_query</replaceable>
673 674
    specifies any select expression without an ORDER BY, FOR UPDATE,
    or LIMIT clause.
675 676
   </para>

677
   <para>
678 679 680 681 682 683 684 685
    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.
686
   </para>
687 688 689
    
   <para>
    Multiple INTERSECT operators in the same SELECT statement are
690
    evaluated left to right, unless parentheses dictate otherwise.
691 692 693
    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.
694
   </para>
695 696
  </refsect2>

697
  <refsect2 id="SQL-EXCEPT">
698
   <refsect2info>
699
    <date>2000-12-11</date>
700
   </refsect2info>
701
   <title id="sql-except-title">
702 703 704 705
    EXCEPT Clause
   </title>
   <para>
    <synopsis>
706 707
<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> ] [, ...] ]
B
Bruce Momjian 已提交
708 709
    [ LIMIT [ <replaceable class="PARAMETER">start</replaceable> , ] { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
    [ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
710
    </synopsis>
711
    
712 713
    where
    <replaceable class="PARAMETER">table_query</replaceable>
714 715
    specifies any select expression without an ORDER BY, FOR UPDATE,
    or LIMIT clause.
716 717
   </para>

718
   <para>
719 720
    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.
721
   </para>
722 723 724 725 726 727 728
    
   <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>
    
729 730
   <para>
    Multiple EXCEPT operators in the same SELECT statement are
731
    evaluated left to right, unless parentheses dictate otherwise.
732
    EXCEPT binds at the same level as UNION.
733 734 735 736 737 738 739 740 741 742 743 744
   </para>
  </refsect2>

  <refsect2 id="SQL-LIMIT">
   <refsect2info>
    <date>2000-02-20</date>
   </refsect2info>
   <title id="sql-limit-title">
    LIMIT Clause
   </title>
   <para>
    <synopsis>
B
Bruce Momjian 已提交
745
    LIMIT [ <replaceable class="PARAMETER">start</replaceable> , ] { <replaceable class="PARAMETER">count</replaceable> | ALL }
746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765
    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 已提交
766
    an unpredictable subset of the query's rows---you may be asking for
767
    the tenth through twentieth rows, but tenth through twentieth in what
B
Bruce Momjian 已提交
768
    ordering?  You don't know what ordering unless you specify ORDER BY.
769 770 771
   </para>

   <para>
772
    As of <productname>Postgres</productname> 7.0, the
773 774
    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 已提交
775
    orders) depending on what you use for LIMIT and OFFSET.  Thus, using
776 777 778 779 780 781
    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.
782
   </para>
783
  </refsect2>
784
 </refsect1>
785

786 787 788 789
 <refsect1 id="R1-SQL-SELECT-2">
  <title>
   Usage
  </title>
790

791 792 793
  <para>
   To join the table <literal>films</literal> with the table
   <literal>distributors</literal>:
794 795

   <programlisting>
796 797 798
SELECT f.title, f.did, d.name, f.date_prod, f.kind
    FROM distributors d, films f
    WHERE f.did = d.did
799

800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820
           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>
821 822
  </para>

823 824
  <para>
   To sum the column <literal>len</literal> of all films and group
825
   the results by <literal>kind</literal>:
826

827
<programlisting>
828
SELECT kind, SUM(len) AS total FROM films GROUP BY kind;
829

830 831 832 833 834 835 836 837 838
   kind   | total
----------+-------
 Action   | 07:34
 Comedy   | 02:58
 Drama    | 14:28
 Musical  | 06:42
 Romantic | 04:38
(5 rows)
</programlisting>
839
  </para>
840 841 842

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

846
<programlisting>
847 848 849 850
SELECT kind, SUM(len) AS total
    FROM films
    GROUP BY kind
    HAVING SUM(len) < INTERVAL '5 hour';
851

852 853 854 855 856 857
 kind     | total
----------+-------
 Comedy   | 02:58
 Romantic | 04:38
(2 rows)
</programlisting>
858 859
  </para>

860
  <para>
861
   The following two examples are identical ways of sorting the individual
862 863
   results according to the contents of the second column
   (<literal>name</literal>):
864 865

   <programlisting>
866 867
SELECT * FROM distributors ORDER BY name;
SELECT * FROM distributors ORDER BY 2;
868

869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885
 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>
886
  </para>
887 888 889 890 891

  <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
892
   with letter W in each table.  Only distinct rows are wanted, so the
893
   ALL keyword is omitted:
894

895 896 897 898 899 900 901 902
<programlisting>
distributors:               actors:
 did |     name              id |     name
-----+--------------        ----+----------------
 108 | Westward               1 | Woody Allen
 111 | Walt Disney            2 | Warren Beatty
 112 | Warner Bros.           3 | Walter Matthau
 ...                         ...
903

904
SELECT distributors.name
905 906
    FROM   distributors
    WHERE  distributors.name LIKE 'W%'
907 908 909
UNION
SELECT actors.name
    FROM   actors
T
Tatsuo Ishii 已提交
910
    WHERE  actors.name LIKE 'W%';
911

912 913 914 915 916 917 918 919 920
      name
----------------
 Walt Disney
 Walter Matthau
 Warner Bros.
 Warren Beatty
 Westward
 Woody Allen
</programlisting>
921
  </para>
922 923 924 925 926 927 928 929
 </refsect1>
 
 <refsect1 id="R1-SQL-SELECT-3">
  <title>
   Compatibility
  </title>
  
  <refsect2 id="R2-SQL-SELECT-4">
930 931 932 933 934 935 936 937 938 939
   <refsect2info>
    <date>1998-09-24</date>
   </refsect2info>
   <title>
    <acronym>Extensions</acronym>
   </title>

   <para>
<productname>Postgres</productname> allows one to omit 
the <command>FROM</command> clause from a query. This feature
940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955
was retained from the original PostQuel query language.  It has
a straightforward use to compute the results of simple constant
expressions:

  <programlisting>
SELECT 2+2;

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

Some other DBMSes 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:

956
  <programlisting>
957
SELECT distributors.* WHERE distributors.name = 'Westward';
958

959 960 961
 did | name
-----+----------
 108 | Westward
962
  </programlisting>
963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982

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,
<Productname>Postgres</Productname> 7.1
and later will warn if the implicit-FROM feature is used in a query that also
contains an explicit FROM clause.

983
   </para>
984
  </refsect2>
985 986

  <refsect2 id="R2-SQL-SELECT-5">
987
   <refsect2info>
988
    <date>1998-09-24</date>
989 990 991 992 993 994 995 996 997 998 999 1000
   </refsect2info>
   <title>
    <acronym>SQL92</acronym>
   </title>
   <para>
   </para>
   
   <refsect3 id="R3-SQL-SELECT-1">
    <refsect3info>
     <date>1998-04-15</date>
    </refsect3info>
    <title>
1001
     SELECT Clause
1002 1003
    </title>
    <para>
1004
     In the <acronym>SQL92</acronym> standard, the optional keyword <literal>AS</>
1005 1006 1007
     is just noise and can be 
     omitted without affecting the meaning.
     The <productname>Postgres</productname> parser requires this keyword when
1008
     renaming output columns because the type extensibility features lead to
1009
     parsing ambiguities
1010
     in this context.  <literal>AS</literal> is optional in FROM items, however.</para>
1011
     
1012 1013
    <para>
     The DISTINCT ON phrase is not part of <acronym>SQL92</acronym>.
1014
     Nor are LIMIT and OFFSET.
1015
    </para>
1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027
     
    <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.
     <productname>Postgres</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>Postgres</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.
    </para>
1028 1029 1030 1031
   </refsect3>

   <refsect3 id="R3-SQL-UNION-1">
    <refsect3info>
1032
     <date>1998-09-24</date>
1033 1034
    </refsect3info>
    <title>
1035
     UNION/INTERSECT/EXCEPT Clause
1036 1037
    </title>
    <para>
1038 1039
     The <acronym>SQL92</acronym> syntax for UNION/INTERSECT/EXCEPT allows an
     additional CORRESPONDING BY option:
1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058
     <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
     <productname>Postgres</productname>.
    </para>
   </refsect3>
   
  </refsect2>
 </refsect1>
</refentry>

<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
1059
sgml-omittag:nil
1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070
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:
1071
-->