1SELECT(7) PostgreSQL 13.3 Documentation SELECT(7)
2
3
4
6 SELECT, TABLE, WITH - retrieve rows from a table or view
7
9 [ WITH [ RECURSIVE ] with_query [, ...] ]
10 SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ]
11 [ * | expression [ [ AS ] output_name ] [, ...] ]
12 [ FROM from_item [, ...] ]
13 [ WHERE condition ]
14 [ GROUP BY grouping_element [, ...] ]
15 [ HAVING condition ]
16 [ WINDOW window_name AS ( window_definition ) [, ...] ]
17 [ { UNION | INTERSECT | EXCEPT } [ ALL | DISTINCT ] select ]
18 [ ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...] ]
19 [ LIMIT { count | ALL } ]
20 [ OFFSET start [ ROW | ROWS ] ]
21 [ FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } { ONLY | WITH TIES } ]
22 [ FOR { UPDATE | NO KEY UPDATE | SHARE | KEY SHARE } [ OF table_name [, ...] ] [ NOWAIT | SKIP LOCKED ] [...] ]
23
24 where from_item can be one of:
25
26 [ ONLY ] table_name [ * ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
27 [ TABLESAMPLE sampling_method ( argument [, ...] ) [ REPEATABLE ( seed ) ] ]
28 [ LATERAL ] ( select ) [ AS ] alias [ ( column_alias [, ...] ) ]
29 with_query_name [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
30 [ LATERAL ] function_name ( [ argument [, ...] ] )
31 [ WITH ORDINALITY ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
32 [ LATERAL ] function_name ( [ argument [, ...] ] ) [ AS ] alias ( column_definition [, ...] )
33 [ LATERAL ] function_name ( [ argument [, ...] ] ) AS ( column_definition [, ...] )
34 [ LATERAL ] ROWS FROM( function_name ( [ argument [, ...] ] ) [ AS ( column_definition [, ...] ) ] [, ...] )
35 [ WITH ORDINALITY ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
36 from_item [ NATURAL ] join_type from_item [ ON join_condition | USING ( join_column [, ...] ) ]
37
38 and grouping_element can be one of:
39
40 ( )
41 expression
42 ( expression [, ...] )
43 ROLLUP ( { expression | ( expression [, ...] ) } [, ...] )
44 CUBE ( { expression | ( expression [, ...] ) } [, ...] )
45 GROUPING SETS ( grouping_element [, ...] )
46
47 and with_query is:
48
49 with_query_name [ ( column_name [, ...] ) ] AS [ [ NOT ] MATERIALIZED ] ( select | values | insert | update | delete )
50
51 TABLE [ ONLY ] table_name [ * ]
52
54 SELECT retrieves rows from zero or more tables. The general processing
55 of SELECT is as follows:
56
57 1. All queries in the WITH list are computed. These effectively serve
58 as temporary tables that can be referenced in the FROM list. A WITH
59 query that is referenced more than once in FROM is computed only
60 once, unless specified otherwise with NOT MATERIALIZED. (See WITH
61 Clause below.)
62
63 2. All elements in the FROM list are computed. (Each element in the
64 FROM list is a real or virtual table.) If more than one element is
65 specified in the FROM list, they are cross-joined together. (See
66 FROM Clause below.)
67
68 3. If the WHERE clause is specified, all rows that do not satisfy the
69 condition are eliminated from the output. (See WHERE Clause below.)
70
71 4. If the GROUP BY clause is specified, or if there are aggregate
72 function calls, the output is combined into groups of rows that
73 match on one or more values, and the results of aggregate functions
74 are computed. If the HAVING clause is present, it eliminates groups
75 that do not satisfy the given condition. (See GROUP BY Clause and
76 HAVING Clause below.)
77
78 5. The actual output rows are computed using the SELECT output
79 expressions for each selected row or row group. (See SELECT List
80 below.)
81
82 6. SELECT DISTINCT eliminates duplicate rows from the result. SELECT
83 DISTINCT ON eliminates rows that match on all the specified
84 expressions. SELECT ALL (the default) will return all candidate
85 rows, including duplicates. (See DISTINCT Clause below.)
86
87 7. Using the operators UNION, INTERSECT, and EXCEPT, the output of
88 more than one SELECT statement can be combined to form a single
89 result set. The UNION operator returns all rows that are in one or
90 both of the result sets. The INTERSECT operator returns all rows
91 that are strictly in both result sets. The EXCEPT operator returns
92 the rows that are in the first result set but not in the second. In
93 all three cases, duplicate rows are eliminated unless ALL is
94 specified. The noise word DISTINCT can be added to explicitly
95 specify eliminating duplicate rows. Notice that DISTINCT is the
96 default behavior here, even though ALL is the default for SELECT
97 itself. (See UNION Clause, INTERSECT Clause, and EXCEPT Clause
98 below.)
99
100 8. If the ORDER BY clause is specified, the returned rows are sorted
101 in the specified order. If ORDER BY is not given, the rows are
102 returned in whatever order the system finds fastest to produce.
103 (See ORDER BY Clause below.)
104
105 9. If the LIMIT (or FETCH FIRST) or OFFSET clause is specified, the
106 SELECT statement only returns a subset of the result rows. (See
107 LIMIT Clause below.)
108
109 10. If FOR UPDATE, FOR NO KEY UPDATE, FOR SHARE or FOR KEY SHARE is
110 specified, the SELECT statement locks the selected rows against
111 concurrent updates. (See The Locking Clause below.)
112
113 You must have SELECT privilege on each column used in a SELECT command.
114 The use of FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE or FOR KEY SHARE
115 requires UPDATE privilege as well (for at least one column of each
116 table so selected).
117
119 WITH Clause
120 The WITH clause allows you to specify one or more subqueries that can
121 be referenced by name in the primary query. The subqueries effectively
122 act as temporary tables or views for the duration of the primary query.
123 Each subquery can be a SELECT, TABLE, VALUES, INSERT, UPDATE or DELETE
124 statement. When writing a data-modifying statement (INSERT, UPDATE or
125 DELETE) in WITH, it is usual to include a RETURNING clause. It is the
126 output of RETURNING, not the underlying table that the statement
127 modifies, that forms the temporary table that is read by the primary
128 query. If RETURNING is omitted, the statement is still executed, but it
129 produces no output so it cannot be referenced as a table by the primary
130 query.
131
132 A name (without schema qualification) must be specified for each WITH
133 query. Optionally, a list of column names can be specified; if this is
134 omitted, the column names are inferred from the subquery.
135
136 If RECURSIVE is specified, it allows a SELECT subquery to reference
137 itself by name. Such a subquery must have the form
138
139 non_recursive_term UNION [ ALL | DISTINCT ] recursive_term
140
141 where the recursive self-reference must appear on the right-hand side
142 of the UNION. Only one recursive self-reference is permitted per query.
143 Recursive data-modifying statements are not supported, but you can use
144 the results of a recursive SELECT query in a data-modifying statement.
145 See Section 7.8 for an example.
146
147 Another effect of RECURSIVE is that WITH queries need not be ordered: a
148 query can reference another one that is later in the list. (However,
149 circular references, or mutual recursion, are not implemented.) Without
150 RECURSIVE, WITH queries can only reference sibling WITH queries that
151 are earlier in the WITH list.
152
153 When there are multiple queries in the WITH clause, RECURSIVE should be
154 written only once, immediately after WITH. It applies to all queries in
155 the WITH clause, though it has no effect on queries that do not use
156 recursion or forward references.
157
158 The primary query and the WITH queries are all (notionally) executed at
159 the same time. This implies that the effects of a data-modifying
160 statement in WITH cannot be seen from other parts of the query, other
161 than by reading its RETURNING output. If two such data-modifying
162 statements attempt to modify the same row, the results are unspecified.
163
164 A key property of WITH queries is that they are normally evaluated only
165 once per execution of the primary query, even if the primary query
166 refers to them more than once. In particular, data-modifying statements
167 are guaranteed to be executed once and only once, regardless of whether
168 the primary query reads all or any of their output.
169
170 However, a WITH query can be marked NOT MATERIALIZED to remove this
171 guarantee. In that case, the WITH query can be folded into the primary
172 query much as though it were a simple sub-SELECT in the primary query's
173 FROM clause. This results in duplicate computations if the primary
174 query refers to that WITH query more than once; but if each such use
175 requires only a few rows of the WITH query's total output, NOT
176 MATERIALIZED can provide a net savings by allowing the queries to be
177 optimized jointly. NOT MATERIALIZED is ignored if it is attached to a
178 WITH query that is recursive or is not side-effect-free (i.e., is not a
179 plain SELECT containing no volatile functions).
180
181 By default, a side-effect-free WITH query is folded into the primary
182 query if it is used exactly once in the primary query's FROM clause.
183 This allows joint optimization of the two query levels in situations
184 where that should be semantically invisible. However, such folding can
185 be prevented by marking the WITH query as MATERIALIZED. That might be
186 useful, for example, if the WITH query is being used as an optimization
187 fence to prevent the planner from choosing a bad plan. PostgreSQL
188 versions before v12 never did such folding, so queries written for
189 older versions might rely on WITH to act as an optimization fence.
190
191 See Section 7.8 for additional information.
192
193 FROM Clause
194 The FROM clause specifies one or more source tables for the SELECT. If
195 multiple sources are specified, the result is the Cartesian product
196 (cross join) of all the sources. But usually qualification conditions
197 are added (via WHERE) to restrict the returned rows to a small subset
198 of the Cartesian product.
199
200 The FROM clause can contain the following elements:
201
202 table_name
203 The name (optionally schema-qualified) of an existing table or
204 view. If ONLY is specified before the table name, only that table
205 is scanned. If ONLY is not specified, the table and all its
206 descendant tables (if any) are scanned. Optionally, * can be
207 specified after the table name to explicitly indicate that
208 descendant tables are included.
209
210 alias
211 A substitute name for the FROM item containing the alias. An alias
212 is used for brevity or to eliminate ambiguity for self-joins (where
213 the same table is scanned multiple times). When an alias is
214 provided, it completely hides the actual name of the table or
215 function; for example given FROM foo AS f, the remainder of the
216 SELECT must refer to this FROM item as f not foo. If an alias is
217 written, a column alias list can also be written to provide
218 substitute names for one or more columns of the table.
219
220 TABLESAMPLE sampling_method ( argument [, ...] ) [ REPEATABLE ( seed )
221 ]
222 A TABLESAMPLE clause after a table_name indicates that the
223 specified sampling_method should be used to retrieve a subset of
224 the rows in that table. This sampling precedes the application of
225 any other filters such as WHERE clauses. The standard PostgreSQL
226 distribution includes two sampling methods, BERNOULLI and SYSTEM,
227 and other sampling methods can be installed in the database via
228 extensions.
229
230 The BERNOULLI and SYSTEM sampling methods each accept a single
231 argument which is the fraction of the table to sample, expressed as
232 a percentage between 0 and 100. This argument can be any
233 real-valued expression. (Other sampling methods might accept more
234 or different arguments.) These two methods each return a
235 randomly-chosen sample of the table that will contain approximately
236 the specified percentage of the table's rows. The BERNOULLI method
237 scans the whole table and selects or ignores individual rows
238 independently with the specified probability. The SYSTEM method
239 does block-level sampling with each block having the specified
240 chance of being selected; all rows in each selected block are
241 returned. The SYSTEM method is significantly faster than the
242 BERNOULLI method when small sampling percentages are specified, but
243 it may return a less-random sample of the table as a result of
244 clustering effects.
245
246 The optional REPEATABLE clause specifies a seed number or
247 expression to use for generating random numbers within the sampling
248 method. The seed value can be any non-null floating-point value.
249 Two queries that specify the same seed and argument values will
250 select the same sample of the table, if the table has not been
251 changed meanwhile. But different seed values will usually produce
252 different samples. If REPEATABLE is not given then a new random
253 sample is selected for each query, based upon a system-generated
254 seed. Note that some add-on sampling methods do not accept
255 REPEATABLE, and will always produce new samples on each use.
256
257 select
258 A sub-SELECT can appear in the FROM clause. This acts as though its
259 output were created as a temporary table for the duration of this
260 single SELECT command. Note that the sub-SELECT must be surrounded
261 by parentheses, and an alias must be provided for it. A VALUES(7)
262 command can also be used here.
263
264 with_query_name
265 A WITH query is referenced by writing its name, just as though the
266 query's name were a table name. (In fact, the WITH query hides any
267 real table of the same name for the purposes of the primary query.
268 If necessary, you can refer to a real table of the same name by
269 schema-qualifying the table's name.) An alias can be provided in
270 the same way as for a table.
271
272 function_name
273 Function calls can appear in the FROM clause. (This is especially
274 useful for functions that return result sets, but any function can
275 be used.) This acts as though the function's output were created as
276 a temporary table for the duration of this single SELECT command.
277 If the function's result type is composite (including the case of a
278 function with multiple OUT parameters), each attribute becomes a
279 separate column in the implicit table.
280
281 When the optional WITH ORDINALITY clause is added to the function
282 call, an additional column of type bigint will be appended to the
283 function's result column(s). This column numbers the rows of the
284 function's result set, starting from 1. By default, this column is
285 named ordinality.
286
287 An alias can be provided in the same way as for a table. If an
288 alias is written, a column alias list can also be written to
289 provide substitute names for one or more attributes of the
290 function's composite return type, including the ordinality column
291 if present.
292
293 Multiple function calls can be combined into a single FROM-clause
294 item by surrounding them with ROWS FROM( ... ). The output of such
295 an item is the concatenation of the first row from each function,
296 then the second row from each function, etc. If some of the
297 functions produce fewer rows than others, null values are
298 substituted for the missing data, so that the total number of rows
299 returned is always the same as for the function that produced the
300 most rows.
301
302 If the function has been defined as returning the record data type,
303 then an alias or the key word AS must be present, followed by a
304 column definition list in the form ( column_name data_type [, ...
305 ]). The column definition list must match the actual number and
306 types of columns returned by the function.
307
308 When using the ROWS FROM( ... ) syntax, if one of the functions
309 requires a column definition list, it's preferred to put the column
310 definition list after the function call inside ROWS FROM( ... ). A
311 column definition list can be placed after the ROWS FROM( ... )
312 construct only if there's just a single function and no WITH
313 ORDINALITY clause.
314
315 To use ORDINALITY together with a column definition list, you must
316 use the ROWS FROM( ... ) syntax and put the column definition list
317 inside ROWS FROM( ... ).
318
319 join_type
320 One of
321
322 • [ INNER ] JOIN
323
324 • LEFT [ OUTER ] JOIN
325
326 • RIGHT [ OUTER ] JOIN
327
328 • FULL [ OUTER ] JOIN
329
330 • CROSS JOIN
331
332 For the INNER and OUTER join types, a join condition must be
333 specified, namely exactly one of NATURAL, ON join_condition, or
334 USING (join_column [, ...]). See below for the meaning. For CROSS
335 JOIN, none of these clauses can appear.
336
337 A JOIN clause combines two FROM items, which for convenience we
338 will refer to as “tables”, though in reality they can be any type
339 of FROM item. Use parentheses if necessary to determine the order
340 of nesting. In the absence of parentheses, JOINs nest
341 left-to-right. In any case JOIN binds more tightly than the commas
342 separating FROM-list items.
343
344 CROSS JOIN and INNER JOIN produce a simple Cartesian product, the
345 same result as you get from listing the two tables at the top level
346 of FROM, but restricted by the join condition (if any). CROSS JOIN
347 is equivalent to INNER JOIN ON (TRUE), that is, no rows are removed
348 by qualification. These join types are just a notational
349 convenience, since they do nothing you couldn't do with plain FROM
350 and WHERE.
351
352 LEFT OUTER JOIN returns all rows in the qualified Cartesian product
353 (i.e., all combined rows that pass its join condition), plus one
354 copy of each row in the left-hand table for which there was no
355 right-hand row that passed the join condition. This left-hand row
356 is extended to the full width of the joined table by inserting null
357 values for the right-hand columns. Note that only the JOIN clause's
358 own condition is considered while deciding which rows have matches.
359 Outer conditions are applied afterwards.
360
361 Conversely, RIGHT OUTER JOIN returns all the joined rows, plus one
362 row for each unmatched right-hand row (extended with nulls on the
363 left). This is just a notational convenience, since you could
364 convert it to a LEFT OUTER JOIN by switching the left and right
365 tables.
366
367 FULL OUTER JOIN returns all the joined rows, plus one row for each
368 unmatched left-hand row (extended with nulls on the right), plus
369 one row for each unmatched right-hand row (extended with nulls on
370 the left).
371
372 ON join_condition
373 join_condition is an expression resulting in a value of type
374 boolean (similar to a WHERE clause) that specifies which rows in a
375 join are considered to match.
376
377 USING ( join_column [, ...] )
378 A clause of the form USING ( a, b, ... ) is shorthand for ON
379 left_table.a = right_table.a AND left_table.b = right_table.b ....
380 Also, USING implies that only one of each pair of equivalent
381 columns will be included in the join output, not both.
382
383 NATURAL
384 NATURAL is shorthand for a USING list that mentions all columns in
385 the two tables that have matching names. If there are no common
386 column names, NATURAL is equivalent to ON TRUE.
387
388 LATERAL
389 The LATERAL key word can precede a sub-SELECT FROM item. This
390 allows the sub-SELECT to refer to columns of FROM items that appear
391 before it in the FROM list. (Without LATERAL, each sub-SELECT is
392 evaluated independently and so cannot cross-reference any other
393 FROM item.)
394
395 LATERAL can also precede a function-call FROM item, but in this
396 case it is a noise word, because the function expression can refer
397 to earlier FROM items in any case.
398
399 A LATERAL item can appear at top level in the FROM list, or within
400 a JOIN tree. In the latter case it can also refer to any items that
401 are on the left-hand side of a JOIN that it is on the right-hand
402 side of.
403
404 When a FROM item contains LATERAL cross-references, evaluation
405 proceeds as follows: for each row of the FROM item providing the
406 cross-referenced column(s), or set of rows of multiple FROM items
407 providing the columns, the LATERAL item is evaluated using that row
408 or row set's values of the columns. The resulting row(s) are joined
409 as usual with the rows they were computed from. This is repeated
410 for each row or set of rows from the column source table(s).
411
412 The column source table(s) must be INNER or LEFT joined to the
413 LATERAL item, else there would not be a well-defined set of rows
414 from which to compute each set of rows for the LATERAL item. Thus,
415 although a construct such as X RIGHT JOIN LATERAL Y is
416 syntactically valid, it is not actually allowed for Y to reference
417 X.
418
419 WHERE Clause
420 The optional WHERE clause has the general form
421
422 WHERE condition
423
424 where condition is any expression that evaluates to a result of type
425 boolean. Any row that does not satisfy this condition will be
426 eliminated from the output. A row satisfies the condition if it returns
427 true when the actual row values are substituted for any variable
428 references.
429
430 GROUP BY Clause
431 The optional GROUP BY clause has the general form
432
433 GROUP BY grouping_element [, ...]
434
435 GROUP BY will condense into a single row all selected rows that share
436 the same values for the grouped expressions. An expression used inside
437 a grouping_element can be an input column name, or the name or ordinal
438 number of an output column (SELECT list item), or an arbitrary
439 expression formed from input-column values. In case of ambiguity, a
440 GROUP BY name will be interpreted as an input-column name rather than
441 an output column name.
442
443 If any of GROUPING SETS, ROLLUP or CUBE are present as grouping
444 elements, then the GROUP BY clause as a whole defines some number of
445 independent grouping sets. The effect of this is equivalent to
446 constructing a UNION ALL between subqueries with the individual
447 grouping sets as their GROUP BY clauses. For further details on the
448 handling of grouping sets see Section 7.2.4.
449
450 Aggregate functions, if any are used, are computed across all rows
451 making up each group, producing a separate value for each group. (If
452 there are aggregate functions but no GROUP BY clause, the query is
453 treated as having a single group comprising all the selected rows.) The
454 set of rows fed to each aggregate function can be further filtered by
455 attaching a FILTER clause to the aggregate function call; see
456 Section 4.2.7 for more information. When a FILTER clause is present,
457 only those rows matching it are included in the input to that aggregate
458 function.
459
460 When GROUP BY is present, or any aggregate functions are present, it is
461 not valid for the SELECT list expressions to refer to ungrouped columns
462 except within aggregate functions or when the ungrouped column is
463 functionally dependent on the grouped columns, since there would
464 otherwise be more than one possible value to return for an ungrouped
465 column. A functional dependency exists if the grouped columns (or a
466 subset thereof) are the primary key of the table containing the
467 ungrouped column.
468
469 Keep in mind that all aggregate functions are evaluated before
470 evaluating any “scalar” expressions in the HAVING clause or SELECT
471 list. This means that, for example, a CASE expression cannot be used to
472 skip evaluation of an aggregate function; see Section 4.2.14.
473
474 Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
475 cannot be specified with GROUP BY.
476
477 HAVING Clause
478 The optional HAVING clause has the general form
479
480 HAVING condition
481
482 where condition is the same as specified for the WHERE clause.
483
484 HAVING eliminates group rows that do not satisfy the condition. HAVING
485 is different from WHERE: WHERE filters individual rows before the
486 application of GROUP BY, while HAVING filters group rows created by
487 GROUP BY. Each column referenced in condition must unambiguously
488 reference a grouping column, unless the reference appears within an
489 aggregate function or the ungrouped column is functionally dependent on
490 the grouping columns.
491
492 The presence of HAVING turns a query into a grouped query even if there
493 is no GROUP BY clause. This is the same as what happens when the query
494 contains aggregate functions but no GROUP BY clause. All the selected
495 rows are considered to form a single group, and the SELECT list and
496 HAVING clause can only reference table columns from within aggregate
497 functions. Such a query will emit a single row if the HAVING condition
498 is true, zero rows if it is not true.
499
500 Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
501 cannot be specified with HAVING.
502
503 WINDOW Clause
504 The optional WINDOW clause has the general form
505
506 WINDOW window_name AS ( window_definition ) [, ...]
507
508 where window_name is a name that can be referenced from OVER clauses or
509 subsequent window definitions, and window_definition is
510
511 [ existing_window_name ]
512 [ PARTITION BY expression [, ...] ]
513 [ ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...] ]
514 [ frame_clause ]
515
516 If an existing_window_name is specified it must refer to an earlier
517 entry in the WINDOW list; the new window copies its partitioning clause
518 from that entry, as well as its ordering clause if any. In this case
519 the new window cannot specify its own PARTITION BY clause, and it can
520 specify ORDER BY only if the copied window does not have one. The new
521 window always uses its own frame clause; the copied window must not
522 specify a frame clause.
523
524 The elements of the PARTITION BY list are interpreted in much the same
525 fashion as elements of a GROUP BY clause, except that they are always
526 simple expressions and never the name or number of an output column.
527 Another difference is that these expressions can contain aggregate
528 function calls, which are not allowed in a regular GROUP BY clause.
529 They are allowed here because windowing occurs after grouping and
530 aggregation.
531
532 Similarly, the elements of the ORDER BY list are interpreted in much
533 the same fashion as elements of a statement-level ORDER BY clause,
534 except that the expressions are always taken as simple expressions and
535 never the name or number of an output column.
536
537 The optional frame_clause defines the window frame for window functions
538 that depend on the frame (not all do). The window frame is a set of
539 related rows for each row of the query (called the current row). The
540 frame_clause can be one of
541
542 { RANGE | ROWS | GROUPS } frame_start [ frame_exclusion ]
543 { RANGE | ROWS | GROUPS } BETWEEN frame_start AND frame_end [ frame_exclusion ]
544
545 where frame_start and frame_end can be one of
546
547 UNBOUNDED PRECEDING
548 offset PRECEDING
549 CURRENT ROW
550 offset FOLLOWING
551 UNBOUNDED FOLLOWING
552
553 and frame_exclusion can be one of
554
555 EXCLUDE CURRENT ROW
556 EXCLUDE GROUP
557 EXCLUDE TIES
558 EXCLUDE NO OTHERS
559
560 If frame_end is omitted it defaults to CURRENT ROW. Restrictions are
561 that frame_start cannot be UNBOUNDED FOLLOWING, frame_end cannot be
562 UNBOUNDED PRECEDING, and the frame_end choice cannot appear earlier in
563 the above list of frame_start and frame_end options than the
564 frame_start choice does — for example RANGE BETWEEN CURRENT ROW AND
565 offset PRECEDING is not allowed.
566
567 The default framing option is RANGE UNBOUNDED PRECEDING, which is the
568 same as RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW; it sets the
569 frame to be all rows from the partition start up through the current
570 row's last peer (a row that the window's ORDER BY clause considers
571 equivalent to the current row; all rows are peers if there is no ORDER
572 BY). In general, UNBOUNDED PRECEDING means that the frame starts with
573 the first row of the partition, and similarly UNBOUNDED FOLLOWING means
574 that the frame ends with the last row of the partition, regardless of
575 RANGE, ROWS or GROUPS mode. In ROWS mode, CURRENT ROW means that the
576 frame starts or ends with the current row; but in RANGE or GROUPS mode
577 it means that the frame starts or ends with the current row's first or
578 last peer in the ORDER BY ordering. The offset PRECEDING and offset
579 FOLLOWING options vary in meaning depending on the frame mode. In ROWS
580 mode, the offset is an integer indicating that the frame starts or ends
581 that many rows before or after the current row. In GROUPS mode, the
582 offset is an integer indicating that the frame starts or ends that many
583 peer groups before or after the current row's peer group, where a peer
584 group is a group of rows that are equivalent according to the window's
585 ORDER BY clause. In RANGE mode, use of an offset option requires that
586 there be exactly one ORDER BY column in the window definition. Then the
587 frame contains those rows whose ordering column value is no more than
588 offset less than (for PRECEDING) or more than (for FOLLOWING) the
589 current row's ordering column value. In these cases the data type of
590 the offset expression depends on the data type of the ordering column.
591 For numeric ordering columns it is typically of the same type as the
592 ordering column, but for datetime ordering columns it is an interval.
593 In all these cases, the value of the offset must be non-null and
594 non-negative. Also, while the offset does not have to be a simple
595 constant, it cannot contain variables, aggregate functions, or window
596 functions.
597
598 The frame_exclusion option allows rows around the current row to be
599 excluded from the frame, even if they would be included according to
600 the frame start and frame end options. EXCLUDE CURRENT ROW excludes
601 the current row from the frame. EXCLUDE GROUP excludes the current row
602 and its ordering peers from the frame. EXCLUDE TIES excludes any peers
603 of the current row from the frame, but not the current row itself.
604 EXCLUDE NO OTHERS simply specifies explicitly the default behavior of
605 not excluding the current row or its peers.
606
607 Beware that the ROWS mode can produce unpredictable results if the
608 ORDER BY ordering does not order the rows uniquely. The RANGE and
609 GROUPS modes are designed to ensure that rows that are peers in the
610 ORDER BY ordering are treated alike: all rows of a given peer group
611 will be in the frame or excluded from it.
612
613 The purpose of a WINDOW clause is to specify the behavior of window
614 functions appearing in the query's SELECT list or ORDER BY clause.
615 These functions can reference the WINDOW clause entries by name in
616 their OVER clauses. A WINDOW clause entry does not have to be
617 referenced anywhere, however; if it is not used in the query it is
618 simply ignored. It is possible to use window functions without any
619 WINDOW clause at all, since a window function call can specify its
620 window definition directly in its OVER clause. However, the WINDOW
621 clause saves typing when the same window definition is needed for more
622 than one window function.
623
624 Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
625 cannot be specified with WINDOW.
626
627 Window functions are described in detail in Section 3.5, Section 4.2.8,
628 and Section 7.2.5.
629
630 SELECT List
631 The SELECT list (between the key words SELECT and FROM) specifies
632 expressions that form the output rows of the SELECT statement. The
633 expressions can (and usually do) refer to columns computed in the FROM
634 clause.
635
636 Just as in a table, every output column of a SELECT has a name. In a
637 simple SELECT this name is just used to label the column for display,
638 but when the SELECT is a sub-query of a larger query, the name is seen
639 by the larger query as the column name of the virtual table produced by
640 the sub-query. To specify the name to use for an output column, write
641 AS output_name after the column's expression. (You can omit AS, but
642 only if the desired output name does not match any PostgreSQL keyword
643 (see Appendix C). For protection against possible future keyword
644 additions, it is recommended that you always either write AS or
645 double-quote the output name.) If you do not specify a column name, a
646 name is chosen automatically by PostgreSQL. If the column's expression
647 is a simple column reference then the chosen name is the same as that
648 column's name. In more complex cases a function or type name may be
649 used, or the system may fall back on a generated name such as ?column?.
650
651 An output column's name can be used to refer to the column's value in
652 ORDER BY and GROUP BY clauses, but not in the WHERE or HAVING clauses;
653 there you must write out the expression instead.
654
655 Instead of an expression, * can be written in the output list as a
656 shorthand for all the columns of the selected rows. Also, you can write
657 table_name.* as a shorthand for the columns coming from just that
658 table. In these cases it is not possible to specify new names with AS;
659 the output column names will be the same as the table columns' names.
660
661 According to the SQL standard, the expressions in the output list
662 should be computed before applying DISTINCT, ORDER BY, or LIMIT. This
663 is obviously necessary when using DISTINCT, since otherwise it's not
664 clear what values are being made distinct. However, in many cases it is
665 convenient if output expressions are computed after ORDER BY and LIMIT;
666 particularly if the output list contains any volatile or expensive
667 functions. With that behavior, the order of function evaluations is
668 more intuitive and there will not be evaluations corresponding to rows
669 that never appear in the output. PostgreSQL will effectively evaluate
670 output expressions after sorting and limiting, so long as those
671 expressions are not referenced in DISTINCT, ORDER BY or GROUP BY. (As a
672 counterexample, SELECT f(x) FROM tab ORDER BY 1 clearly must evaluate
673 f(x) before sorting.) Output expressions that contain set-returning
674 functions are effectively evaluated after sorting and before limiting,
675 so that LIMIT will act to cut off the output from a set-returning
676 function.
677
678 Note
679 PostgreSQL versions before 9.6 did not provide any guarantees about
680 the timing of evaluation of output expressions versus sorting and
681 limiting; it depended on the form of the chosen query plan.
682
683 DISTINCT Clause
684 If SELECT DISTINCT is specified, all duplicate rows are removed from
685 the result set (one row is kept from each group of duplicates). SELECT
686 ALL specifies the opposite: all rows are kept; that is the default.
687
688 SELECT DISTINCT ON ( expression [, ...] ) keeps only the first row of
689 each set of rows where the given expressions evaluate to equal. The
690 DISTINCT ON expressions are interpreted using the same rules as for
691 ORDER BY (see above). Note that the “first row” of each set is
692 unpredictable unless ORDER BY is used to ensure that the desired row
693 appears first. For example:
694
695 SELECT DISTINCT ON (location) location, time, report
696 FROM weather_reports
697 ORDER BY location, time DESC;
698
699 retrieves the most recent weather report for each location. But if we
700 had not used ORDER BY to force descending order of time values for each
701 location, we'd have gotten a report from an unpredictable time for each
702 location.
703
704 The DISTINCT ON expression(s) must match the leftmost ORDER BY
705 expression(s). The ORDER BY clause will normally contain additional
706 expression(s) that determine the desired precedence of rows within each
707 DISTINCT ON group.
708
709 Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
710 cannot be specified with DISTINCT.
711
712 UNION Clause
713 The UNION clause has this general form:
714
715 select_statement UNION [ ALL | DISTINCT ] select_statement
716
717 select_statement is any SELECT statement without an ORDER BY, LIMIT,
718 FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE, or FOR KEY SHARE clause.
719 (ORDER BY and LIMIT can be attached to a subexpression if it is
720 enclosed in parentheses. Without parentheses, these clauses will be
721 taken to apply to the result of the UNION, not to its right-hand input
722 expression.)
723
724 The UNION operator computes the set union of the rows returned by the
725 involved SELECT statements. A row is in the set union of two result
726 sets if it appears in at least one of the result sets. The two SELECT
727 statements that represent the direct operands of the UNION must produce
728 the same number of columns, and corresponding columns must be of
729 compatible data types.
730
731 The result of UNION does not contain any duplicate rows unless the ALL
732 option is specified. ALL prevents elimination of duplicates.
733 (Therefore, UNION ALL is usually significantly quicker than UNION; use
734 ALL when you can.) DISTINCT can be written to explicitly specify the
735 default behavior of eliminating duplicate rows.
736
737 Multiple UNION operators in the same SELECT statement are evaluated
738 left to right, unless otherwise indicated by parentheses.
739
740 Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
741 cannot be specified either for a UNION result or for any input of a
742 UNION.
743
744 INTERSECT Clause
745 The INTERSECT clause has this general form:
746
747 select_statement INTERSECT [ ALL | DISTINCT ] select_statement
748
749 select_statement is any SELECT statement without an ORDER BY, LIMIT,
750 FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE, or FOR KEY SHARE clause.
751
752 The INTERSECT operator computes the set intersection of the rows
753 returned by the involved SELECT statements. A row is in the
754 intersection of two result sets if it appears in both result sets.
755
756 The result of INTERSECT does not contain any duplicate rows unless the
757 ALL option is specified. With ALL, a row that has m duplicates in the
758 left table and n duplicates in the right table will appear min(m,n)
759 times in the result set. DISTINCT can be written to explicitly specify
760 the default behavior of eliminating duplicate rows.
761
762 Multiple INTERSECT operators in the same SELECT statement are evaluated
763 left to right, unless parentheses dictate otherwise. INTERSECT binds
764 more tightly than UNION. That is, A UNION B INTERSECT C will be read as
765 A UNION (B INTERSECT C).
766
767 Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
768 cannot be specified either for an INTERSECT result or for any input of
769 an INTERSECT.
770
771 EXCEPT Clause
772 The EXCEPT clause has this general form:
773
774 select_statement EXCEPT [ ALL | DISTINCT ] select_statement
775
776 select_statement is any SELECT statement without an ORDER BY, LIMIT,
777 FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE, or FOR KEY SHARE clause.
778
779 The EXCEPT operator computes the set of rows that are in the result of
780 the left SELECT statement but not in the result of the right one.
781
782 The result of EXCEPT does not contain any duplicate rows unless the ALL
783 option is specified. With ALL, a row that has m duplicates in the left
784 table and n duplicates in the right table will appear max(m-n,0) times
785 in the result set. DISTINCT can be written to explicitly specify the
786 default behavior of eliminating duplicate rows.
787
788 Multiple EXCEPT operators in the same SELECT statement are evaluated
789 left to right, unless parentheses dictate otherwise. EXCEPT binds at
790 the same level as UNION.
791
792 Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
793 cannot be specified either for an EXCEPT result or for any input of an
794 EXCEPT.
795
796 ORDER BY Clause
797 The optional ORDER BY clause has this general form:
798
799 ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...]
800
801 The ORDER BY clause causes the result rows to be sorted according to
802 the specified expression(s). If two rows are equal according to the
803 leftmost expression, they are compared according to the next expression
804 and so on. If they are equal according to all specified expressions,
805 they are returned in an implementation-dependent order.
806
807 Each expression can be the name or ordinal number of an output column
808 (SELECT list item), or it can be an arbitrary expression formed from
809 input-column values.
810
811 The ordinal number refers to the ordinal (left-to-right) position of
812 the output column. This feature makes it possible to define an ordering
813 on the basis of a column that does not have a unique name. This is
814 never absolutely necessary because it is always possible to assign a
815 name to an output column using the AS clause.
816
817 It is also possible to use arbitrary expressions in the ORDER BY
818 clause, including columns that do not appear in the SELECT output list.
819 Thus the following statement is valid:
820
821 SELECT name FROM distributors ORDER BY code;
822
823 A limitation of this feature is that an ORDER BY clause applying to the
824 result of a UNION, INTERSECT, or EXCEPT clause can only specify an
825 output column name or number, not an expression.
826
827 If an ORDER BY expression is a simple name that matches both an output
828 column name and an input column name, ORDER BY will interpret it as the
829 output column name. This is the opposite of the choice that GROUP BY
830 will make in the same situation. This inconsistency is made to be
831 compatible with the SQL standard.
832
833 Optionally one can add the key word ASC (ascending) or DESC
834 (descending) after any expression in the ORDER BY clause. If not
835 specified, ASC is assumed by default. Alternatively, a specific
836 ordering operator name can be specified in the USING clause. An
837 ordering operator must be a less-than or greater-than member of some
838 B-tree operator family. ASC is usually equivalent to USING < and DESC
839 is usually equivalent to USING >. (But the creator of a user-defined
840 data type can define exactly what the default sort ordering is, and it
841 might correspond to operators with other names.)
842
843 If NULLS LAST is specified, null values sort after all non-null values;
844 if NULLS FIRST is specified, null values sort before all non-null
845 values. If neither is specified, the default behavior is NULLS LAST
846 when ASC is specified or implied, and NULLS FIRST when DESC is
847 specified (thus, the default is to act as though nulls are larger than
848 non-nulls). When USING is specified, the default nulls ordering depends
849 on whether the operator is a less-than or greater-than operator.
850
851 Note that ordering options apply only to the expression they follow;
852 for example ORDER BY x, y DESC does not mean the same thing as ORDER BY
853 x DESC, y DESC.
854
855 Character-string data is sorted according to the collation that applies
856 to the column being sorted. That can be overridden at need by including
857 a COLLATE clause in the expression, for example ORDER BY mycolumn
858 COLLATE "en_US". For more information see Section 4.2.10 and
859 Section 23.2.
860
861 LIMIT Clause
862 The LIMIT clause consists of two independent sub-clauses:
863
864 LIMIT { count | ALL }
865 OFFSET start
866
867 The parameter count specifies the maximum number of rows to return,
868 while start specifies the number of rows to skip before starting to
869 return rows. When both are specified, start rows are skipped before
870 starting to count the count rows to be returned.
871
872 If the count expression evaluates to NULL, it is treated as LIMIT ALL,
873 i.e., no limit. If start evaluates to NULL, it is treated the same as
874 OFFSET 0.
875
876 SQL:2008 introduced a different syntax to achieve the same result,
877 which PostgreSQL also supports. It is:
878
879 OFFSET start { ROW | ROWS }
880 FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } { ONLY | WITH TIES }
881
882 In this syntax, the start or count value is required by the standard to
883 be a literal constant, a parameter, or a variable name; as a PostgreSQL
884 extension, other expressions are allowed, but will generally need to be
885 enclosed in parentheses to avoid ambiguity. If count is omitted in a
886 FETCH clause, it defaults to 1. The WITH TIES option is used to return
887 any additional rows that tie for the last place in the result set
888 according to the ORDER BY clause; ORDER BY is mandatory in this case.
889 ROW and ROWS as well as FIRST and NEXT are noise words that don't
890 influence the effects of these clauses. According to the standard, the
891 OFFSET clause must come before the FETCH clause if both are present;
892 but PostgreSQL is laxer and allows either order.
893
894 When using LIMIT, it is a good idea to use an ORDER BY clause that
895 constrains the result rows into a unique order. Otherwise you will get
896 an unpredictable subset of the query's rows — you might be asking for
897 the tenth through twentieth rows, but tenth through twentieth in what
898 ordering? You don't know what ordering unless you specify ORDER BY.
899
900 The query planner takes LIMIT into account when generating a query
901 plan, so you are very likely to get different plans (yielding different
902 row orders) depending on what you use for LIMIT and OFFSET. Thus, using
903 different LIMIT/OFFSET values to select different subsets of a query
904 result will give inconsistent results unless you enforce a predictable
905 result ordering with ORDER BY. This is not a bug; it is an inherent
906 consequence of the fact that SQL does not promise to deliver the
907 results of a query in any particular order unless ORDER BY is used to
908 constrain the order.
909
910 It is even possible for repeated executions of the same LIMIT query to
911 return different subsets of the rows of a table, if there is not an
912 ORDER BY to enforce selection of a deterministic subset. Again, this is
913 not a bug; determinism of the results is simply not guaranteed in such
914 a case.
915
916 The Locking Clause
917 FOR UPDATE, FOR NO KEY UPDATE, FOR SHARE and FOR KEY SHARE are locking
918 clauses; they affect how SELECT locks rows as they are obtained from
919 the table.
920
921 The locking clause has the general form
922
923 FOR lock_strength [ OF table_name [, ...] ] [ NOWAIT | SKIP LOCKED ]
924
925 where lock_strength can be one of
926
927 UPDATE
928 NO KEY UPDATE
929 SHARE
930 KEY SHARE
931
932 For more information on each row-level lock mode, refer to
933 Section 13.3.2.
934
935 To prevent the operation from waiting for other transactions to commit,
936 use either the NOWAIT or SKIP LOCKED option. With NOWAIT, the statement
937 reports an error, rather than waiting, if a selected row cannot be
938 locked immediately. With SKIP LOCKED, any selected rows that cannot be
939 immediately locked are skipped. Skipping locked rows provides an
940 inconsistent view of the data, so this is not suitable for general
941 purpose work, but can be used to avoid lock contention with multiple
942 consumers accessing a queue-like table. Note that NOWAIT and SKIP
943 LOCKED apply only to the row-level lock(s) — the required ROW SHARE
944 table-level lock is still taken in the ordinary way (see Chapter 13).
945 You can use LOCK(7) with the NOWAIT option first, if you need to
946 acquire the table-level lock without waiting.
947
948 If specific tables are named in a locking clause, then only rows coming
949 from those tables are locked; any other tables used in the SELECT are
950 simply read as usual. A locking clause without a table list affects all
951 tables used in the statement. If a locking clause is applied to a view
952 or sub-query, it affects all tables used in the view or sub-query.
953 However, these clauses do not apply to WITH queries referenced by the
954 primary query. If you want row locking to occur within a WITH query,
955 specify a locking clause within the WITH query.
956
957 Multiple locking clauses can be written if it is necessary to specify
958 different locking behavior for different tables. If the same table is
959 mentioned (or implicitly affected) by more than one locking clause,
960 then it is processed as if it was only specified by the strongest one.
961 Similarly, a table is processed as NOWAIT if that is specified in any
962 of the clauses affecting it. Otherwise, it is processed as SKIP LOCKED
963 if that is specified in any of the clauses affecting it.
964
965 The locking clauses cannot be used in contexts where returned rows
966 cannot be clearly identified with individual table rows; for example
967 they cannot be used with aggregation.
968
969 When a locking clause appears at the top level of a SELECT query, the
970 rows that are locked are exactly those that are returned by the query;
971 in the case of a join query, the rows locked are those that contribute
972 to returned join rows. In addition, rows that satisfied the query
973 conditions as of the query snapshot will be locked, although they will
974 not be returned if they were updated after the snapshot and no longer
975 satisfy the query conditions. If a LIMIT is used, locking stops once
976 enough rows have been returned to satisfy the limit (but note that rows
977 skipped over by OFFSET will get locked). Similarly, if a locking clause
978 is used in a cursor's query, only rows actually fetched or stepped past
979 by the cursor will be locked.
980
981 When a locking clause appears in a sub-SELECT, the rows locked are
982 those returned to the outer query by the sub-query. This might involve
983 fewer rows than inspection of the sub-query alone would suggest, since
984 conditions from the outer query might be used to optimize execution of
985 the sub-query. For example,
986
987 SELECT * FROM (SELECT * FROM mytable FOR UPDATE) ss WHERE col1 = 5;
988
989 will lock only rows having col1 = 5, even though that condition is not
990 textually within the sub-query.
991
992 Previous releases failed to preserve a lock which is upgraded by a
993 later savepoint. For example, this code:
994
995 BEGIN;
996 SELECT * FROM mytable WHERE key = 1 FOR UPDATE;
997 SAVEPOINT s;
998 UPDATE mytable SET ... WHERE key = 1;
999 ROLLBACK TO s;
1000
1001 would fail to preserve the FOR UPDATE lock after the ROLLBACK TO. This
1002 has been fixed in release 9.3.
1003
1004 Caution
1005 It is possible for a SELECT command running at the READ COMMITTED
1006 transaction isolation level and using ORDER BY and a locking clause
1007 to return rows out of order. This is because ORDER BY is applied
1008 first. The command sorts the result, but might then block trying to
1009 obtain a lock on one or more of the rows. Once the SELECT unblocks,
1010 some of the ordering column values might have been modified,
1011 leading to those rows appearing to be out of order (though they are
1012 in order in terms of the original column values). This can be
1013 worked around at need by placing the FOR UPDATE/SHARE clause in a
1014 sub-query, for example
1015
1016 SELECT * FROM (SELECT * FROM mytable FOR UPDATE) ss ORDER BY column1;
1017
1018 Note that this will result in locking all rows of mytable, whereas
1019 FOR UPDATE at the top level would lock only the actually returned
1020 rows. This can make for a significant performance difference,
1021 particularly if the ORDER BY is combined with LIMIT or other
1022 restrictions. So this technique is recommended only if concurrent
1023 updates of the ordering columns are expected and a strictly sorted
1024 result is required.
1025
1026 At the REPEATABLE READ or SERIALIZABLE transaction isolation level
1027 this would cause a serialization failure (with a SQLSTATE of
1028 '40001'), so there is no possibility of receiving rows out of order
1029 under these isolation levels.
1030
1031 TABLE Command
1032 The command
1033
1034 TABLE name
1035
1036 is equivalent to
1037
1038 SELECT * FROM name
1039
1040 It can be used as a top-level command or as a space-saving syntax
1041 variant in parts of complex queries. Only the WITH, UNION, INTERSECT,
1042 EXCEPT, ORDER BY, LIMIT, OFFSET, FETCH and FOR locking clauses can be
1043 used with TABLE; the WHERE clause and any form of aggregation cannot be
1044 used.
1045
1047 To join the table films with the table distributors:
1048
1049 SELECT f.title, f.did, d.name, f.date_prod, f.kind
1050 FROM distributors d, films f
1051 WHERE f.did = d.did
1052
1053 title | did | name | date_prod | kind
1054 -------------------+-----+--------------+------------+----------
1055 The Third Man | 101 | British Lion | 1949-12-23 | Drama
1056 The African Queen | 101 | British Lion | 1951-08-11 | Romantic
1057 ...
1058
1059 To sum the column len of all films and group the results by kind:
1060
1061 SELECT kind, sum(len) AS total FROM films GROUP BY kind;
1062
1063 kind | total
1064 ----------+-------
1065 Action | 07:34
1066 Comedy | 02:58
1067 Drama | 14:28
1068 Musical | 06:42
1069 Romantic | 04:38
1070
1071 To sum the column len of all films, group the results by kind and show
1072 those group totals that are less than 5 hours:
1073
1074 SELECT kind, sum(len) AS total
1075 FROM films
1076 GROUP BY kind
1077 HAVING sum(len) < interval '5 hours';
1078
1079 kind | total
1080 ----------+-------
1081 Comedy | 02:58
1082 Romantic | 04:38
1083
1084 The following two examples are identical ways of sorting the individual
1085 results according to the contents of the second column (name):
1086
1087 SELECT * FROM distributors ORDER BY name;
1088 SELECT * FROM distributors ORDER BY 2;
1089
1090 did | name
1091 -----+------------------
1092 109 | 20th Century Fox
1093 110 | Bavaria Atelier
1094 101 | British Lion
1095 107 | Columbia
1096 102 | Jean Luc Godard
1097 113 | Luso films
1098 104 | Mosfilm
1099 103 | Paramount
1100 106 | Toho
1101 105 | United Artists
1102 111 | Walt Disney
1103 112 | Warner Bros.
1104 108 | Westward
1105
1106 The next example shows how to obtain the union of the tables
1107 distributors and actors, restricting the results to those that begin
1108 with the letter W in each table. Only distinct rows are wanted, so the
1109 key word ALL is omitted.
1110
1111 distributors: actors:
1112 did | name id | name
1113 -----+-------------- ----+----------------
1114 108 | Westward 1 | Woody Allen
1115 111 | Walt Disney 2 | Warren Beatty
1116 112 | Warner Bros. 3 | Walter Matthau
1117 ... ...
1118
1119 SELECT distributors.name
1120 FROM distributors
1121 WHERE distributors.name LIKE 'W%'
1122 UNION
1123 SELECT actors.name
1124 FROM actors
1125 WHERE actors.name LIKE 'W%';
1126
1127 name
1128 ----------------
1129 Walt Disney
1130 Walter Matthau
1131 Warner Bros.
1132 Warren Beatty
1133 Westward
1134 Woody Allen
1135
1136 This example shows how to use a function in the FROM clause, both with
1137 and without a column definition list:
1138
1139 CREATE FUNCTION distributors(int) RETURNS SETOF distributors AS $$
1140 SELECT * FROM distributors WHERE did = $1;
1141 $$ LANGUAGE SQL;
1142
1143 SELECT * FROM distributors(111);
1144 did | name
1145 -----+-------------
1146 111 | Walt Disney
1147
1148 CREATE FUNCTION distributors_2(int) RETURNS SETOF record AS $$
1149 SELECT * FROM distributors WHERE did = $1;
1150 $$ LANGUAGE SQL;
1151
1152 SELECT * FROM distributors_2(111) AS (f1 int, f2 text);
1153 f1 | f2
1154 -----+-------------
1155 111 | Walt Disney
1156
1157 Here is an example of a function with an ordinality column added:
1158
1159 SELECT * FROM unnest(ARRAY['a','b','c','d','e','f']) WITH ORDINALITY;
1160 unnest | ordinality
1161 --------+----------
1162 a | 1
1163 b | 2
1164 c | 3
1165 d | 4
1166 e | 5
1167 f | 6
1168 (6 rows)
1169
1170 This example shows how to use a simple WITH clause:
1171
1172 WITH t AS (
1173 SELECT random() as x FROM generate_series(1, 3)
1174 )
1175 SELECT * FROM t
1176 UNION ALL
1177 SELECT * FROM t
1178
1179 x
1180 --------------------
1181 0.534150459803641
1182 0.520092216785997
1183 0.0735620250925422
1184 0.534150459803641
1185 0.520092216785997
1186 0.0735620250925422
1187
1188 Notice that the WITH query was evaluated only once, so that we got two
1189 sets of the same three random values.
1190
1191 This example uses WITH RECURSIVE to find all subordinates (direct or
1192 indirect) of the employee Mary, and their level of indirectness, from a
1193 table that shows only direct subordinates:
1194
1195 WITH RECURSIVE employee_recursive(distance, employee_name, manager_name) AS (
1196 SELECT 1, employee_name, manager_name
1197 FROM employee
1198 WHERE manager_name = 'Mary'
1199 UNION ALL
1200 SELECT er.distance + 1, e.employee_name, e.manager_name
1201 FROM employee_recursive er, employee e
1202 WHERE er.employee_name = e.manager_name
1203 )
1204 SELECT distance, employee_name FROM employee_recursive;
1205
1206 Notice the typical form of recursive queries: an initial condition,
1207 followed by UNION, followed by the recursive part of the query. Be sure
1208 that the recursive part of the query will eventually return no tuples,
1209 or else the query will loop indefinitely. (See Section 7.8 for more
1210 examples.)
1211
1212 This example uses LATERAL to apply a set-returning function
1213 get_product_names() for each row of the manufacturers table:
1214
1215 SELECT m.name AS mname, pname
1216 FROM manufacturers m, LATERAL get_product_names(m.id) pname;
1217
1218 Manufacturers not currently having any products would not appear in the
1219 result, since it is an inner join. If we wished to include the names of
1220 such manufacturers in the result, we could do:
1221
1222 SELECT m.name AS mname, pname
1223 FROM manufacturers m LEFT JOIN LATERAL get_product_names(m.id) pname ON true;
1224
1226 Of course, the SELECT statement is compatible with the SQL standard.
1227 But there are some extensions and some missing features.
1228
1229 Omitted FROM Clauses
1230 PostgreSQL allows one to omit the FROM clause. It has a straightforward
1231 use to compute the results of simple expressions:
1232
1233 SELECT 2+2;
1234
1235 ?column?
1236 ----------
1237 4
1238
1239 Some other SQL databases cannot do this except by introducing a dummy
1240 one-row table from which to do the SELECT.
1241
1242 Note that if a FROM clause is not specified, the query cannot reference
1243 any database tables. For example, the following query is invalid:
1244
1245 SELECT distributors.* WHERE distributors.name = 'Westward';
1246
1247 PostgreSQL releases prior to 8.1 would accept queries of this form, and
1248 add an implicit entry to the query's FROM clause for each table
1249 referenced by the query. This is no longer allowed.
1250
1251 Empty SELECT Lists
1252 The list of output expressions after SELECT can be empty, producing a
1253 zero-column result table. This is not valid syntax according to the SQL
1254 standard. PostgreSQL allows it to be consistent with allowing
1255 zero-column tables. However, an empty list is not allowed when DISTINCT
1256 is used.
1257
1258 Omitting the AS Key Word
1259 In the SQL standard, the optional key word AS can be omitted before an
1260 output column name whenever the new column name is a valid column name
1261 (that is, not the same as any reserved keyword). PostgreSQL is
1262 slightly more restrictive: AS is required if the new column name
1263 matches any keyword at all, reserved or not. Recommended practice is to
1264 use AS or double-quote output column names, to prevent any possible
1265 conflict against future keyword additions.
1266
1267 In FROM items, both the standard and PostgreSQL allow AS to be omitted
1268 before an alias that is an unreserved keyword. But this is impractical
1269 for output column names, because of syntactic ambiguities.
1270
1271 ONLY and Inheritance
1272 The SQL standard requires parentheses around the table name when
1273 writing ONLY, for example SELECT * FROM ONLY (tab1), ONLY (tab2) WHERE
1274 .... PostgreSQL considers these parentheses to be optional.
1275
1276 PostgreSQL allows a trailing * to be written to explicitly specify the
1277 non-ONLY behavior of including child tables. The standard does not
1278 allow this.
1279
1280 (These points apply equally to all SQL commands supporting the ONLY
1281 option.)
1282
1283 TABLESAMPLE Clause Restrictions
1284 The TABLESAMPLE clause is currently accepted only on regular tables and
1285 materialized views. According to the SQL standard it should be possible
1286 to apply it to any FROM item.
1287
1288 Function Calls in FROM
1289 PostgreSQL allows a function call to be written directly as a member of
1290 the FROM list. In the SQL standard it would be necessary to wrap such a
1291 function call in a sub-SELECT; that is, the syntax FROM func(...) alias
1292 is approximately equivalent to FROM LATERAL (SELECT func(...)) alias.
1293 Note that LATERAL is considered to be implicit; this is because the
1294 standard requires LATERAL semantics for an UNNEST() item in FROM.
1295 PostgreSQL treats UNNEST() the same as other set-returning functions.
1296
1297 Namespace Available to GROUP BY and ORDER BY
1298 In the SQL-92 standard, an ORDER BY clause can only use output column
1299 names or numbers, while a GROUP BY clause can only use expressions
1300 based on input column names. PostgreSQL extends each of these clauses
1301 to allow the other choice as well (but it uses the standard's
1302 interpretation if there is ambiguity). PostgreSQL also allows both
1303 clauses to specify arbitrary expressions. Note that names appearing in
1304 an expression will always be taken as input-column names, not as
1305 output-column names.
1306
1307 SQL:1999 and later use a slightly different definition which is not
1308 entirely upward compatible with SQL-92. In most cases, however,
1309 PostgreSQL will interpret an ORDER BY or GROUP BY expression the same
1310 way SQL:1999 does.
1311
1312 Functional Dependencies
1313 PostgreSQL recognizes functional dependency (allowing columns to be
1314 omitted from GROUP BY) only when a table's primary key is included in
1315 the GROUP BY list. The SQL standard specifies additional conditions
1316 that should be recognized.
1317
1318 LIMIT and OFFSET
1319 The clauses LIMIT and OFFSET are PostgreSQL-specific syntax, also used
1320 by MySQL. The SQL:2008 standard has introduced the clauses OFFSET ...
1321 FETCH {FIRST|NEXT} ... for the same functionality, as shown above in
1322 LIMIT Clause. This syntax is also used by IBM DB2. (Applications
1323 written for Oracle frequently use a workaround involving the
1324 automatically generated rownum column, which is not available in
1325 PostgreSQL, to implement the effects of these clauses.)
1326
1327 FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE, FOR KEY SHARE
1328 Although FOR UPDATE appears in the SQL standard, the standard allows it
1329 only as an option of DECLARE CURSOR. PostgreSQL allows it in any
1330 SELECT query as well as in sub-SELECTs, but this is an extension. The
1331 FOR NO KEY UPDATE, FOR SHARE and FOR KEY SHARE variants, as well as the
1332 NOWAIT and SKIP LOCKED options, do not appear in the standard.
1333
1334 Data-Modifying Statements in WITH
1335 PostgreSQL allows INSERT, UPDATE, and DELETE to be used as WITH
1336 queries. This is not found in the SQL standard.
1337
1338 Nonstandard Clauses
1339 DISTINCT ON ( ... ) is an extension of the SQL standard.
1340
1341 ROWS FROM( ... ) is an extension of the SQL standard.
1342
1343 The MATERIALIZED and NOT MATERIALIZED options of WITH are extensions of
1344 the SQL standard.
1345
1346
1347
1348PostgreSQL 13.3 2021 SELECT(7)