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
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
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
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
|
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/select.sgml,v 1.63 2002/10/24 21:19:15 tgl Exp $
PostgreSQL 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>2000-12-11</date>
</refsynopsisdivinfo>
<synopsis>
SELECT [ ALL | DISTINCT [ ON ( <replaceable class="PARAMETER">expression</replaceable> [, ...] ) ] ]
* | <replaceable class="PARAMETER">expression</replaceable> [ AS <replaceable class="PARAMETER">output_name</replaceable> ] [, ...]
[ FROM <replaceable class="PARAMETER">from_item</replaceable> [, ...] ]
[ WHERE <replaceable class="PARAMETER">condition</replaceable> ]
[ GROUP BY <replaceable class="PARAMETER">expression</replaceable> [, ...] ]
[ HAVING <replaceable class="PARAMETER">condition</replaceable> [, ...] ]
[ { UNION | INTERSECT | EXCEPT } [ ALL ] <replaceable class="PARAMETER">select</replaceable> ]
[ ORDER BY <replaceable class="PARAMETER">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...] ]
[ LIMIT { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
[ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
[ FOR UPDATE [ OF <replaceable class="PARAMETER">tablename</replaceable> [, ...] ] ]
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">table_function_name</replaceable> ( [ <replaceable class="parameter">argument</replaceable> [, ...] ] )
[ AS ] <replaceable class="PARAMETER">alias</replaceable> [ ( <replaceable class="PARAMETER">column_alias_list</replaceable> | <replaceable class="PARAMETER">column_definition_list</replaceable> ) ]
|
<replaceable class="PARAMETER">table_function_name</replaceable> ( [ <replaceable class="parameter">argument</replaceable> [, ...] ] )
AS ( <replaceable class="PARAMETER">column_definition_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> ) ]
</synopsis>
<refsect2 id="R2-SQL-SELECT-1">
<refsect2info>
<date>2000-12-11</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">output_name</replaceable></term>
<listitem>
<para>
Specifies another name for an output column 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">output_name</replaceable>
cannot be used in the WHERE or HAVING clauses; write out the
expression instead.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">from_item</replaceable></term>
<listitem>
<para>
A table reference, sub-SELECT, table function, or JOIN clause. See below for details.
</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 and HAVING clause descriptions below.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">select</replaceable></term>
<listitem>
<para>
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).
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
<para>
FROM items can contain:
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">table_name</replaceable></term>
<listitem>
<para>
The name (optionally schema-qualified) of an existing table or view.
If <literal>ONLY</> is specified, only that table is scanned. If
<literal>ONLY</> is not specified, the table and all its descendant
tables (if any) are scanned. <literal>*</> can be appended to the
table name to indicate that descendant tables are to be scanned, but
in the current version, this is the default behavior. (In releases
before 7.1, <literal>ONLY</> was the default behavior.) The
default behavior can be modified by changing the
<option>SQL_INHERITANCE</option> configuration option.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">alias</replaceable></term>
<listitem>
<para>
A substitute name for the FROM item containing the alias.
An alias is used for brevity or to eliminate ambiguity for self-joins
(where the same table is scanned multiple times). When an alias
is provided, it completely hides the actual name of the table or
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
written, a column alias list can also be written to provide
substitute names for one or more columns of the table.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">select</replaceable></term>
<listitem>
<para>
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">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
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.
</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.
</para>
</listitem>
</varlistentry>
<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>
</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-12-11</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>
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.
</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 <quote>first row</quote> 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" endterm="sql-orderby-title">.)
</para>
<para>
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
returned by the queries involved.
Duplicate rows are eliminated unless ALL is specified.
(See <xref linkend="sql-union" endterm="sql-union-title">.)
</para>
<para>
The INTERSECT operator computes the rows that are common to both queries.
Duplicate rows are eliminated unless ALL is specified.
(See <xref linkend="sql-intersect" endterm="sql-intersect-title">.)
</para>
<para>
The EXCEPT operator computes the rows returned by the first query but
not the second query.
Duplicate rows are eliminated unless ALL is specified.
(See <xref linkend="sql-except" endterm="sql-except-title">.)
</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>
The FOR UPDATE clause causes the SELECT statement to lock the selected
rows against concurrent updates.
</para>
<para>
You must have SELECT privilege to a table to read its values
(See the <command>GRANT</command>/<command>REVOKE</command> statements).
Use of FOR UPDATE requires UPDATE privilege as well.
</para>
<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
from sub-tables (inheritance children) of the table.
<command>ONLY</command> will
suppress rows from sub-tables of the table. Before
<Productname>PostgreSQL</Productname> 7.1,
this was the default result, and adding sub-tables was done
by appending <command>*</command> to the table name.
This old behavior 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>
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.
</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
(i.e., all combined rows that pass its ON condition), plus one copy of each
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 null values for the right-hand columns.
Note that only the <literal>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>
<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: =, <, <=, >, >= or <>,
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">expression</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>
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
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">boolean_expr</replaceable>
</synopsis>
where <replaceable class="PARAMETER">boolean_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">boolean_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">boolean_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">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...]
</synopsis></para>
<para>
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.
</para>
<para>
The ordinal number refers to the ordinal (left-to-right) position
of the result column. This feature makes it possible to define an ordering
on the basis of a column that does not have a unique name.
This is never absolutely necessary because it is always possible
to assign a name to a result column using the 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>
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>
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 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 <</> and <literal>DESC</> is equivalent to
<literal>USING ></>.
</para>
<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>
<para>
Data of character types is sorted according to the locale-specific
collation order that was established when the database cluster
was initialized.
</para>
</refsect2>
<refsect2 id="SQL-UNION">
<refsect2info>
<date>2000-12-11</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">expression</replaceable> [ ASC | DESC | USING <replaceable class="PARAMETER">operator</replaceable> ] [, ...] ]
[ LIMIT { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
[ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
</synopsis>
where
<replaceable class="PARAMETER">table_query</replaceable>
specifies any select expression without an ORDER BY, LIMIT, or FOR UPDATE
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.)
</para>
<para>
The UNION operator computes the collection (set union) of the rows
returned by the queries involved.
The two SELECT 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.
</para>
<para>
The result of UNION does not contain any duplicate rows
unless the ALL option is specified. ALL prevents elimination of
duplicates.
</para>
<para>
Multiple UNION operators in the same SELECT statement are
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.
</para>
</refsect2>
<refsect2 id="SQL-INTERSECT">
<refsect2info>
<date>2000-12-11</date>
</refsect2info>
<title id="sql-intersect-title">
INTERSECT Clause
</title>
<para>
<synopsis>
<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> ] [, ...] ]
[ LIMIT { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
[ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
</synopsis>
where
<replaceable class="PARAMETER">table_query</replaceable>
specifies any select expression without an ORDER BY, LIMIT, or
FOR UPDATE clause.
</para>
<para>
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.
</para>
<para>
Multiple INTERSECT operators in the same SELECT statement are
evaluated left to right, unless parentheses dictate otherwise.
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.
</para>
</refsect2>
<refsect2 id="SQL-EXCEPT">
<refsect2info>
<date>2000-12-11</date>
</refsect2info>
<title id="sql-except-title">
EXCEPT Clause
</title>
<para>
<synopsis>
<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> ] [, ...] ]
[ LIMIT { <replaceable class="PARAMETER">count</replaceable> | ALL } ]
[ OFFSET <replaceable class="PARAMETER">start</replaceable> ]
</synopsis>
where
<replaceable class="PARAMETER">table_query</replaceable>
specifies any select expression without an ORDER BY, LIMIT,
or FOR UPDATE clause.
</para>
<para>
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.
</para>
<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>
<para>
Multiple EXCEPT operators in the same SELECT statement are
evaluated left to right, unless parentheses dictate otherwise.
EXCEPT binds at the same level as UNION.
</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>
</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 specify ORDER BY.
</para>
<para>
As of <productname>PostgreSQL</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 use 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>
<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>
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 UPDATE, DELETE, or SELECT FOR UPDATE of these
rows will be blocked until the current transaction ends. Also, if an
UPDATE, DELETE, or SELECT FOR UPDATE from another transaction has already
locked a selected row or rows, SELECT FOR UPDATE will wait for the other
transaction to complete, and will then lock and return the updated row
(or no row, if the row was deleted). For further discussion see the
concurrency chapter of the <citetitle>User's Guide</citetitle>.
</para>
<para>
If specific tables are named in FOR UPDATE, then only rows coming from
those tables are locked; any other tables used in the SELECT are simply
read as usual.
</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
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.
</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>
<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)
</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>Extensions</title>
<para>
<productname>PostgreSQL</productname> allows one to omit
the <command>FROM</command> clause from a query. This feature
was retained from the original PostQUEL query language. It has
a straightforward use to compute the results of simple expressions:
<programlisting>
SELECT 2+2;
?column?
----------
4
</programlisting>
Some other SQL 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:
<programlisting>
SELECT distributors.* WHERE distributors.name = 'Westward';
did | name
-----+----------
108 | Westward
</programlisting>
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>PostgreSQL</Productname> 7.1
and later will warn if the implicit-FROM feature is used in a query that also
contains an explicit FROM clause.
</para>
<para>
The table-function feature is a <productname>PostgreSQL</productname>
extension.
</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 <literal>AS</>
is just noise and can be
omitted without affecting the meaning.
The <productname>PostgreSQL</productname> parser requires this keyword when
renaming output columns because the type extensibility features lead to
parsing ambiguities
in this context. <literal>AS</literal> is optional in FROM items, however.</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>PostgreSQL</productname> extends each of these clauses to
allow the other choice as well (but it uses the standard's interpretation
if there is ambiguity).
<productname>PostgreSQL</productname> also allows both clauses to specify
arbitrary expressions. Note that names appearing in an expression will
always be taken as input-column names, not as result-column names.
</para>
</refsect3>
<refsect3 id="R3-SQL-UNION-1">
<refsect3info>
<date>1998-09-24</date>
</refsect3info>
<title>
UNION/INTERSECT/EXCEPT Clause
</title>
<para>
The <acronym>SQL92</acronym> syntax for UNION/INTERSECT/EXCEPT allows an
additional CORRESPONDING BY option:
<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>PostgreSQL</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:
-->
|