aboutsummaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/select.sgml
blob: ab379f72f6ad49d302d2a474431b100103e411ec (plain)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
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
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
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
184
185
186
187
188
189
190
191
192
193
194
195
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
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
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
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
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
399
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
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
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
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/select.sgml,v 1.28 2000/03/27 17:14:43 thomas Exp $
Postgres documentation
-->

<refentry id="SQL-SELECT">
 <refmeta>
  <refentrytitle id="sql-select-title">
   SELECT
  </refentrytitle>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>
 <refnamediv>
  <refname>
   SELECT
  </refname>
  <refpurpose>
   Retrieve rows from a table or view.
  </refpurpose></refnamediv>
 <refsynopsisdiv>
  <refsynopsisdivinfo>
   <date>1999-07-20</date>
  </refsynopsisdivinfo>
  <synopsis>
SELECT [ ALL | DISTINCT [ ON ( <replaceable class="PARAMETER">expression</replaceable> [, ...] ) ] ]
    <replaceable class="PARAMETER">expression</replaceable> [ AS <replaceable class="PARAMETER">name</replaceable> ] [, ...]
    [ INTO [ TEMPORARY | TEMP ] [ TABLE ] <replaceable class="PARAMETER">new_table</replaceable> ]
    [ FROM <replaceable class="PARAMETER">table</replaceable> [ <replaceable class="PARAMETER">alias</replaceable> ] [, ...] ]
    [ WHERE <replaceable class="PARAMETER">condition</replaceable> ]
    [ GROUP BY <replaceable class="PARAMETER">column</replaceable> [, ...] ]
    [ HAVING <replaceable class="PARAMETER">condition</replaceable> [, ...] ]
    [ { UNION [ ALL ] | INTERSECT | EXCEPT } <replaceable class="PARAMETER">select</replaceable> ]
    [ ORDER BY <replaceable class="PARAMETER">column</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...] ]
    [ FOR UPDATE [ OF <replaceable class="PARAMETER">class_name</replaceable> [, ...] ] ]
    LIMIT { <replaceable class="PARAMETER">count</replaceable> | ALL } [ { OFFSET | , } <replaceable class="PARAMETER">start</replaceable> ]
  </synopsis>
  
  <refsect2 id="R2-SQL-SELECT-1">
   <refsect2info>
    <date>2000-03-15</date>
   </refsect2info>
   <title>
    Inputs
   </title>

   <para>
    <variablelist>
     <varlistentry>
      <term><replaceable class="PARAMETER">expression</replaceable></term>
      <listitem>
       <para>
	The name of a table's column or an expression.
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
      <term><replaceable class="PARAMETER">name</replaceable></term>
      <listitem>
       <para>
	Specifies another name for a column or an expression using
	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
	<replaceable class="PARAMETER">name</replaceable>
	cannot be used in the WHERE or HAVING clauses; write out the
	expression instead.
       </para>
      </listitem>
     </varlistentry>
     
    <varlistentry>
     <term>TEMPORARY</term>
     <term>TEMP</term>
     <listitem>
      <para>
	If TEMPORARY or TEMP is specified,
	the table is created unique to this session, and is
	automatically dropped on session exit.
      </para>
     </listitem>
    </varlistentry>

     <varlistentry>
      <term><replaceable class="PARAMETER">new_table</replaceable></term>
      <listitem>
       <para>
	If the INTO TABLE clause is specified, the result of the
	query will be stored in a new table with the indicated
	name.
	The target table (<replaceable class="PARAMETER">new_table</replaceable>) will
	be created automatically and must not exist before this command.
        Refer to <command>SELECT INTO</command> for more information.

	<note>
	 <para>
	  The <command>CREATE TABLE AS</command> statement will also
	  create a new  table from a select query.
	 </para>
	</note>
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
      <term><replaceable class="PARAMETER">table</replaceable></term>
      <listitem>
       <para>
	The name of an existing table referenced by the FROM clause.
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
      <term><replaceable class="PARAMETER">alias</replaceable></term>
      <listitem>
       <para>
	An alternate name for the preceding
	<replaceable class="PARAMETER">table</replaceable>.
	It is used for brevity or to eliminate ambiguity for joins
	within a single table.
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
      <term><replaceable class="PARAMETER">condition</replaceable></term>
      <listitem>
       <para>
	A boolean expression giving a result of true or false.
	See the WHERE clause.
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
      <term><replaceable class="PARAMETER">column</replaceable></term>
      <listitem>
       <para>
	The name of a table's column.
       </para>
      </listitem>
     </varlistentry>
     
     <varlistentry>
      <term><replaceable class="PARAMETER">select</replaceable></term>
      <listitem>
       <para>
	A select statement with all features except the ORDER BY and
	LIMIT clauses.
       </para>
      </listitem>
     </varlistentry>
     
    </variablelist>
   </para>
  </refsect2>
  
  <refsect2 id="R2-SQL-SELECT-2">
   <refsect2info>
    <date>1998-09-24</date>
   </refsect2info>
   <title>
    Outputs
   </title>
   <para>

    <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>
   </para>
  </refsect2>
 </refsynopsisdiv>

 <refsect1 id="R1-SQL-SELECT-1">
  <refsect1info>
   <date>2000-03-15</date>
  </refsect1info>
  <title>
   Description
  </title>
  <para>
   <command>SELECT</command> will return rows from one or more tables.
   Candidates for selection are rows which satisfy the WHERE condition;
   if WHERE is omitted, all rows are candidates.
   (See <xref linkend="sql-where" endterm="sql-where-title">.)
  </para>

  <para>
   <command>DISTINCT</command> will eliminate duplicate rows from the
   result.
   <command>ALL</command> (the default) will return all candidate rows,
   including duplicates.
  </para>

  <para>
   <command>DISTINCT ON</command> eliminates rows that match on all the
   specified expressions, keeping only the first row of each set of
   duplicates.  The DISTINCT ON expressions are interpreted using the
   same rules as for ORDER BY items; see below.
   Note that "the first row" of each set is unpredictable
   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>

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

  <para>
   The HAVING clause allows selection of only those groups of rows
   meeting the specified condition.
   (See <xref linkend="sql-having" endterm="sql-having-title">.)
  </para>
   
  <para>
   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.
   (See <xref linkend="sql-orderby-title" endterm="sql-orderby-title">.)
  </para>
   
  <para>
   The UNION operator allows the result to be the collection of rows
   returned by the queries involved.
   (See <xref linkend="sql-union" endterm="sql-union-title">.)
  </para>
   
  <para>
   The INTERSECT operator gives you the rows that are common to both queries.
   (See <xref linkend="sql-intersect" endterm="sql-intersect-title">.)
  </para>
   
  <para>
   The EXCEPT operator gives you the rows returned by the first query but
   not the second query.
   (See <xref linkend="sql-except" endterm="sql-except-title">.)
  </para>
   
  <para>
   The FOR UPDATE clause allows the SELECT statement to perform 
   exclusive locking of selected rows.
  </para>
   
  <para>
   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">.)
  </para>

  <para>
   You must have SELECT privilege to a table to read its values
   (See the <command>GRANT</command>/<command>REVOKE</command> statements).
  </para>
   
  <refsect2 id="SQL-WHERE">
   <refsect2info>
    <date>2000-03-15</date>
   </refsect2info>
   <title id="sql-where-title">
    WHERE Clause
   </title>

   <para>
    The optional WHERE condition has the general form:
    
    <synopsis>
