File: r4787.html

package info (click to toggle)
postgresql 6.3.2-15
  • links: PTS
  • area: main
  • in suites: slink
  • size: 21,136 kB
  • ctags: 15,441
  • sloc: ansic: 162,182; sh: 5,538; java: 5,143; yacc: 4,891; tcl: 4,778; sql: 4,120; makefile: 2,653; lex: 906; cpp: 839; python: 836; perl: 678; asm: 70; csh: 5; sed: 2
file content (866 lines) | stat: -rw-r--r-- 14,915 bytes parent folder | download
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
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.0 Transitional//EN">
<HTML
><HEAD
><TITLE
>   SELECT
  </TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet version 1.12"><LINK
REL="HOME"
TITLE="PostgreSQL Reference Manual"
HREF="book1.html"><LINK
REL="UP"
TITLE="Commands"
HREF="c25.html"><LINK
REL="PREVIOUS"
TITLE="ROLLBACK"
HREF="r4734.html"><LINK
REL="NEXT"
TITLE="SET"
HREF="r4994.html"></HEAD
><BODY
BGCOLOR="#FFFFFF"
TEXT="#000000"
><DIV
CLASS="NAVHEADER"
><TABLE
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="3"
ALIGN="center"
>PostgreSQL Reference Manual</TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="bottom"
><A
HREF="r4734.html"
>Prev</A
></TD
><TD
WIDTH="80%"
ALIGN="center"
VALIGN="bottom"
></TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="bottom"
><A
HREF="r4994.html"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><H1
>SELECT</H1
><DIV
CLASS="REFNAMEDIV"
><H2
>Name</H2
>   SELECT
   &#8212;    Retrieve rows from a table or view.
  </DIV
><DIV
CLASS="REFSYNOPSISDIV"
><PRE
CLASS="SYNOPSIS"
>SELECT [ALL|DISTINCT]
    <TT
CLASS="REPLACEABLE"
><I
>expression</I
></TT
> [AS <TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
>] [, ...]
    [INTO [TABLE] <TT
CLASS="REPLACEABLE"
><I
>intable</I
></TT
>]
    [FROM <TT
CLASS="REPLACEABLE"
><I
>table</I
></TT
> [<TT
CLASS="REPLACEABLE"
><I
>alias</I
></TT
>] [, ...] ]
    [WHERE <TT
CLASS="REPLACEABLE"
><I
>condition</I
></TT
>]
    [GROUP BY <TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
> [, ...] ]
    [HAVING <TT
CLASS="REPLACEABLE"
><I
>condition</I
></TT
> [, ...] ]
    [UNION [ALL] <TT
CLASS="REPLACEABLE"
><I
>select</I
></TT
>]
    [ORDER BY <TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
> [ASC | DESC] [, ...] ]
  </PRE
><DIV
CLASS="REFSECT2"
><H3
>    Inputs
   </H3
><P
>    <P
></P
><DL
><DT
><TT
CLASS="REPLACEABLE"
><I
>expression</I
></TT
></DT
><DD
><P
>	The name of a table's column or an expression.
       </P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
></DT
><DD
><P
>	Specifies another name for a column or an expression using
	the AS clause. <TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
>
	cannot be used in the WHERE
	condition. It can, however, be referenced in associated
	ORDER BY or GROUP BY clauses.
       </P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>intable</I
></TT
></DT
><DD
><P
>	If the INTO TABLE clause is specified, the result of the
	query will be stored in another table with the indicated
	name.
	If <TT
CLASS="REPLACEABLE"
><I
>intable</I
></TT
> does
	not exist, it will be created automatically.
	
	<BLOCKQUOTE
CLASS="NOTE"
><P
><B
>NOTE: </B
>	  The <B
CLASS="COMMAND"
>CREATE TABLE AS</B
> statement will also
	  create a new  table from a select query.
	 </P
></BLOCKQUOTE
>
       </P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>table</I
></TT
></DT
><DD
><P
>	The name of an existing table referenced by the FROM clause.
       </P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>alias</I
></TT
></DT
><DD
><P
>	An alternate name for the preceding
	<TT
CLASS="REPLACEABLE"
><I
>table</I
></TT
>.
	It is used for brevity or to eliminate ambiguity for joins
	within a single table.
       </P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>condition</I
></TT
></DT
><DD
><P
>	A boolean expression giving a result of true or false.
	See the WHERE clause.
       </P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
></DT
><DD
><P
>	The name of a table's column.
       </P
></DD
><DT
><TT
CLASS="REPLACEABLE"
><I
>select</I
></TT
></DT
><DD
><P
>	A select statement with all features except the ORDER BY clause.
       </P
