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