WHERE <replaceable class="PARAMETER">boolean_expr</replaceable>
    </synopsis>
    
    <replaceable class="PARAMETER">boolean_expr</replaceable>
    can consist of any expression which evaluates to a boolean value.
    In many cases, this expression will be

    <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
    locally-defined operator, 
    and <replaceable class="PARAMETER">log_op</replaceable> can be one 
    of: AND, OR, NOT.
    SELECT will ignore all rows for which the WHERE condition does not return
    TRUE.
   </para>
  </refsect2>
  
  <refsect2 id="SQL-GROUPBY">
   <refsect2info>
    <date>2000-03-15</date>
   </refsect2info>
   <title id="sql-groupby-title">
    GROUP BY Clause
   </title>
   <para>
    GROUP BY specifies a grouped table derived by the application
    of this clause:
    <synopsis>
GROUP BY <replaceable class="PARAMETER">column</replaceable> [, ...]
    </synopsis>
   </para>

   <para>
    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 SELECT
    output expression(s) to refer to
    ungrouped columns except within aggregate functions, since there
    would be more than one possible value to return for an ungrouped column.
   </para>

   <para>
    An item in GROUP BY can also 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, a GROUP BY name will
    be interpreted as an input-column name rather than an output column name.
   </para>
  </refsect2>

  <refsect2 id="SQL-HAVING">
   <refsect2info>
    <date>2000-03-15</date>
   </refsect2info>
   <title id="sql-having-title">
    HAVING Clause
   </title>
   <para>
    The optional HAVING condition has the general form:
    
    <synopsis>