></DD
></DL
>
   </P
></DIV
><DIV
CLASS="REFSECT2"
><H3
>    Outputs
   </H3
><P
></P
><DL
><DT
>Rows</DT
><DD
><P
>       The complete set of rows resulting from the query specification.
      </P
></DD
><DT
><SPAN
CLASS="RETURNVALUE"
>count</SPAN
></DT
><DD
><P
>       The count of rows returned by the query.
      </P
></DD
></DL
></DIV
></DIV
><DIV
CLASS="REFSECT1"
><H2
>   Description
  </H2
><P
>   SELECT will get all rows which satisfy the WHERE condition
   or all rows of a table if WHERE is omitted.</P
><P
>   The GROUP BY clause allows a user to divide a table
   conceptually into groups. (See GROUP BY clause).</P
><P
>   The HAVING clause specifies a grouped table derived by the
   elimination of groups from the result of the previously
   specified clause. (See HAVING clause).</P
><P
>   The ORDER BY clause allows a user to specify that he/she
   wishes the rows sorted according to the ASCending or 
   DESCending mode operator. (See ORDER BY clause)</P
><P
>   The UNION clause specifies a table derived from a Cartesian
   product union join. (See UNION clause).</P
><P
>   You must have SELECT privilege to a table to read its values
   (See GRANT/REVOKE statements).</P
><DIV
CLASS="REFSECT2"
><H3
>    WHERE clause
   </H3
><P
>    The optional WHERE condition has the general form:
    
    <PRE
CLASS="SYNOPSIS"
>WHERE <TT
CLASS="REPLACEABLE"
><I
>expr</I
></TT
> <TT
CLASS="REPLACEABLE"
><I
>cond_op</I
></TT
> <TT
CLASS="REPLACEABLE"
><I
>expr</I
></TT
> [<TT
CLASS="REPLACEABLE"
><I
>log_op</I
></TT
> ...]
    </PRE
>
    
    where <TT
CLASS="REPLACEABLE"
><I
>cond_op</I
></TT
> can be
    one of: =, &#60;, &#60;=, &#62;, &#62;=, &#60;&#62;
    or a conditional operator like ALL, ANY, IN, LIKE, et cetera
    and <TT
CLASS="REPLACEABLE"
><I
>log_op</I
></TT
> can be one 
    of: AND, OR, NOT.
    The comparison returns either TRUE or FALSE and all
    instances will be discarded
    if the expression evaluates to FALSE.
   </P
></DIV
><DIV
CLASS="REFSECT2"
><H3
>    GROUP BY clause
   </H3
><P
>    GROUP BY specifies a grouped table derived by the application
    of the this clause:
    <PRE
CLASS="SYNOPSIS"
>     GROUP BY <TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
> [, ...]
    </PRE
></P
></DIV
><DIV
CLASS="REFSECT2"
><H3
>    HAVING clause
   </H3
><P
>    The optional HAVING condition has the general form:
    
    <PRE
CLASS="SYNOPSIS"
>HAVING <TT
CLASS="REPLACEABLE"
><I
>cond_expr</I
></TT
>
    </PRE
>
    
    where <TT
CLASS="REPLACEABLE"
><I
>cond_expr</I
></TT
> is the same
    as specified for the WHERE clause.</P
><P
>    HAVING specifies a grouped table derived by the elimination
    of groups from the result of the previously specified clause
    that do not meet the <TT
CLASS="REPLACEABLE"
><I
>cond_expr</I
></TT
>.</P
><P
>    Each column referenced in <TT
CLASS="REPLACEABLE"
><I
>cond_expr</I
></TT
> shall unambiguously
    reference a grouping column.
   </P
></DIV
><DIV
CLASS="REFSECT2"
><H3
>    ORDER BY clause
   </H3
><P
>    <PRE
CLASS="SYNOPSIS"
>ORDER BY <TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
> [ASC | DESC] [, ...]
    </PRE
></P
><P
>    <TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
> can be either a column
    name or an ordinal number.</P
><P
>    The ordinal numbers refers to the ordinal (left-to-right) position
    of the 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 assign a name
    to a calculated column using the AS clause, e.g.:
    <PRE
CLASS="PROGRAMLISTING"
>     SELECT title, date_prod + 1 AS newlen FROM films ORDER BY newlen;
    </PRE
></P
><P
>    The columns in the ORDER BY must appear in the SELECT clause.
    Thus the following statement is illegal:
    <PRE
CLASS="PROGRAMLISTING"
>     SELECT name FROM distributors ORDER BY code;
    </PRE
