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