HAVING <replaceable class="PARAMETER">cond_expr</replaceable>
    </synopsis>
    
    where <replaceable class="PARAMETER">cond_expr</replaceable> is the same
    as specified for the WHERE clause.
   </para>
    
   <para>
    HAVING specifies a grouped table derived by the elimination
    of group rows that do not satisfy the
    <replaceable class="PARAMETER">cond_expr</replaceable>.
    HAVING is different from WHERE:
    WHERE filters individual rows before application of GROUP BY,
    while HAVING filters group rows created by GROUP BY.
   </para>

   <para>
    Each column referenced in 
    <replaceable class="PARAMETER">cond_expr</replaceable> shall unambiguously
    reference a grouping column, unless the reference appears within an
    aggregate function.
   </para>
  </refsect2>
  
  <refsect2 id="SQL-ORDERBY">
   <refsect2info>
    <date>2000-03-15</date>
   </refsect2info>
   <title id="sql-orderby-title">
    ORDER BY Clause
   </title>
   <para>
    <synopsis>
ORDER BY <replaceable class="PARAMETER">column</replaceable> [ ASC | DESC ] [, ...]
    </synopsis></para>
    
   <para>
    <replaceable class="PARAMETER">column</replaceable> can be either a
    result column name or an ordinal number.
   </para>
   <para>
    The ordinal numbers 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 proper name.
    This is never absolutely necessary because it is always possible
    to assign a name to a result column using the AS clause, e.g.:
    <programlisting>
SELECT title, date_prod + 1 AS newlen FROM films ORDER BY newlen;
    </programlisting></para>
    
   <para>
    It is also possible to ORDER BY
    arbitrary expressions (an extension to SQL92),
    including fields that do not appear in the
    SELECT result list.
    Thus the following statement is legal:
    <programlisting>
SELECT name FROM distributors ORDER BY code;
    </programlisting>

    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.
   </para>
    
   <para>
    Optionally one may add the keyword DESC (descending)
    or ASC (ascending) after each column name in the ORDER BY clause.
    If not specified, ASC is assumed by default.  Alternatively, a
    specific ordering operator name may be specified.  ASC is equivalent
    to USING '&lt;' and DESC is equivalent to USING '&gt;'.
   </para>
  </refsect2>
  
  <refsect2 id="SQL-UNION">
   <refsect2info>
    <date>1998-09-24</date>
   </refsect2info>
   <title id="sql-union-title">
    UNION Clause
   </title>
   <para>
    <synopsis>
<replaceable class="PARAMETER">table_query</replaceable> UNION [ ALL ] <replaceable class="PARAMETER">table_query</replaceable>
    [ ORDER BY <replaceable class="PARAMETER">column</replaceable> [ ASC | DESC ] [, ...] ]
    </synopsis>

    where
    <replaceable class="PARAMETER">table_query</replaceable>
    specifies any select expression without an ORDER BY or LIMIT clause.
   </para>
    
   <para>
    The UNION operator allows the result to be the collection of rows
    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
    of compatible data types.
   </para>
    
   <para>
    By default, the result of UNION does not contain any duplicate rows
    unless the ALL clause is specified.
   </para>
    
   <para>
    Multiple UNION operators in the same SELECT statement are
    evaluated left to right.
    Note that the ALL keyword is not global in nature, being 
    applied only for the current pair of table results.
   </para>

  </refsect2>

  <refsect2 id="SQL-INTERSECT">
   <refsect2info>
    <date>1998-09-24</date>
   </refsect2info>
   <title id="sql-intersect-title">
    INTERSECT Clause
   </title>
   <para>
    <synopsis>
<replaceable class="PARAMETER">table_query</replaceable> INTERSECT <replaceable class="PARAMETER">table_query</replaceable>
    [ ORDER BY <replaceable class="PARAMETER">column</replaceable> [ ASC | DESC ] [, ...] ]
    </synopsis>
    
    where
    <replaceable class="PARAMETER">table_query</replaceable>
    specifies any select expression without an ORDER BY or LIMIT clause.
   </para>

   <para>
    The INTERSECT operator gives you the rows that are common to both queries.
    The two SELECTs that represent the direct operands of the INTERSECT must
    produce the same number of columns, and corresponding columns must be
    of compatible data types.
   </para>
    
   <para>
    Multiple INTERSECT operators in the same SELECT statement are
    evaluated left to right, unless parentheses dictate otherwise.
   </para>
  </refsect2>

  <refsect2 id="SQL-EXCEPT">
   <refsect2info>
    <date>1998-09-24</date>
   </refsect2info>
   <title id="sql-except-title">
    EXCEPT Clause
   </title>
   <para>
    <synopsis>
