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