></P
><P
>    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.</P
></DIV
><DIV
CLASS="REFSECT2"
><H3
>    UNION clause
   </H3
><P
>    <PRE
CLASS="SYNOPSIS"
><TT
CLASS="REPLACEABLE"
><I
>table_query</I
></TT
> UNION [ALL] <TT
CLASS="REPLACEABLE"
><I
>table_query</I
></TT
>
     [ORDER BY <TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
> [ASC | DESC] [, ...] ]
    </PRE
>
    
    where
    <TT
CLASS="REPLACEABLE"
><I
>table_query</I
></TT
>
    specifies any select expression without an ORDER BY clause.</P
><P
>    The UNION operator specifies a table derived from a Cartesian product.
    The two tables that represent the direct operands of the UNION must
    have the same number of columns, and corresponding columns must be
    of compatible data types.</P
><P
>    By default, the result of UNION does not contain any duplicate rows
    unless the ALL clause is specified.</P
><P
>    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.</P
></DIV
></DIV
><DIV
CLASS="REFSECT1"
><H2
>   Usage
  </H2
><P
>   To join the table <TT
CLASS="LITERAL"
>films</TT
> with the table
   <TT
CLASS="LITERAL"
>distributors</TT
>:
  </P
><PRE
CLASS="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
  </PRE
><P
>   To sum the column <TT
CLASS="LITERAL"
>len</TT
> of all films and group
   the reults by <TT
CLASS="LITERAL"
>kind</TT
>:
  </P
><PRE
CLASS="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
  </PRE
><P
>   To sum the column <TT
CLASS="LITERAL"
>len</TT
> of all films, group
   the reults by <TT
CLASS="LITERAL"
>kind</TT
> and show those group totals
   that are less than 5 hours:
  </P
><PRE
CLASS="PROGRAMLISTING"
>    SELECT kind, SUM(len) AS total
        FROM films
        GROUP BY kind
        HAVING SUM(len) &#60; INTERVAL '5 hour';

    kind      |total
    ----------+------
    Comedy    | 02:58
    Romantic  | 04:38
  </PRE
><P
>    The following two examples are identical ways of sorting the individual
   results according to the contents of the second column
   (<TT
CLASS="LITERAL"
>name</TT
>):
  </P
><PRE
CLASS="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
  </PRE
><P
>   This example shows how to obtain the union of the tables
   <TT
CLASS="LITERAL"
>distributors</TT
> and
   <TT
CLASS="LITERAL"
>actors</TT
>, restricting the results to those that begin
   with letter W in each table.  Only distinct rows are to be used, so the
   ALL keyword is omitted:
  </P
><PRE
CLASS="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
  </PRE
></DIV
><DIV
CLASS="REFSECT1"
><H2
>   Compatibility
  </H2
><P
>  </P
><DIV
CLASS="REFSECT2"
><H3
>    <SPAN
CLASS="ACRONYM"
>SQL92</SPAN
>
   </H3
><P
>   </P
><DIV
CLASS="REFSECT3"
><H4
>     SELECT clause
    </H4
><P
>     In the <SPAN
CLASS="ACRONYM"
>SQL92</SPAN
> standard, the optional keyword "AS"
     is just noise and can be 
     omitted without affecting the meaning.
     The <SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
> parser requires this keyword when
     renaming columns because the type extensibility features lead to
     parsing ambiguities
     in this context.</P
><P
>     In the <SPAN
CLASS="ACRONYM"
>SQL92</SPAN
> standard, the new column name 
     specified in an
     "AS" clause may be referenced in GROUP BY and HAVING clauses.
     This is not currently
     allowed in <SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
>.
    </P
></DIV
><DIV
CLASS="REFSECT3"
><H4
>     UNION clause
    </H4
><P
>     The <SPAN
CLASS="ACRONYM"
>SQL92</SPAN
> syntax for UNION allows an
     additional CORRESPONDING BY clause:
     <PRE
CLASS="SYNOPSIS"
> 
<TT
CLASS="REPLACEABLE"
><I
>table_query</I
></TT
> UNION [ALL]
    [CORRESPONDING [BY (<TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
> [,...])]]
    <TT
CLASS="REPLACEABLE"
><I
>table_query</I
></TT
>
     </PRE
></P
><P
>     The CORRESPONDING BY clause is not supported by
     <SPAN
CLASS="PRODUCTNAME"
>Postgres</SPAN
>.
    </P
></DIV
></DIV
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="r4734.html"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="book1.html"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="r4994.html"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>ROLLBACK</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="c25.html"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>SET</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>