<replaceable class="PARAMETER">table_query</replaceable> EXCEPT <replaceable class="PARAMETER">table_query</replaceable>
     [ ORDER BY <replaceable class="PARAMETER">column</replaceable> [ ASC | DESC ] [, ...] ]
    </synopsis>
    
    where
    <replaceable class="PARAMETER">table_query</replaceable>
    specifies any select expression without an ORDER BY or LIMIT clause.
   </para>

   <para>
    The EXCEPT operator gives you the rows returned by the first query but
    not the second query.
    The two SELECTs that represent the direct operands of the EXCEPT must
    produce the same number of columns, and corresponding columns must be
    of compatible data types.
   </para>

   <para>
    Multiple EXCEPT operators in the same SELECT statement are
    evaluated left to right, unless parentheses dictate otherwise.
   </para>
  </refsect2>

  <refsect2 id="SQL-LIMIT">
   <refsect2info>
    <date>2000-02-20</date>
   </refsect2info>
   <title id="sql-limit-title">
    LIMIT Clause
   </title>
   <para>
    <synopsis>
    LIMIT { <replaceable class="PARAMETER">count</replaceable> | ALL } [ { OFFSET | , } <replaceable class="PARAMETER">start</replaceable> ]
    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
    an unpredictable subset of the query's rows --- you may be asking for
    the tenth through twentieth rows, but tenth through twentieth in what
    ordering?  You don't know what ordering, unless you specified ORDER BY.
   </para>

   <para>
    As of <productname>Postgres</productname> 7.0, the
    query optimizer takes 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 give for LIMIT and OFFSET.  Thus, using
    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.
   </para>
  </refsect2>
 </refsect1>

 <refsect1 id="R1-SQL-SELECT-2">
  <title>
   Usage
  </title>

  <para>
   To join the table <literal>films</literal> with the table
   <literal>distributors</literal>:

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

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

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

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

   kind   | total
----------+-------
 Action   | 07:34
 Comedy   | 02:58
 Drama    | 14:28
 Musical  | 06:42
 Romantic | 04:38
(5 rows)
</programlisting>
  </para>

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

<programlisting>
SELECT kind, SUM(len) AS total
    FROM films
    GROUP BY kind
    HAVING SUM(len) < INTERVAL '5 hour';

 kind     | total
----------+-------
 Comedy   | 02:58
 Romantic | 04:38
(2 rows)
</programlisting>
  </para>

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

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

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

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

<programlisting>
distributors:               actors:
 did |     name              id |     name
-----+--------------        ----+----------------
 108 | Westward               1 | Woody Allen
 111 | Walt Disney            2 | Warren Beatty
 112 | Warner Bros.           3 | Walter Matthau
 ...                         ...

SELECT distributors.name
    FROM   distributors
    WHERE  distributors.name LIKE 'W%'
UNION
SELECT actors.name
    FROM   actors
    WHERE  actors.name LIKE 'W%'

      name
----------------
 Walt Disney
 Walter Matthau
 Warner Bros.
 Warren Beatty
 Westward
 Woody Allen
</programlisting>
  </para>
 </refsect1>
 
 <refsect1 id="R1-SQL-SELECT-3">
  <title>
   Compatibility
  </title>
  
  <refsect2 id="R2-SQL-SELECT-4">
   <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
was retained from the original PostQuel query language:
  <programlisting>
SELECT distributors.* WHERE name = 'Westwood';

 did | name
-----+----------
 108 | Westward
  </programlisting>
   </para>
  </refsect2>

  <refsect2 id="R2-SQL-SELECT-5">
   <refsect2info>
    <date>1998-09-24</date>
   </refsect2info>
   <title>
    <acronym>SQL92</acronym>
   </title>
   <para>
   </para>
   
   <refsect3 id="R3-SQL-SELECT-1">
    <refsect3info>
     <date>1998-04-15</date>
    </refsect3info>
    <title>
     SELECT Clause
    </title>
    <para>
     In the <acronym>SQL92</acronym> standard, the optional keyword "AS"
     is just noise and can be 
     omitted without affecting the meaning.
     The <productname>Postgres</productname> parser requires this keyword when
     renaming columns because the type extensibility features lead to
     parsing ambiguities
     in this context.</para>
     
    <para>
     The DISTINCT ON phrase is not part of <acronym>SQL92</acronym>.
     Nor are LIMIT and OFFSET.
    </para>
     
    <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>
   </refsect3>

   <refsect3 id="R3-SQL-UNION-1">
    <refsect3info>
     <date>1998-09-24</date>
    </refsect3info>
    <title>
     UNION Clause
    </title>
    <para>
     The <acronym>SQL92</acronym> syntax for UNION allows an
     additional CORRESPONDING BY clause:
     <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
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->