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
|
<!-- $Header: /cvsroot/pgsql/doc/src/sgml/queries.sgml,v 1.18.2.1 2002/11/10 12:45:42 petere Exp $ -->
<chapter id="queries">
<title>Queries</title>
<para>
The previous chapters explained how to create tables, how to fill
them with data, and how to manipulate that data. Now we finally
discuss how to retrieve the data out of the database.
</para>
<sect1 id="queries-overview">
<title>Overview</title>
<para>
The process of retrieving or the command to retrieve data from a
database is called a <firstterm>query</firstterm>. In SQL the
<command>SELECT</command> command is used to specify queries. The
general syntax of the <command>SELECT</command> command is
<synopsis>
SELECT <replaceable>select_list</replaceable> FROM <replaceable>table_expression</replaceable> <optional><replaceable>sort_specification</replaceable></optional>
</synopsis>
The following sections describe the details of the select list, the
table expression, and the sort specification.
</para>
<para>
The simplest kind of query has the form
<programlisting>
SELECT * FROM table1;
</programlisting>
Assuming that there is a table called <literal>table1</literal>,
this command would retrieve all rows and all columns from
<literal>table1</literal>. (The method of retrieval depends on the
client application. For example, the
<application>psql</application> program will display an ASCII-art
table on the screen, while client libraries will offer functions to
retrieve individual rows and columns.) The select list
specification <literal>*</literal> means all columns that the table
expression happens to provide. A select list can also select a
subset of the available columns or make calculations using the
columns. For example, if
<literal>table1</literal> has columns named <literal>a</>,
<literal>b</>, and <literal>c</> (and perhaps others) you can make
the following query:
<programlisting>
SELECT a, b + c FROM table1;
</programlisting>
(assuming that <literal>b</> and <literal>c</> are of a numerical
data type).
See <xref linkend="queries-select-lists"> for more details.
</para>
<para>
<literal>FROM table1</literal> is a particularly simple kind of
table expression: it reads just one table. In general, table
expressions can be complex constructs of base tables, joins, and
subqueries. But you can also omit the table expression entirely and
use the <command>SELECT</command> command as a calculator:
<programlisting>
SELECT 3 * 4;
</programlisting>
This is more useful if the expressions in the select list return
varying results. For example, you could call a function this way:
<programlisting>
SELECT random();
</programlisting>
</para>
</sect1>
<sect1 id="queries-table-expressions">
<title>Table Expressions</title>
<para>
A <firstterm>table expression</firstterm> computes a table. The
table expression contains a <literal>FROM</> clause that is
optionally followed by <literal>WHERE</>, <literal>GROUP BY</>, and
<literal>HAVING</> clauses. Trivial table expressions simply refer
to a table on disk, a so-called base table, but more complex
expressions can be used to modify or combine base tables in various
ways.
</para>
<para>
The optional <literal>WHERE</>, <literal>GROUP BY</>, and
<literal>HAVING</> clauses in the table expression specify a
pipeline of successive transformations performed on the table
derived in the <literal>FROM</> clause. All these transformations
produce a virtual table that provides the rows that are passed to
the select list to compute the output rows of the query.
</para>
<sect2 id="queries-from">
<title>The FROM Clause</title>
<para>
The <literal>FROM</> clause derives a table from one or more other
tables given in a comma-separated table reference list.
<synopsis>
FROM <replaceable>table_reference</replaceable> <optional>, <replaceable>table_reference</replaceable> <optional>, ...</optional></optional>
</synopsis>
A table reference may be a table name (possibly schema-qualified),
or a derived table such as a subquery, a table join, or complex
combinations of these. If more than one table reference is listed
in the <literal>FROM</> clause they are cross-joined (see below)
to form the intermediate virtual table that may then be subject to
transformations by the <literal>WHERE</>, <literal>GROUP BY</>,
and <literal>HAVING</> clauses and is finally the result of the
overall table expression.
</para>
<para>
When a table reference names a table that is the supertable of a
table inheritance hierarchy, the table reference produces rows of
not only that table but all of its subtable successors, unless the
keyword <literal>ONLY</> precedes the table name. However, the
reference produces only the columns that appear in the named table
--- any columns added in subtables are ignored.
</para>
<sect3 id="queries-join">
<title>Joined Tables</title>
<indexterm zone="queries-join">
<primary>joins</primary>
</indexterm>
<para>
A joined table is a table derived from two other (real or
derived) tables according to the rules of the particular join
type. Inner, outer, and cross-joins are available.
</para>
<variablelist>
<title>Join Types</title>
<varlistentry>
<term>Cross join</term>
<indexterm>
<primary>joins</primary>
<secondary>cross</secondary>
</indexterm>
<listitem>
<synopsis>
<replaceable>T1</replaceable> CROSS JOIN <replaceable>T2</replaceable>
</synopsis>
<para>
For each combination of rows from
<replaceable>T1</replaceable> and
<replaceable>T2</replaceable>, the derived table will contain a
row consisting of all columns in <replaceable>T1</replaceable>
followed by all columns in <replaceable>T2</replaceable>. If
the tables have N and M rows respectively, the joined
table will have N * M rows. A cross join is equivalent to an
<literal>INNER JOIN ON TRUE</literal>.
</para>
<tip>
<para>
<literal>FROM <replaceable>T1</replaceable> CROSS JOIN
<replaceable>T2</replaceable></literal> is equivalent to
<literal>FROM <replaceable>T1</replaceable>,
<replaceable>T2</replaceable></literal>.
</para>
</tip>
</listitem>
</varlistentry>
<varlistentry>
<term>Qualified joins</term>
<indexterm>
<primary>joins</primary>
<secondary>outer</secondary>
</indexterm>
<listitem>
<synopsis>
<replaceable>T1</replaceable> { <optional>INNER</optional> | { LEFT | RIGHT | FULL } <optional>OUTER</optional> } JOIN <replaceable>T2</replaceable> ON <replaceable>boolean_expression</replaceable>
<replaceable>T1</replaceable> { <optional>INNER</optional> | { LEFT | RIGHT | FULL } <optional>OUTER</optional> } JOIN <replaceable>T2</replaceable> USING ( <replaceable>join column list</replaceable> )
<replaceable>T1</replaceable> NATURAL { <optional>INNER</optional> | { LEFT | RIGHT | FULL } <optional>OUTER</optional> } JOIN <replaceable>T2</replaceable>
</synopsis>
<para>
The words <literal>INNER</literal> and
<literal>OUTER</literal> are optional in all forms.
<literal>INNER</literal> is the default;
<literal>LEFT</literal>, <literal>RIGHT</literal>, and
<literal>FULL</literal> imply an outer join.
</para>
<para>
The <firstterm>join condition</firstterm> is specified in the
<literal>ON</> or <literal>USING</> clause, or implicitly by
the word <literal>NATURAL</>. The join condition determines
which rows from the two source tables are considered to
<quote>match</quote>, as explained in detail below.
</para>
<para>
The <literal>ON</> clause is the most general kind of join
condition: it takes a Boolean value expression of the same
kind as is used in a <literal>WHERE</> clause. A pair of rows
from <replaceable>T1</> and <replaceable>T2</> match if the
<literal>ON</> expression evaluates to true for them.
</para>
<para>
<literal>USING</> is a shorthand notation: it takes a
comma-separated list of column names, which the joined tables
must have in common, and forms a join condition specifying
equality of each of these pairs of columns. Furthermore, the
output of a <literal>JOIN USING</> has one column for each of
the equated pairs of input columns, followed by all of the
other columns from each table. Thus, <literal>USING (a, b,
c)</literal> is equivalent to <literal>ON (t1.a = t2.a AND
t1.b = t2.b AND t1.c = t2.c)</literal> with the exception that
if <literal>ON</> is used there will be two columns
<literal>a</>, <literal>b</>, and <literal>c</> in the result,
whereas with <literal>USING</> there will be only one of each.
</para>
<para>
<indexterm>
<primary>joins</primary>
<secondary>natural</secondary>
</indexterm>
Finally, <literal>NATURAL</> is a shorthand form of
<literal>USING</>: it forms a <literal>USING</> list
consisting of exactly those column names that appear in both
input tables. As with <literal>USING</>, these columns appear
only once in the output table.
</para>
<para>
The possible types of qualified join are:
</para>
<variablelist>
<varlistentry>
<term><literal>INNER JOIN</></term>
<listitem>
<para>
For each row R1 of T1, the joined table has a row for each
row in T2 that satisfies the join condition with R1.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>LEFT OUTER JOIN</></term>
<indexterm>
<primary>joins</primary>
<secondary>left</secondary>
</indexterm>
<listitem>
<para>
First, an inner join is performed. Then, for each row in
T1 that does not satisfy the join condition with any row in
T2, a joined row is added with null values in columns of
T2. Thus, the joined table unconditionally has at least
one row for each row in T1.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>RIGHT OUTER JOIN</></term>
<listitem>
<para>
First, an inner join is performed. Then, for each row in
T2 that does not satisfy the join condition with any row in
T1, a joined row is added with null values in columns of
T1. This is the converse of a left join: the result table
will unconditionally have a row for each row in T2.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>FULL OUTER JOIN</></term>
<listitem>
<para>
First, an inner join is performed. Then, for each row in
T1 that does not satisfy the join condition with any row in
T2, a joined row is added with null values in columns of
T2. Also, for each row of T2 that does not satisfy the
join condition with any row in T1, a joined row with null
values in the columns of T1 is added.
</para>
</listitem>
</varlistentry>
</variablelist>
</listitem>
</varlistentry>
</variablelist>
<para>
Joins of all types can be chained together or nested: either or
both of <replaceable>T1</replaceable> and
<replaceable>T2</replaceable> may be joined tables. Parentheses
may be used around <literal>JOIN</> clauses to control the join
order. In the absence of parentheses, <literal>JOIN</> clauses
nest left-to-right.
</para>
<para>
To put this together, assume we have tables <literal>t1</literal>
<programlisting>
num | name
-----+------
1 | a
2 | b
3 | c
</programlisting>
and <literal>t2</literal>
<programlisting>
num | value
-----+-------
1 | xxx
3 | yyy
5 | zzz
</programlisting>
then we get the following results for the various joins:
<screen>
<prompt>=></> <userinput>SELECT * FROM t1 CROSS JOIN t2;</>
num | name | num | value
-----+------+-----+-------
1 | a | 1 | xxx
1 | a | 3 | yyy
1 | a | 5 | zzz
2 | b | 1 | xxx
2 | b | 3 | yyy
2 | b | 5 | zzz
3 | c | 1 | xxx
3 | c | 3 | yyy
3 | c | 5 | zzz
(9 rows)
<prompt>=></> <userinput>SELECT * FROM t1 INNER JOIN t2 ON t1.num = t2.num;</>
num | name | num | value
-----+------+-----+-------
1 | a | 1 | xxx
3 | c | 3 | yyy
(2 rows)
<prompt>=></> <userinput>SELECT * FROM t1 INNER JOIN t2 USING (num);</>
num | name | value
-----+------+-------
1 | a | xxx
3 | c | yyy
(2 rows)
<prompt>=></> <userinput>SELECT * FROM t1 NATURAL INNER JOIN t2;</>
num | name | value
-----+------+-------
1 | a | xxx
3 | c | yyy
(2 rows)
<prompt>=></> <userinput>SELECT * FROM t1 LEFT JOIN t2 ON t1.num = t2.num;</>
num | name | num | value
-----+------+-----+-------
1 | a | 1 | xxx
2 | b | |
3 | c | 3 | yyy
(3 rows)
<prompt>=></> <userinput>SELECT * FROM t1 LEFT JOIN t2 USING (num);</>
num | name | value
-----+------+-------
1 | a | xxx
2 | b |
3 | c | yyy
(3 rows)
<prompt>=></> <userinput>SELECT * FROM t1 RIGHT JOIN t2 ON t1.num = t2.num;</>
num | name | num | value
-----+------+-----+-------
1 | a | 1 | xxx
3 | c | 3 | yyy
| | 5 | zzz
(3 rows)
<prompt>=></> <userinput>SELECT * FROM t1 FULL JOIN t2 ON t1.num = t2.num;</>
num | name | num | value
-----+------+-----+-------
1 | a | 1 | xxx
2 | b | |
3 | c | 3 | yyy
| | 5 | zzz
(4 rows)
</screen>
</para>
<para>
The join condition specified with <literal>ON</> can also contain
conditions that do not relate directly to the join. This can
prove useful for some queries but needs to be thought out
carefully. For example:
<screen>
<prompt>=></> <userinput>SELECT * FROM t1 LEFT JOIN t2 ON t1.num = t2.num AND t2.value = 'xxx';</>
num | name | num | value
-----+------+-----+-------
1 | a | 1 | xxx
2 | b | |
3 | c | |
(3 rows)
</screen>
</para>
</sect3>
<sect3 id="queries-table-aliases">
<title>Table and Column Aliases</title>
<indexterm zone="queries-table-aliases">
<primary>label</primary>
<secondary>table</secondary>
</indexterm>
<indexterm>
<primary>alias</primary>
<see>label</see>
</indexterm>
<para>
A temporary name can be given to tables and complex table
references to be used for references to the derived table in
further processing. This is called a <firstterm>table
alias</firstterm>.
</para>
<para>
To create a table alias, write
<synopsis>
FROM <replaceable>table_reference</replaceable> AS <replaceable>alias</replaceable>
</synopsis>
or
<synopsis>
FROM <replaceable>table_reference</replaceable> <replaceable>alias</replaceable>
</synopsis>
The <literal>AS</literal> key word is noise.
<replaceable>alias</replaceable> can be any identifier.
</para>
<para>
A typical application of table aliases is to assign short
identifiers to long table names to keep the join clauses
readable. For example:
<programlisting>
SELECT * FROM some_very_long_table_name s JOIN another_fairly_long_name a ON s.id = a.num;
</programlisting>
</para>
<para>
The alias becomes the new name of the table reference for the
current query -- it is no longer possible to refer to the table
by the original name. Thus
<programlisting>
SELECT * FROM my_table AS m WHERE my_table.a > 5;
</programlisting>
is not valid SQL syntax. What will actually happen (this is a
<productname>PostgreSQL</productname> extension to the standard)
is that an implicit table reference is added to the
<literal>FROM</literal> clause, so the query is processed as if
it were written as
<programlisting>
SELECT * FROM my_table AS m, my_table AS my_table WHERE my_table.a > 5;
</programlisting>
which will result in a cross join, which is usually not what you
want.
</para>
<para>
Table aliases are mainly for notational convenience, but it is
necessary to use them when joining a table to itself, e.g.,
<programlisting>
SELECT * FROM my_table AS a CROSS JOIN my_table AS b ...
</programlisting>
Additionally, an alias is required if the table reference is a
subquery (see <xref linkend="queries-subqueries">).
</para>
<para>
Parentheses are used to resolve ambiguities. The following
statement will assign the alias <literal>b</literal> to the
result of the join, unlike the previous example:
<programlisting>
SELECT * FROM (my_table AS a CROSS JOIN my_table) AS b ...
</programlisting>
</para>
<para>
Another form of table aliasing also gives temporary names to the columns of the table:
<synopsis>
FROM <replaceable>table_reference</replaceable> <optional>AS</optional> <replaceable>alias</replaceable> ( <replaceable>column1</replaceable> <optional>, <replaceable>column2</replaceable> <optional>, ...</optional></optional> )
</synopsis>
If fewer column aliases are specified than the actual table has
columns, the remaining columns are not renamed. This syntax is
especially useful for self-joins or subqueries.
</para>
<para>
When an alias is applied to the output of a <literal>JOIN</>
clause, using any of these forms, the alias hides the original
names within the <literal>JOIN</>. For example,
<programlisting>
SELECT a.* FROM my_table AS a JOIN your_table AS b ON ...
</programlisting>
is valid SQL, but
<programlisting>
SELECT a.* FROM (my_table AS a JOIN your_table AS b ON ...) AS c
</programlisting>
is not valid: the table alias <literal>a</> is not visible
outside the alias <literal>c</>.
</para>
</sect3>
<sect3 id="queries-subqueries">
<title>Subqueries</title>
<indexterm zone="queries-subqueries">
<primary>subqueries</primary>
</indexterm>
<para>
Subqueries specifying a derived table must be enclosed in
parentheses and <emphasis>must</emphasis> be assigned a table
alias name. (See <xref linkend="queries-table-aliases">.) For
example:
<programlisting>
FROM (SELECT * FROM table1) AS alias_name
</programlisting>
</para>
<para>
This example is equivalent to <literal>FROM table1 AS
alias_name</literal>. More interesting cases, which can't be
reduced to a plain join, arise when the subquery involves
grouping or aggregation.
</para>
</sect3>
</sect2>
<sect2 id="queries-where">
<title>The WHERE Clause</title>
<indexterm zone="queries-where">
<primary>where</primary>
</indexterm>
<para>
The syntax of the <literal>WHERE</> clause is
<synopsis>
WHERE <replaceable>search_condition</replaceable>
</synopsis>
where <replaceable>search_condition</replaceable> is any value
expression as defined in <xref linkend="sql-expressions"> that
returns a value of type <type>boolean</type>.
</para>
<para>
After the processing of the <literal>FROM</> clause is done, each
row of the derived virtual table is checked against the search
condition. If the result of the condition is true, the row is
kept in the output table, otherwise (that is, if the result is
false or null) it is discarded. The search condition typically
references at least some column in the table generated in the
<literal>FROM</> clause; this is not required, but otherwise the
<literal>WHERE</> clause will be fairly useless.
</para>
<note>
<para>
Before the implementation of the <literal>JOIN</> syntax, it was
necessary to put the join condition of an inner join in the
<literal>WHERE</> clause. For example, these table expressions
are equivalent:
<programlisting>
FROM a, b WHERE a.id = b.id AND b.val > 5
</programlisting>
and
<programlisting>
FROM a INNER JOIN b ON (a.id = b.id) WHERE b.val > 5
</programlisting>
or perhaps even
<programlisting>
FROM a NATURAL JOIN b WHERE b.val > 5
</programlisting>
Which one of these you use is mainly a matter of style. The
<literal>JOIN</> syntax in the <literal>FROM</> clause is
probably not as portable to other SQL database products. For
outer joins there is no choice in any case: they must be done in
the <literal>FROM</> clause. An <literal>ON</>/<literal>USING</>
clause of an outer join is <emphasis>not</> equivalent to a
<literal>WHERE</> condition, because it determines the addition
of rows (for unmatched input rows) as well as the removal of rows
from the final result.
</para>
</note>
<para>
Here are some examples of <literal>WHERE</literal> clauses:
<programlisting>
SELECT ... FROM fdt WHERE c1 > 5
SELECT ... FROM fdt WHERE c1 IN (1, 2, 3)
SELECT ... FROM fdt WHERE c1 IN (SELECT c1 FROM t2)
SELECT ... FROM fdt WHERE c1 IN (SELECT c3 FROM t2 WHERE c2 = fdt.c1 + 10)
SELECT ... FROM fdt WHERE c1 BETWEEN (SELECT c3 FROM t2 WHERE c2 = fdt.c1 + 10) AND 100
SELECT ... FROM fdt WHERE EXISTS (SELECT c1 FROM t2 WHERE c2 > fdt.c1)
</programlisting>
<literal>fdt</literal> is the table derived in the
<literal>FROM</> clause. Rows that do not meet the search
condition of the <literal>WHERE</> clause are eliminated from
<literal>fdt</literal>. Notice the use of scalar subqueries as
value expressions. Just like any other query, the subqueries can
employ complex table expressions. Notice how
<literal>fdt</literal> is referenced in the subqueries.
Qualifying <literal>c1</> as <literal>fdt.c1</> is only necessary
if <literal>c1</> is also the name of a column in the derived
input table of the subquery. Qualifying the column name adds
clarity even when it is not needed. This shows how the column
naming scope of an outer query extends into its inner queries.
</para>
</sect2>
<sect2 id="queries-group">
<title>The GROUP BY and HAVING Clauses</title>
<indexterm zone="queries-group">
<primary>group</primary>
</indexterm>
<para>
After passing the <literal>WHERE</> filter, the derived input
table may be subject to grouping, using the <literal>GROUP BY</>
clause, and elimination of group rows using the <literal>HAVING</>
clause.
</para>
<synopsis>
SELECT <replaceable>select_list</replaceable>
FROM ...
<optional>WHERE ...</optional>
GROUP BY <replaceable>grouping_column_reference</replaceable> <optional>, <replaceable>grouping_column_reference</replaceable></optional>...
</synopsis>
<para>
The <literal>GROUP BY</> clause is used to group together rows in
a table that share the same values in all the columns listed. The
order in which the columns are listed does not matter. The
purpose is to reduce each group of rows sharing common values into
one group row that is representative of all rows in the group.
This is done to eliminate redundancy in the output and/or compute
aggregates that apply to these groups. For instance:
<screen>
<prompt>=></> <userinput>SELECT * FROM test1;</>
x | y
---+---
a | 3
c | 2
b | 5
a | 1
(4 rows)
<prompt>=></> <userinput>SELECT x FROM test1 GROUP BY x;</>
x
---
a
b
c
(3 rows)
</screen>
</para>
<para>
In the second query, we could not have written <literal>SELECT *
FROM test1 GROUP BY x</literal>, because there is no single value
for the column <literal>y</> that could be associated with each
group. The grouped-by columns can be referenced in the select list since
they have a known constant value per group.
</para>
<para>
In general, if a table is grouped, columns that are not
used in the grouping cannot be referenced except in aggregate
expressions. An example with aggregate expressions is:
<screen>
<prompt>=></> <userinput>SELECT x, sum(y) FROM test1 GROUP BY x;</>
x | sum
---+-----
a | 4
b | 5
c | 2
(3 rows)
</screen>
Here <literal>sum()</literal> is an aggregate function that
computes a single value over the entire group. More information
about the available aggregate functions can be found in <xref
linkend="functions-aggregate">.
</para>
<tip>
<para>
Grouping without aggregate expressions effectively calculates the
set of distinct values in a column. This can also be achieved
using the <literal>DISTINCT</> clause (see <xref
linkend="queries-distinct">).
</para>
</tip>
<para>
Here is another example: <function>sum(sales)</function> on a
table grouped by product code gives the total sales for each
product, not the total sales on all products.
<programlisting>
SELECT product_id, p.name, (sum(s.units) * p.price) AS sales
FROM products p LEFT JOIN sales s USING (product_id)
GROUP BY product_id, p.name, p.price;
</programlisting>
In this example, the columns <literal>product_id</literal>,
<literal>p.name</literal>, and <literal>p.price</literal> must be
in the <literal>GROUP BY</> clause since they are referenced in
the query select list. (Depending on how exactly the products
table is set up, name and price may be fully dependent on the
product ID, so the additional groupings could theoretically be
unnecessary, but this is not implemented yet.) The column
<literal>s.units</> does not have to be in the <literal>GROUP
BY</> list since it is only used in an aggregate expression
(<function>sum()</function>), which represents the group of sales
of a product. For each product, a summary row is returned about
all sales of the product.
</para>
<para>
In strict SQL, <literal>GROUP BY</> can only group by columns of
the source table but <productname>PostgreSQL</productname> extends
this to also allow <literal>GROUP BY</> to group by columns in the
select list. Grouping by value expressions instead of simple
column names is also allowed.
</para>
<para>
If a table has been grouped using a <literal>GROUP BY</literal>
clause, but then only certain groups are of interest, the
<literal>HAVING</literal> clause can be used, much like a
<literal>WHERE</> clause, to eliminate groups from a grouped
table. The syntax is:
<synopsis>
SELECT <replaceable>select_list</replaceable> FROM ... <optional>WHERE ...</optional> GROUP BY ... HAVING <replaceable>boolean_expression</replaceable>
</synopsis>
Expressions in the <literal>HAVING</> clause can refer both to
grouped expressions and to ungrouped expressions (which necessarily
involve an aggregate function).
</para>
<para>
Example:
<screen>
<prompt>=></> <userinput>SELECT x, sum(y) FROM test1 GROUP BY x HAVING sum(y) > 3;</>
x | sum
---+-----
a | 4
b | 5
(2 rows)
<prompt>=></> <userinput>SELECT x, sum(y) FROM test1 GROUP BY x HAVING x < 'c';</>
x | sum
---+-----
a | 4
b | 5
(2 rows)
</screen>
</para>
<para>
Again, a more realistic example:
<programlisting>
SELECT product_id, p.name, (sum(s.units) * (p.price - p.cost)) AS profit
FROM products p LEFT JOIN sales s USING (product_id)
WHERE s.date > CURRENT_DATE - INTERVAL '4 weeks'
GROUP BY product_id, p.name, p.price, p.cost
HAVING sum(p.price * s.units) > 5000;
</programlisting>
In the example above, the <literal>WHERE</> clause is selecting
rows by a column that is not grouped, while the <literal>HAVING</>
clause restricts the output to groups with total gross sales over
5000. Note that the aggregate expressions do not necessarily need
to be the same everywhere.
</para>
</sect2>
</sect1>
<sect1 id="queries-select-lists">
<title>Select Lists</title>
<indexterm>
<primary>select</primary>
<secondary>select list</secondary>
</indexterm>
<para>
As shown in the previous section,
the table expression in the <command>SELECT</command> command
constructs an intermediate virtual table by possibly combining
tables, views, eliminating rows, grouping, etc. This table is
finally passed on to processing by the <firstterm>select list</firstterm>. The select
list determines which <emphasis>columns</emphasis> of the
intermediate table are actually output.
</para>
<sect2 id="queries-select-list-items">
<title>Select-List Items</title>
<para>
The simplest kind of select list is <literal>*</literal> which
emits all columns that the table expression produces. Otherwise,
a select list is a comma-separated list of value expressions (as
defined in <xref linkend="sql-expressions">). For instance, it
could be a list of column names:
<programlisting>
SELECT a, b, c FROM ...
</programlisting>
The columns names <literal>a</>, <literal>b</>, and <literal>c</>
are either the actual names of the columns of tables referenced
in the <literal>FROM</> clause, or the aliases given to them as
explained in <xref linkend="queries-table-aliases">. The name
space available in the select list is the same as in the
<literal>WHERE</> clause, unless grouping is used, in which case
it is the same as in the <literal>HAVING</> clause.
</para>
<para>
If more than one table has a column of the same name, the table
name must also be given, as in
<programlisting>
SELECT tbl1.a, tbl2.b, tbl1.c FROM ...
</programlisting>
(See also <xref linkend="queries-where">.)
</para>
<para>
If an arbitrary value expression is used in the select list, it
conceptually adds a new virtual column to the returned table. The
value expression is evaluated once for each retrieved row, with
the row's values substituted for any column references. But the
expressions in the select list do not have to reference any
columns in the table expression of the <literal>FROM</> clause;
they could be constant arithmetic expressions as well, for
instance.
</para>
</sect2>
<sect2 id="queries-column-labels">
<title>Column Labels</title>
<indexterm zone="queries-column-labels">
<primary>label</primary>
<secondary>column</secondary>
</indexterm>
<para>
The entries in the select list can be assigned names for further
processing. The <quote>further processing</quote> in this case is
an optional sort specification and the client application (e.g.,
column headers for display). For example:
<programlisting>
SELECT a AS value, b + c AS sum FROM ...
</programlisting>
</para>
<para>
If no output column name is specified via AS, the system assigns a
default name. For simple column references, this is the name of the
referenced column. For function
calls, this is the name of the function. For complex expressions,
the system will generate a generic name.
</para>
<note>
<para>
The naming of output columns here is different from that done in
the <literal>FROM</> clause (see <xref
linkend="queries-table-aliases">). This pipeline will in fact
allow you to rename the same column twice, but the name chosen in
the select list is the one that will be passed on.
</para>
</note>
</sect2>
<sect2 id="queries-distinct">
<title>DISTINCT</title>
<indexterm zone="queries-distinct">
<primary>distinct</primary>
</indexterm>
<para>
After the select list has been processed, the result table may
optionally be subject to the elimination of duplicates. The
<literal>DISTINCT</literal> key word is written directly after the
<literal>SELECT</literal> to enable this:
<synopsis>
SELECT DISTINCT <replaceable>select_list</replaceable> ...
</synopsis>
(Instead of <literal>DISTINCT</> the word <literal>ALL</literal>
can be used to select the default behavior of retaining all rows.)
</para>
<para>
Obviously, two rows are considered distinct if they differ in at
least one column value. Null values are considered equal in this
comparison.
</para>
<para>
Alternatively, an arbitrary expression can determine what rows are
to be considered distinct:
<synopsis>
SELECT DISTINCT ON (<replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> ...</optional>) <replaceable>select_list</replaceable> ...
</synopsis>
Here <replaceable>expression</replaceable> is an arbitrary value
expression that is evaluated for all rows. A set of rows for
which all the expressions are equal are considered duplicates, and
only the first row of the set is kept in the output. Note that
the <quote>first row</quote> of a set is unpredictable unless the
query is sorted on enough columns to guarantee a unique ordering
of the rows arriving at the <literal>DISTINCT</> filter.
(<literal>DISTINCT ON</> processing occurs after <literal>ORDER
BY</> sorting.)
</para>
<para>
The <literal>DISTINCT ON</> clause is not part of the SQL standard
and is sometimes considered bad style because of the potentially
indeterminate nature of its results. With judicious use of
<literal>GROUP BY</> and subselects in <literal>FROM</> the
construct can be avoided, but it is often the most convenient
alternative.
</para>
</sect2>
</sect1>
<sect1 id="queries-union">
<title>Combining Queries</title>
<indexterm zone="queries-union">
<primary>union</primary>
</indexterm>
<indexterm zone="queries-union">
<primary>intersection</primary>
</indexterm>
<indexterm zone="queries-union">
<primary>except</primary>
</indexterm>
<para>
The results of two queries can be combined using the set operations
union, intersection, and difference. The syntax is
<synopsis>
<replaceable>query1</replaceable> UNION <optional>ALL</optional> <replaceable>query2</replaceable>
<replaceable>query1</replaceable> INTERSECT <optional>ALL</optional> <replaceable>query2</replaceable>
<replaceable>query1</replaceable> EXCEPT <optional>ALL</optional> <replaceable>query2</replaceable>
</synopsis>
<replaceable>query1</replaceable> and
<replaceable>query2</replaceable> are queries that can use any of
the features discussed up to this point. Set operations can also
be nested and chained, for example
<synopsis>
<replaceable>query1</replaceable> UNION <replaceable>query2</replaceable> UNION <replaceable>query3</replaceable>
</synopsis>
which really says
<synopsis>
(<replaceable>query1</replaceable> UNION <replaceable>query2</replaceable>) UNION <replaceable>query3</replaceable>
</synopsis>
</para>
<para>
<literal>UNION</> effectively appends the result of
<replaceable>query2</replaceable> to the result of
<replaceable>query1</replaceable> (although there is no guarantee
that this is the order in which the rows are actually returned).
Furthermore, it eliminates all duplicate rows, in the sense of
<literal>DISTINCT</>, unless <literal>UNION ALL</> is used.
</para>
<para>
<literal>INTERSECT</> returns all rows that are both in the result
of <replaceable>query1</replaceable> and in the result of
<replaceable>query2</replaceable>. Duplicate rows are eliminated
unless <literal>INTERSECT ALL</> is used.
</para>
<para>
<literal>EXCEPT</> returns all rows that are in the result of
<replaceable>query1</replaceable> but not in the result of
<replaceable>query2</replaceable>. (This is sometimes called the
<firstterm>difference</> between two queries.) Again, duplicates
are eliminated unless <literal>EXCEPT ALL</> is used.
</para>
<para>
In order to calculate the union, intersection, or difference of two
queries, the two queries must be <quote>union compatible</quote>,
which means that they both return the same number of columns, and
that the corresponding columns have compatible data types, as
described in <xref linkend="typeconv-union-case">.
</para>
</sect1>
<sect1 id="queries-order">
<title>Sorting Rows</title>
<indexterm zone="queries-order">
<primary>sorting</primary>
<secondary>query results</secondary>
</indexterm>
<para>
After a query has produced an output table (after the select list
has been processed) it can optionally be sorted. If sorting is not
chosen, the rows will be returned in random order. The actual
order in that case will depend on the scan and join plan types and
the order on disk, but it must not be relied on. A particular
output ordering can only be guaranteed if the sort step is explicitly
chosen.
</para>
<para>
The <literal>ORDER BY</> clause specifies the sort order:
<synopsis>
SELECT <replaceable>select_list</replaceable>
FROM <replaceable>table_expression</replaceable>
ORDER BY <replaceable>column1</replaceable> <optional>ASC | DESC</optional> <optional>, <replaceable>column2</replaceable> <optional>ASC | DESC</optional> ...</optional>
</synopsis>
<replaceable>column1</replaceable>, etc., refer to select list
columns. These can be either the output name of a column (see
<xref linkend="queries-column-labels">) or the number of a column. Some
examples:
<programlisting>
SELECT a, b FROM table1 ORDER BY a;
SELECT a + b AS sum, c FROM table1 ORDER BY sum;
SELECT a, sum(b) FROM table1 GROUP BY a ORDER BY 1;
</programlisting>
</para>
<para>
As an extension to the SQL standard, <productname>PostgreSQL</productname> also allows ordering
by arbitrary expressions:
<programlisting>
SELECT a, b FROM table1 ORDER BY a + b;
</programlisting>
References to column names in the <literal>FROM</> clause that are
renamed in the select list are also allowed:
<programlisting>
SELECT a AS b FROM table1 ORDER BY a;
</programlisting>
But these extensions do not work in queries involving
<literal>UNION</>, <literal>INTERSECT</>, or <literal>EXCEPT</>,
and are not portable to other SQL databases.
</para>
<para>
Each column specification may be followed by an optional
<literal>ASC</> or <literal>DESC</> to set the sort direction to
ascending or descending. <literal>ASC</> order is the default.
Ascending order puts smaller values first, where
<quote>smaller</quote> is defined in terms of the
<literal><</literal> operator. Similarly, descending order is
determined with the <literal>></literal> operator.
</para>
<para>
If more than one sort column is specified, the later entries are
used to sort rows that are equal under the order imposed by the
earlier sort columns.
</para>
</sect1>
<sect1 id="queries-limit">
<title>LIMIT and OFFSET</title>
<indexterm zone="queries-limit">
<primary>limit</primary>
</indexterm>
<indexterm zone="queries-limit">
<primary>offset</primary>
<secondary>with query results</secondary>
</indexterm>
<para>
<literal>LIMIT</> and <literal>OFFSET</> allow you to retrieve just
a portion of the rows that are generated by the rest of the query:
<synopsis>
SELECT <replaceable>select_list</replaceable>
FROM <replaceable>table_expression</replaceable>
<optional>LIMIT { <replaceable>number</replaceable> | ALL }</optional> <optional>OFFSET <replaceable>number</replaceable></optional>
</synopsis>
</para>
<para>
If a limit count is given, no more than that many rows will be
returned (but possibly less, if the query itself yields less rows).
<literal>LIMIT ALL</> is the same as omitting the <literal>LIMIT</>
clause.
</para>
<para>
<literal>OFFSET</> says to skip that many rows before beginning to
return rows to the client. <literal>OFFSET 0</> is the same as
omitting the <literal>OFFSET</> clause. If both <literal>OFFSET</>
and <literal>LIMIT</> appear, then <literal>OFFSET</> rows are
skipped before starting to count the <literal>LIMIT</> rows that
are returned.
</para>
<para>
When using <literal>LIMIT</>, it is a good idea to use an
<literal>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? The
ordering is unknown, unless you specified <literal>ORDER BY</>.
</para>
<para>
The query optimizer takes <literal>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 <literal>LIMIT</> and <literal>OFFSET</>. Thus, using
different <literal>LIMIT</>/<literal>OFFSET</> values to select
different subsets of a query result <emphasis>will give
inconsistent results</emphasis> unless you enforce a predictable
result ordering with <literal>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
<literal>ORDER BY</> is used to constrain the order.
</para>
</sect1>
</chapter>
|