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
<REFENTRY ID="SQL-SELECT-1">
<REFMETA>
<REFENTRYTITLE>
SELECT
</REFENTRYTITLE>
<REFMISCINFO>SQL - Language Statements</REFMISCINFO>
</REFMETA>
<REFNAMEDIV>
<REFNAME>
SELECT
</REFNAME>
<REFPURPOSE>
Retrieve rows from a table or view
</REFPURPOSE>
<REFSYNOPSISDIV>
<REFSYNOPSISDIVINFO>
<DATE>1998-04-15</DATE>
</REFSYNOPSISDIVINFO>
<SYNOPSIS>
<REPLACEABLE CLASS="PARAMETER">
</REPLACEABLE>
SELECT [ALL|DISTINCT]
<REPLACEABLE CLASS="PARAMETER">expression</REPLACEABLE> [AS <REPLACEABLE CLASS="PARAMETER">name</REPLACEABLE>] [, ...]
[INTO [TABLE] <REPLACEABLE CLASS="PARAMETER">intable</REPLACEABLE>]
[FROM <REPLACEABLE CLASS="PARAMETER">table</REPLACEABLE> [<REPLACEABLE CLASS="PARAMETER">alias</REPLACEABLE>] [, ...] ]
[WHERE <REPLACEABLE CLASS="PARAMETER">condition</REPLACEABLE>]
[GROUP BY <REPLACEABLE CLASS="PARAMETER">column</REPLACEABLE> [, ...] ]
[HAVING <REPLACEABLE CLASS="PARAMETER">condition</REPLACEABLE> [, ...] ]
[UNION [ALL] <REPLACEABLE CLASS="PARAMETER">select</REPLACEABLE>]
[ORDER BY <REPLACEABLE CLASS="PARAMETER">column</REPLACEABLE> [ASC | DESC] [, ...] ]
</SYNOPSIS>
<REFSECT2 ID="R2-SQL-SELECT-1">
<REFSECT2INFO>
<DATE>1998-04-15</DATE>
</REFSECT2INFO>
<TITLE>
Inputs
</TITLE>
<PARA>
<VARIABLELIST>
<VARLISTENTRY>
<TERM>
<REPLACEABLE CLASS="PARAMETER">expression</REPLACEABLE>
</TERM>
<LISTITEM>
<PARA>
The name of a table's column or an expression.
</PARA>
</LISTITEM>
</VARLISTENTRY>
<VARLISTENTRY>
<TERM>
<REPLACEABLE CLASS="PARAMETER">name</REPLACEABLE>
</TERM>
<LISTITEM>
<PARA>
Specifies another name for a column or an expression using
the AS clause. <REPLACEABLE CLASS="PARAMETER">name</REPLACEABLE> cannot be used in the WHERE
condition. It can, however, be referenced in associated
ORDER BY or GROUP BY clauses.
</PARA>
</LISTITEM>
</VARLISTENTRY>
<VARLISTENTRY>
<TERM>
<REPLACEABLE CLASS="PARAMETER">intable</REPLACEABLE>
</TERM>
<LISTITEM>
<PARA>
If the INTO TABLE clause is specified, the result of the
query will be stored in another table with the indicated
name.
If <REPLACEABLE CLASS="PARAMETER">intable</REPLACEABLE> does not exist, it will be created automatically.
<Note>
<Para>
The CREATE TABLE AS statement will also create a new table from a select query.
</Para>
</Note>
</PARA>
</LISTITEM>
</VARLISTENTRY>
<VARLISTENTRY>
<TERM>
<REPLACEABLE CLASS="PARAMETER">table</REPLACEABLE>
</TERM>
<LISTITEM>
<PARA>
The name of an existing table referenced by FROM clause.
</PARA>
</LISTITEM>
</VARLISTENTRY>
<VARLISTENTRY>
<TERM>
<REPLACEABLE CLASS="PARAMETER">alias</REPLACEABLE>
</TERM>
<LISTITEM>
<PARA>
An alternate name for the preceeding <REPLACEABLE CLASS="PARAMETER">table</REPLACEABLE>.
Used for brevity or to eliminate ambiguity for joins within a single table.
</PARA>
</LISTITEM>
</VARLISTENTRY>
<VARLISTENTRY>
<TERM>
<REPLACEABLE CLASS="PARAMETER">condition</REPLACEABLE>
</TERM>
<LISTITEM>
<PARA>
An expression leading to a boolean (true/false) result.
See the WHERE clause.
</PARA>
</LISTITEM>
</VARLISTENTRY>
<VARLISTENTRY>
<TERM>
<REPLACEABLE CLASS="PARAMETER">column</REPLACEABLE>
</TERM>
<LISTITEM>
<PARA>
The name of a table's column.
</PARA>
</LISTITEM>
</VARLISTENTRY>
<VARLISTENTRY>
<TERM>
<REPLACEABLE CLASS="PARAMETER">select</REPLACEABLE>
</TERM>
<LISTITEM>
<PARA>
A select statement with all features except the ORDER BY clause.
</PARA>
</LISTITEM>
</VARLISTENTRY>
</VARIABLELIST>
</PARA>
</REFSECT2>
<REFSECT2 ID="R2-SQL-SELECT-2">
<REFSECT2INFO>
<DATE>1998-04-15</DATE>
</REFSECT2INFO>
<TITLE>
Outputs
</TITLE>
<VARIABLELIST>
<VARLISTENTRY>
<TERM>
Rows
</TERM>
<LISTITEM>
<PARA>
The complete set of rows resulting from the query specification.
</PARA>
</LISTITEM>
</VARLISTENTRY>
<VARLISTENTRY>
<TERM>
<ReturnValue>count</ReturnValue>
</TERM>
<LISTITEM>
<PARA>
The count of rows returned by the query.
</PARA>
</LISTITEM>
</VARLISTENTRY>
</VARIABLELIST>
</REFSECT2>
</REFSYNOPSISDIV>
<REFSECT1 ID="R1-SQL-SELECT-1">
<REFSECT1INFO>
<DATE>1998-04-15</DATE>
</REFSECT1INFO>
<TITLE>
Description
</TITLE>
<PARA>
SELECT is the principal means to access information
in <productname>Postgres</productname>.
SELECT will get all rows which satisfy the WHERE condition
or all rows of a table if WHERE is omitted.
<PARA>
The GROUP BY clause allows a user to divide a table
conceptually into groups. (See GROUP BY clause).
The HAVING clause specifies a grouped table derived by the
elimination of groups from the result of the previously
specified clause. (See HAVING clause).
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)
The UNION clause specifies a table derived from a Cartesian
product union join. (See UNION clause).
<PARA>
You must have SELECT privilege to a table to read its values
(See GRANT/REVOKE statements).
<REFSECT2 ID="R2-SQL-WHERE-2">
<REFSECT2INFO>
<DATE>1998-04-15</DATE>
</REFSECT2INFO>
<TITLE>
WHERE clause
</TITLE>
<PARA>
The optional WHERE condition has the general form:
<Synopsis>
WHERE <REPLACEABLE CLASS="PARAMETER">expr</REPLACEABLE> <REPLACEABLE CLASS="PARAMETER">cond_op</REPLACEABLE> <REPLACEABLE CLASS="PARAMETER">expr</REPLACEABLE> [<REPLACEABLE CLASS="PARAMETER">log_op</REPLACEABLE> ...]
</Synopsis>
where <REPLACEABLE CLASS="PARAMETER">cond_op</REPLACEABLE> can be one of: =, <, <=, >, >=, <>
or a conditional operator like ALL, ANY, IN, LIKE, et cetera
and <REPLACEABLE CLASS="PARAMETER">log_op</REPLACEABLE> 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.
</PARA>
</REFSECT2>
<REFSECT2 ID="R2-SQL-GROUPBY-2">
<REFSECT2INFO>
<DATE>1998-04-15</DATE>
</REFSECT2INFO>
<TITLE>
GROUP BY clause
</TITLE>
<PARA>
GROUP BY specifies a grouped table derived by the application
of the this clause:
<SYNOPSIS>
GROUP BY <REPLACEABLE CLASS="PARAMETER">column</REPLACEABLE> [, ...]
</SYNOPSIS>
<REFSECT2 ID="R2-SQL-HAVING-2">
<REFSECT2INFO>
<DATE>1998-04-15</DATE>
</REFSECT2INFO>
<TITLE>
HAVING clause
</TITLE>
<PARA>
The optional HAVING condition has the general form:
<Synopsis>
HAVING <REPLACEABLE CLASS="PARAMETER">cond_expr</REPLACEABLE>
</Synopsis>
where <REPLACEABLE CLASS="PARAMETER">cond_expr</REPLACEABLE> is the same
as specified for the WHERE clause.
<Para>
HAVING specifies a grouped table derived by the elimination
of groups from the result of the previously specified clause
that do not meet the <REPLACEABLE CLASS="PARAMETER">cond_expr</REPLACEABLE>.
<Para>
Each column referenced in <REPLACEABLE CLASS="PARAMETER">cond_expr</REPLACEABLE> shall unambiguously
reference a grouping column.
</PARA>
</REFSECT2>
<REFSECT2 ID="R2-SQL-ORDERBYCLAUSE-2">
<REFSECT2INFO>
<DATE>1998-04-15</DATE>
</REFSECT2INFO>
<TITLE>
ORDER BY clause
</TITLE>
<PARA>
<Synopsis>
ORDER BY <REPLACEABLE CLASS="PARAMETER">column</REPLACEABLE> [ASC | DESC] [, ...]
</Synopsis>
<PARA>
<REPLACEABLE CLASS="PARAMETER">column</REPLACEABLE> can be either a column
name or an ordinal number.
<PARA>
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.:
<ProgramListing>
SELECT title, date_prod + 1 AS newlen FROM films ORDER BY newlen;
</ProgramListing>
<PARA>
The columns in the ORDER BY must appear in the SELECT clause.
Thus the following statement is illegal:
<ProgramListing>
SELECT name FROM distributors ORDER BY code;
</ProgramListing>
<PARA>
Optionally one may add the keyword DESC (descending)
or ASC (ascending) after each column name in the ORDER BY clause.
If not specified, ASC is assumed by default.
</REFSECT2>
<REFSECT2 ID="R2-SQL-UNION-2">
<REFSECT2INFO>
<DATE>1998-04-15</DATE>
</REFSECT2INFO>
<TITLE>
UNION clause
</TITLE>
<PARA>
<Synopsis>
<REPLACEABLE CLASS="PARAMETER">table_query</REPLACEABLE> UNION [ALL] <REPLACEABLE CLASS="PARAMETER">table_query</REPLACEABLE>
[ORDER BY <REPLACEABLE CLASS="PARAMETER">column</REPLACEABLE> [ASC | DESC] [, ...] ]
</Synopsis>
where
<REPLACEABLE CLASS="PARAMETER">table_query</REPLACEABLE>
specifies any select expression without an ORDER BY clause.
<PARA>
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.
<PARA>
By default, the result of UNION does not contain any duplicate rows
unless the ALL clause is specified.
<Para>
Multiple UNION operators in the same SELECT statement are evaluated left to right.
Note that the ALL keyword is not global in nature, being applied only for the current pair of
table results.
</REFSECT2>
<REFSECT1 ID="R1-SQL-SELECT-2">
<TITLE>
Usage
</TITLE>
<PARA>
</PARA>
<ProgramListing>
--Join table films with their distributors:
--
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
</ProgramListing>
<ProgramListing>
--sum column "len" of all films group by "kind":
--
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
</ProgramListing>
<ProgramListing>
--sum column length of all films group by "kind"
--having total duration < 5 hours:
--
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
</ProgramListing>
<ProgramListing>
--The following two examples are identicals:
--
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
</ProgramListing>
<ProgramListing>
--union of table distributors and table actors:
-- (only those that begin with letter W):
--
-- distributors: actors:
-- did|name id|name
-- ---+------------ --+--------------
-- 108|Westward 1|Woody Allen
-- 111|Walt Disney 2|Warren Beatty
-- 112|Warner Bros. 3|Walter Matthau
-- ... ...
--
--select only distinct rows (without ALL):
--
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>
</REFSECT1>
<REFSECT1 ID="R1-SQL-SELECT-3">
<TITLE>
Compatibility
</TITLE>
<PARA>
</PARA>
<REFSECT2 ID="R2-SQL-SELECT-4">
<REFSECT2INFO>
<DATE>1998-04-15</DATE>
</REFSECT2INFO>
<TITLE>
<Acronym>SQL92</Acronym>
</TITLE>
<PARA>
</PARA>
<REFSECT3 ID="R3-SQL-SELECT-1">
<REFSECT3INFO>
<DATE>1998-04-15</DATE>
</REFSECT3INFO>
<TITLE>
SELECT clause
</TITLE>
<PARA>
In the <Acronym>SQL92</Acronym> standard, the optional keyword "AS" is just noise and can be
omitted without affecting the meaning.
The <ProductName>Postgres</ProductName> parser requires this keyword when
renaming columns because the type extensibility features lead to parsing ambiguities
in this context.
<PARA>
In the <Acronym>SQL92</Acronym> 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 <ProductName>Postgres</ProductName>.
</PARA>
</REFSECT3>
<REFSECT3 ID="R3-SQL-UNION-1">
<REFSECT3INFO>
<DATE>1998-04-15</DATE>
</REFSECT3INFO>
<TITLE>
UNION clause
</TITLE>
<PARA>
The <Acronym>SQL92</Acronym> syntax for UNION allows an additional CORRESPONDING BY clause:
<Synopsis>
<REPLACEABLE CLASS="PARAMETER">table_query</REPLACEABLE> UNION [ALL]
[CORRESPONDING [BY (<REPLACEABLE CLASS="PARAMETER">column</REPLACEABLE> [,...])]]
<REPLACEABLE CLASS="PARAMETER">table_query</REPLACEABLE>
</Synopsis>
<Para>
The CORRESPONDING BY clause is not supported by <ProductName>Postgres</ProductName>.
</PARA>
</REFSECT3>
</REFSECT2>
</REFSECT1>
</REFENTRY>
<!--
<REPLACEABLE CLASS="PARAMETER">
</REPLACEABLE>
<ReturnValue></ReturnValue>
<PARA>
</PARA>
<VARIABLELIST>
<VARLISTENTRY>
<TERM>•
</TERM>
<LISTITEM>
<PARA>
</PARA>
</LISTITEM>
</VARLISTENTRY>
</VARIABLELIST>
<PARA>
</PARA>
-->