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