1SELECT(7)                PostgreSQL 10.7 Documentation               SELECT(7)
2
3
4

NAME

6       SELECT, TABLE, WITH - retrieve rows from a table or view
7

SYNOPSIS

9       [ WITH [ RECURSIVE ] with_query [, ...] ]
10       SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ]
11           [ * | expression [ [ AS ] output_name ] [, ...] ]
12           [ FROM from_item [, ...] ]
13           [ WHERE condition ]
14           [ GROUP BY grouping_element [, ...] ]
15           [ HAVING condition [, ...] ]
16           [ WINDOW window_name AS ( window_definition ) [, ...] ]
17           [ { UNION | INTERSECT | EXCEPT } [ ALL | DISTINCT ] select ]
18           [ ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...] ]
19           [ LIMIT { count | ALL } ]
20           [ OFFSET start [ ROW | ROWS ] ]
21           [ FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } ONLY ]
22           [ FOR { UPDATE | NO KEY UPDATE | SHARE | KEY SHARE } [ OF table_name [, ...] ] [ NOWAIT | SKIP LOCKED ] [...] ]
23
24       where from_item can be one of:
25
26           [ ONLY ] table_name [ * ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
27                       [ TABLESAMPLE sampling_method ( argument [, ...] ) [ REPEATABLE ( seed ) ] ]
28           [ LATERAL ] ( select ) [ AS ] alias [ ( column_alias [, ...] ) ]
29           with_query_name [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
30           [ LATERAL ] function_name ( [ argument [, ...] ] )
31                       [ WITH ORDINALITY ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
32           [ LATERAL ] function_name ( [ argument [, ...] ] ) [ AS ] alias ( column_definition [, ...] )
33           [ LATERAL ] function_name ( [ argument [, ...] ] ) AS ( column_definition [, ...] )
34           [ LATERAL ] ROWS FROM( function_name ( [ argument [, ...] ] ) [ AS ( column_definition [, ...] ) ] [, ...] )
35                       [ WITH ORDINALITY ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
36           from_item [ NATURAL ] join_type from_item [ ON join_condition | USING ( join_column [, ...] ) ]
37
38       and grouping_element can be one of:
39
40           ( )
41           expression
42           ( expression [, ...] )
43           ROLLUP ( { expression | ( expression [, ...] ) } [, ...] )
44           CUBE ( { expression | ( expression [, ...] ) } [, ...] )
45           GROUPING SETS ( grouping_element [, ...] )
46
47       and with_query is:
48
49           with_query_name [ ( column_name [, ...] ) ] AS ( select | values | insert | update | delete )
50
51       TABLE [ ONLY ] table_name [ * ]
52

DESCRIPTION

54       SELECT retrieves rows from zero or more tables. The general processing
55       of SELECT is as follows:
56
57        1. All queries in the WITH list are computed. These effectively serve
58           as temporary tables that can be referenced in the FROM list. A WITH
59           query that is referenced more than once in FROM is computed only
60           once. (See WITH Clause below.)
61
62        2. All elements in the FROM list are computed. (Each element in the
63           FROM list is a real or virtual table.) If more than one element is
64           specified in the FROM list, they are cross-joined together. (See
65           FROM Clause below.)
66
67        3. If the WHERE clause is specified, all rows that do not satisfy the
68           condition are eliminated from the output. (See WHERE Clause below.)
69
70        4. If the GROUP BY clause is specified, or if there are aggregate
71           function calls, the output is combined into groups of rows that
72           match on one or more values, and the results of aggregate functions
73           are computed. If the HAVING clause is present, it eliminates groups
74           that do not satisfy the given condition. (See GROUP BY Clause and
75           HAVING Clause below.)
76
77        5. The actual output rows are computed using the SELECT output
78           expressions for each selected row or row group. (See SELECT List
79           below.)
80
81        6. SELECT DISTINCT eliminates duplicate rows from the result.  SELECT
82           DISTINCT ON eliminates rows that match on all the specified
83           expressions.  SELECT ALL (the default) will return all candidate
84           rows, including duplicates. (See DISTINCT Clause below.)
85
86        7. Using the operators UNION, INTERSECT, and EXCEPT, the output of
87           more than one SELECT statement can be combined to form a single
88           result set. The UNION operator returns all rows that are in one or
89           both of the result sets. The INTERSECT operator returns all rows
90           that are strictly in both result sets. The EXCEPT operator returns
91           the rows that are in the first result set but not in the second. In
92           all three cases, duplicate rows are eliminated unless ALL is
93           specified. The noise word DISTINCT can be added to explicitly
94           specify eliminating duplicate rows. Notice that DISTINCT is the
95           default behavior here, even though ALL is the default for SELECT
96           itself. (See UNION Clause, INTERSECT Clause, and EXCEPT Clause
97           below.)
98
99        8. If the ORDER BY clause is specified, the returned rows are sorted
100           in the specified order. If ORDER BY is not given, the rows are
101           returned in whatever order the system finds fastest to produce.
102           (See ORDER BY Clause below.)
103
104        9. If the LIMIT (or FETCH FIRST) or OFFSET clause is specified, the
105           SELECT statement only returns a subset of the result rows. (See
106           LIMIT Clause below.)
107
108       10. If FOR UPDATE, FOR NO KEY UPDATE, FOR SHARE or FOR KEY SHARE is
109           specified, the SELECT statement locks the selected rows against
110           concurrent updates. (See The Locking Clause below.)
111
112       You must have SELECT privilege on each column used in a SELECT command.
113       The use of FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE or FOR KEY SHARE
114       requires UPDATE privilege as well (for at least one column of each
115       table so selected).
116

PARAMETERS

118   WITH Clause
119       The WITH clause allows you to specify one or more subqueries that can
120       be referenced by name in the primary query. The subqueries effectively
121       act as temporary tables or views for the duration of the primary query.
122       Each subquery can be a SELECT, TABLE, VALUES, INSERT, UPDATE or DELETE
123       statement. When writing a data-modifying statement (INSERT, UPDATE or
124       DELETE) in WITH, it is usual to include a RETURNING clause. It is the
125       output of RETURNING, not the underlying table that the statement
126       modifies, that forms the temporary table that is read by the primary
127       query. If RETURNING is omitted, the statement is still executed, but it
128       produces no output so it cannot be referenced as a table by the primary
129       query.
130
131       A name (without schema qualification) must be specified for each WITH
132       query. Optionally, a list of column names can be specified; if this is
133       omitted, the column names are inferred from the subquery.
134
135       If RECURSIVE is specified, it allows a SELECT subquery to reference
136       itself by name. Such a subquery must have the form
137
138           non_recursive_term UNION [ ALL | DISTINCT ] recursive_term
139
140       where the recursive self-reference must appear on the right-hand side
141       of the UNION. Only one recursive self-reference is permitted per query.
142       Recursive data-modifying statements are not supported, but you can use
143       the results of a recursive SELECT query in a data-modifying statement.
144       See Section 7.8 for an example.
145
146       Another effect of RECURSIVE is that WITH queries need not be ordered: a
147       query can reference another one that is later in the list. (However,
148       circular references, or mutual recursion, are not implemented.) Without
149       RECURSIVE, WITH queries can only reference sibling WITH queries that
150       are earlier in the WITH list.
151
152       A key property of WITH queries is that they are evaluated only once per
153       execution of the primary query, even if the primary query refers to
154       them more than once. In particular, data-modifying statements are
155       guaranteed to be executed once and only once, regardless of whether the
156       primary query reads all or any of their output.
157
158       The primary query and the WITH queries are all (notionally) executed at
159       the same time. This implies that the effects of a data-modifying
160       statement in WITH cannot be seen from other parts of the query, other
161       than by reading its RETURNING output. If two such data-modifying
162       statements attempt to modify the same row, the results are unspecified.
163
164       See Section 7.8 for additional information.
165
166   FROM Clause
167       The FROM clause specifies one or more source tables for the SELECT. If
168       multiple sources are specified, the result is the Cartesian product
169       (cross join) of all the sources. But usually qualification conditions
170       are added (via WHERE) to restrict the returned rows to a small subset
171       of the Cartesian product.
172
173       The FROM clause can contain the following elements:
174
175       table_name
176           The name (optionally schema-qualified) of an existing table or
177           view. If ONLY is specified before the table name, only that table
178           is scanned. If ONLY is not specified, the table and all its
179           descendant tables (if any) are scanned. Optionally, * can be
180           specified after the table name to explicitly indicate that
181           descendant tables are included.
182
183       alias
184           A substitute name for the FROM item containing the alias. An alias
185           is used for brevity or to eliminate ambiguity for self-joins (where
186           the same table is scanned multiple times). When an alias is
187           provided, it completely hides the actual name of the table or
188           function; for example given FROM foo AS f, the remainder of the
189           SELECT must refer to this FROM item as f not foo. If an alias is
190           written, a column alias list can also be written to provide
191           substitute names for one or more columns of the table.
192
193       TABLESAMPLE sampling_method ( argument [, ...] ) [ REPEATABLE ( seed )
194       ]
195           A TABLESAMPLE clause after a table_name indicates that the
196           specified sampling_method should be used to retrieve a subset of
197           the rows in that table. This sampling precedes the application of
198           any other filters such as WHERE clauses. The standard PostgreSQL
199           distribution includes two sampling methods, BERNOULLI and SYSTEM,
200           and other sampling methods can be installed in the database via
201           extensions.
202
203           The BERNOULLI and SYSTEM sampling methods each accept a single
204           argument which is the fraction of the table to sample, expressed as
205           a percentage between 0 and 100. This argument can be any
206           real-valued expression. (Other sampling methods might accept more
207           or different arguments.) These two methods each return a
208           randomly-chosen sample of the table that will contain approximately
209           the specified percentage of the table's rows. The BERNOULLI method
210           scans the whole table and selects or ignores individual rows
211           independently with the specified probability. The SYSTEM method
212           does block-level sampling with each block having the specified
213           chance of being selected; all rows in each selected block are
214           returned. The SYSTEM method is significantly faster than the
215           BERNOULLI method when small sampling percentages are specified, but
216           it may return a less-random sample of the table as a result of
217           clustering effects.
218
219           The optional REPEATABLE clause specifies a seed number or
220           expression to use for generating random numbers within the sampling
221           method. The seed value can be any non-null floating-point value.
222           Two queries that specify the same seed and argument values will
223           select the same sample of the table, if the table has not been
224           changed meanwhile. But different seed values will usually produce
225           different samples. If REPEATABLE is not given then a new random
226           sample is selected for each query, based upon a system-generated
227           seed. Note that some add-on sampling methods do not accept
228           REPEATABLE, and will always produce new samples on each use.
229
230       select
231           A sub-SELECT can appear in the FROM clause. This acts as though its
232           output were created as a temporary table for the duration of this
233           single SELECT command. Note that the sub-SELECT must be surrounded
234           by parentheses, and an alias must be provided for it. A VALUES(7)
235           command can also be used here.
236
237       with_query_name
238           A WITH query is referenced by writing its name, just as though the
239           query's name were a table name. (In fact, the WITH query hides any
240           real table of the same name for the purposes of the primary query.
241           If necessary, you can refer to a real table of the same name by
242           schema-qualifying the table's name.) An alias can be provided in
243           the same way as for a table.
244
245       function_name
246           Function calls can appear in the FROM clause. (This is especially
247           useful for functions that return result sets, but any function can
248           be used.) This acts as though the function's output were created as
249           a temporary table for the duration of this single SELECT command.
250           When the optional WITH ORDINALITY clause is added to the function
251           call, a new column is appended after all the function's output
252           columns with numbering for each row.
253
254           An alias can be provided in the same way as for a table. If an
255           alias is written, a column alias list can also be written to
256           provide substitute names for one or more attributes of the
257           function's composite return type, including the column added by
258           ORDINALITY if present.
259
260           Multiple function calls can be combined into a single FROM-clause
261           item by surrounding them with ROWS FROM( ... ). The output of such
262           an item is the concatenation of the first row from each function,
263           then the second row from each function, etc. If some of the
264           functions produce fewer rows than others, null values are
265           substituted for the missing data, so that the total number of rows
266           returned is always the same as for the function that produced the
267           most rows.
268
269           If the function has been defined as returning the record data type,
270           then an alias or the key word AS must be present, followed by a
271           column definition list in the form ( column_name data_type [, ...
272           ]). The column definition list must match the actual number and
273           types of columns returned by the function.
274
275           When using the ROWS FROM( ... ) syntax, if one of the functions
276           requires a column definition list, it's preferred to put the column
277           definition list after the function call inside ROWS FROM( ... ). A
278           column definition list can be placed after the ROWS FROM( ... )
279           construct only if there's just a single function and no WITH
280           ORDINALITY clause.
281
282           To use ORDINALITY together with a column definition list, you must
283           use the ROWS FROM( ... ) syntax and put the column definition list
284           inside ROWS FROM( ... ).
285
286       join_type
287           One of
288
289           ·   [ INNER ] JOIN
290
291           ·   LEFT [ OUTER ] JOIN
292
293           ·   RIGHT [ OUTER ] JOIN
294
295           ·   FULL [ OUTER ] JOIN
296
297           ·   CROSS JOIN
298
299           For the INNER and OUTER join types, a join condition must be
300           specified, namely exactly one of NATURAL, ON join_condition, or
301           USING (join_column [, ...]). See below for the meaning. For CROSS
302           JOIN, none of these clauses can appear.
303
304           A JOIN clause combines two FROM items, which for convenience we
305           will refer to as “tables”, though in reality they can be any type
306           of FROM item. Use parentheses if necessary to determine the order
307           of nesting. In the absence of parentheses, JOINs nest
308           left-to-right. In any case JOIN binds more tightly than the commas
309           separating FROM-list items.
310
311           CROSS JOIN and INNER JOIN produce a simple Cartesian product, the
312           same result as you get from listing the two tables at the top level
313           of FROM, but restricted by the join condition (if any).  CROSS JOIN
314           is equivalent to INNER JOIN ON (TRUE), that is, no rows are removed
315           by qualification. These join types are just a notational
316           convenience, since they do nothing you couldn't do with plain FROM
317           and WHERE.
318
319           LEFT OUTER JOIN returns all rows in the qualified Cartesian product
320           (i.e., all combined rows that pass its join condition), plus one
321           copy of each row in the left-hand table for which there was no
322           right-hand row that passed the join condition. This left-hand row
323           is extended to the full width of the joined table by inserting null
324           values for the right-hand columns. Note that only the JOIN clause's
325           own condition is considered while deciding which rows have matches.
326           Outer conditions are applied afterwards.
327
328           Conversely, RIGHT OUTER JOIN returns all the joined rows, plus one
329           row for each unmatched right-hand row (extended with nulls on the
330           left). This is just a notational convenience, since you could
331           convert it to a LEFT OUTER JOIN by switching the left and right
332           tables.
333
334           FULL OUTER JOIN returns all the joined rows, plus one row for each
335           unmatched left-hand row (extended with nulls on the right), plus
336           one row for each unmatched right-hand row (extended with nulls on
337           the left).
338
339       ON join_condition
340           join_condition is an expression resulting in a value of type
341           boolean (similar to a WHERE clause) that specifies which rows in a
342           join are considered to match.
343
344       USING ( join_column [, ...] )
345           A clause of the form USING ( a, b, ... ) is shorthand for ON
346           left_table.a = right_table.a AND left_table.b = right_table.b ....
347           Also, USING implies that only one of each pair of equivalent
348           columns will be included in the join output, not both.
349
350       NATURAL
351           NATURAL is shorthand for a USING list that mentions all columns in
352           the two tables that have matching names. If there are no common
353           column names, NATURAL is equivalent to ON TRUE.
354
355       LATERAL
356           The LATERAL key word can precede a sub-SELECT FROM item. This
357           allows the sub-SELECT to refer to columns of FROM items that appear
358           before it in the FROM list. (Without LATERAL, each sub-SELECT is
359           evaluated independently and so cannot cross-reference any other
360           FROM item.)
361
362           LATERAL can also precede a function-call FROM item, but in this
363           case it is a noise word, because the function expression can refer
364           to earlier FROM items in any case.
365
366           A LATERAL item can appear at top level in the FROM list, or within
367           a JOIN tree. In the latter case it can also refer to any items that
368           are on the left-hand side of a JOIN that it is on the right-hand
369           side of.
370
371           When a FROM item contains LATERAL cross-references, evaluation
372           proceeds as follows: for each row of the FROM item providing the
373           cross-referenced column(s), or set of rows of multiple FROM items
374           providing the columns, the LATERAL item is evaluated using that row
375           or row set's values of the columns. The resulting row(s) are joined
376           as usual with the rows they were computed from. This is repeated
377           for each row or set of rows from the column source table(s).
378
379           The column source table(s) must be INNER or LEFT joined to the
380           LATERAL item, else there would not be a well-defined set of rows
381           from which to compute each set of rows for the LATERAL item. Thus,
382           although a construct such as X RIGHT JOIN LATERAL Y is
383           syntactically valid, it is not actually allowed for Y to reference
384           X.
385
386   WHERE Clause
387       The optional WHERE clause has the general form
388
389           WHERE condition
390
391       where condition is any expression that evaluates to a result of type
392       boolean. Any row that does not satisfy this condition will be
393       eliminated from the output. A row satisfies the condition if it returns
394       true when the actual row values are substituted for any variable
395       references.
396
397   GROUP BY Clause
398       The optional GROUP BY clause has the general form
399
400           GROUP BY grouping_element [, ...]
401
402       GROUP BY will condense into a single row all selected rows that share
403       the same values for the grouped expressions. An expression used inside
404       a grouping_element can be an input column name, or the name or ordinal
405       number of an output column (SELECT list item), or an arbitrary
406       expression formed from input-column values. In case of ambiguity, a
407       GROUP BY name will be interpreted as an input-column name rather than
408       an output column name.
409
410       If any of GROUPING SETS, ROLLUP or CUBE are present as grouping
411       elements, then the GROUP BY clause as a whole defines some number of
412       independent grouping sets. The effect of this is equivalent to
413       constructing a UNION ALL between subqueries with the individual
414       grouping sets as their GROUP BY clauses. For further details on the
415       handling of grouping sets see Section 7.2.4.
416
417       Aggregate functions, if any are used, are computed across all rows
418       making up each group, producing a separate value for each group. (If
419       there are aggregate functions but no GROUP BY clause, the query is
420       treated as having a single group comprising all the selected rows.) The
421       set of rows fed to each aggregate function can be further filtered by
422       attaching a FILTER clause to the aggregate function call; see
423       Section 4.2.7 for more information. When a FILTER clause is present,
424       only those rows matching it are included in the input to that aggregate
425       function.
426
427       When GROUP BY is present, or any aggregate functions are present, it is
428       not valid for the SELECT list expressions to refer to ungrouped columns
429       except within aggregate functions or when the ungrouped column is
430       functionally dependent on the grouped columns, since there would
431       otherwise be more than one possible value to return for an ungrouped
432       column. A functional dependency exists if the grouped columns (or a
433       subset thereof) are the primary key of the table containing the
434       ungrouped column.
435
436       Keep in mind that all aggregate functions are evaluated before
437       evaluating any “scalar” expressions in the HAVING clause or SELECT
438       list. This means that, for example, a CASE expression cannot be used to
439       skip evaluation of an aggregate function; see Section 4.2.14.
440
441       Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
442       cannot be specified with GROUP BY.
443
444   HAVING Clause
445       The optional HAVING clause has the general form
446
447           HAVING condition
448
449       where condition is the same as specified for the WHERE clause.
450
451       HAVING eliminates group rows that do not satisfy the condition.  HAVING
452       is different from WHERE: WHERE filters individual rows before the
453       application of GROUP BY, while HAVING filters group rows created by
454       GROUP BY. Each column referenced in condition must unambiguously
455       reference a grouping column, unless the reference appears within an
456       aggregate function or the ungrouped column is functionally dependent on
457       the grouping columns.
458
459       The presence of HAVING turns a query into a grouped query even if there
460       is no GROUP BY clause. This is the same as what happens when the query
461       contains aggregate functions but no GROUP BY clause. All the selected
462       rows are considered to form a single group, and the SELECT list and
463       HAVING clause can only reference table columns from within aggregate
464       functions. Such a query will emit a single row if the HAVING condition
465       is true, zero rows if it is not true.
466
467       Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
468       cannot be specified with HAVING.
469
470   WINDOW Clause
471       The optional WINDOW clause has the general form
472
473           WINDOW window_name AS ( window_definition ) [, ...]
474
475       where window_name is a name that can be referenced from OVER clauses or
476       subsequent window definitions, and window_definition is
477
478           [ existing_window_name ]
479           [ PARTITION BY expression [, ...] ]
480           [ ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...] ]
481           [ frame_clause ]
482
483       If an existing_window_name is specified it must refer to an earlier
484       entry in the WINDOW list; the new window copies its partitioning clause
485       from that entry, as well as its ordering clause if any. In this case
486       the new window cannot specify its own PARTITION BY clause, and it can
487       specify ORDER BY only if the copied window does not have one. The new
488       window always uses its own frame clause; the copied window must not
489       specify a frame clause.
490
491       The elements of the PARTITION BY list are interpreted in much the same
492       fashion as elements of a GROUP BY Clause, except that they are always
493       simple expressions and never the name or number of an output column.
494       Another difference is that these expressions can contain aggregate
495       function calls, which are not allowed in a regular GROUP BY clause.
496       They are allowed here because windowing occurs after grouping and
497       aggregation.
498
499       Similarly, the elements of the ORDER BY list are interpreted in much
500       the same fashion as elements of an ORDER BY Clause, except that the
501       expressions are always taken as simple expressions and never the name
502       or number of an output column.
503
504       The optional frame_clause defines the window frame for window functions
505       that depend on the frame (not all do). The window frame is a set of
506       related rows for each row of the query (called the current row). The
507       frame_clause can be one of
508
509           { RANGE | ROWS } frame_start
510           { RANGE | ROWS } BETWEEN frame_start AND frame_end
511
512       where frame_start and frame_end can be one of
513
514           UNBOUNDED PRECEDING
515           value PRECEDING
516           CURRENT ROW
517           value FOLLOWING
518           UNBOUNDED FOLLOWING
519
520       If frame_end is omitted it defaults to CURRENT ROW. Restrictions are
521       that frame_start cannot be UNBOUNDED FOLLOWING, frame_end cannot be
522       UNBOUNDED PRECEDING, and the frame_end choice cannot appear earlier in
523       the above list than the frame_start choice — for example RANGE BETWEEN
524       CURRENT ROW AND value PRECEDING is not allowed.
525
526       The default framing option is RANGE UNBOUNDED PRECEDING, which is the
527       same as RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW; it sets the
528       frame to be all rows from the partition start up through the current
529       row's last peer (a row that ORDER BY considers equivalent to the
530       current row, or all rows if there is no ORDER BY). In general,
531       UNBOUNDED PRECEDING means that the frame starts with the first row of
532       the partition, and similarly UNBOUNDED FOLLOWING means that the frame
533       ends with the last row of the partition (regardless of RANGE or ROWS
534       mode). In ROWS mode, CURRENT ROW means that the frame starts or ends
535       with the current row; but in RANGE mode it means that the frame starts
536       or ends with the current row's first or last peer in the ORDER BY
537       ordering. The value PRECEDING and value FOLLOWING cases are currently
538       only allowed in ROWS mode. They indicate that the frame starts or ends
539       with the row that many rows before or after the current row.  value
540       must be an integer expression not containing any variables, aggregate
541       functions, or window functions. The value must not be null or negative;
542       but it can be zero, which selects the current row itself.
543
544       Beware that the ROWS options can produce unpredictable results if the
545       ORDER BY ordering does not order the rows uniquely. The RANGE options
546       are designed to ensure that rows that are peers in the ORDER BY
547       ordering are treated alike; all peer rows will be in the same frame.
548
549       The purpose of a WINDOW clause is to specify the behavior of window
550       functions appearing in the query's SELECT List or ORDER BY Clause.
551       These functions can reference the WINDOW clause entries by name in
552       their OVER clauses. A WINDOW clause entry does not have to be
553       referenced anywhere, however; if it is not used in the query it is
554       simply ignored. It is possible to use window functions without any
555       WINDOW clause at all, since a window function call can specify its
556       window definition directly in its OVER clause. However, the WINDOW
557       clause saves typing when the same window definition is needed for more
558       than one window function.
559
560       Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
561       cannot be specified with WINDOW.
562
563       Window functions are described in detail in Section 3.5, Section 4.2.8,
564       and Section 7.2.5.
565
566   SELECT List
567       The SELECT list (between the key words SELECT and FROM) specifies
568       expressions that form the output rows of the SELECT statement. The
569       expressions can (and usually do) refer to columns computed in the FROM
570       clause.
571
572       Just as in a table, every output column of a SELECT has a name. In a
573       simple SELECT this name is just used to label the column for display,
574       but when the SELECT is a sub-query of a larger query, the name is seen
575       by the larger query as the column name of the virtual table produced by
576       the sub-query. To specify the name to use for an output column, write
577       AS output_name after the column's expression. (You can omit AS, but
578       only if the desired output name does not match any PostgreSQL keyword
579       (see Appendix C). For protection against possible future keyword
580       additions, it is recommended that you always either write AS or
581       double-quote the output name.) If you do not specify a column name, a
582       name is chosen automatically by PostgreSQL. If the column's expression
583       is a simple column reference then the chosen name is the same as that
584       column's name. In more complex cases a function or type name may be
585       used, or the system may fall back on a generated name such as ?column?.
586
587       An output column's name can be used to refer to the column's value in
588       ORDER BY and GROUP BY clauses, but not in the WHERE or HAVING clauses;
589       there you must write out the expression instead.
590
591       Instead of an expression, * can be written in the output list as a
592       shorthand for all the columns of the selected rows. Also, you can write
593       table_name.*  as a shorthand for the columns coming from just that
594       table. In these cases it is not possible to specify new names with AS;
595       the output column names will be the same as the table columns' names.
596
597       According to the SQL standard, the expressions in the output list
598       should be computed before applying DISTINCT, ORDER BY, or LIMIT. This
599       is obviously necessary when using DISTINCT, since otherwise it's not
600       clear what values are being made distinct. However, in many cases it is
601       convenient if output expressions are computed after ORDER BY and LIMIT;
602       particularly if the output list contains any volatile or expensive
603       functions. With that behavior, the order of function evaluations is
604       more intuitive and there will not be evaluations corresponding to rows
605       that never appear in the output.  PostgreSQL will effectively evaluate
606       output expressions after sorting and limiting, so long as those
607       expressions are not referenced in DISTINCT, ORDER BY or GROUP BY. (As a
608       counterexample, SELECT f(x) FROM tab ORDER BY 1 clearly must evaluate
609       f(x) before sorting.) Output expressions that contain set-returning
610       functions are effectively evaluated after sorting and before limiting,
611       so that LIMIT will act to cut off the output from a set-returning
612       function.
613
614           Note
615           PostgreSQL versions before 9.6 did not provide any guarantees about
616           the timing of evaluation of output expressions versus sorting and
617           limiting; it depended on the form of the chosen query plan.
618
619   DISTINCT Clause
620       If SELECT DISTINCT is specified, all duplicate rows are removed from
621       the result set (one row is kept from each group of duplicates).  SELECT
622       ALL specifies the opposite: all rows are kept; that is the default.
623
624       SELECT DISTINCT ON ( expression [, ...] ) keeps only the first row of
625       each set of rows where the given expressions evaluate to equal. The
626       DISTINCT ON expressions are interpreted using the same rules as for
627       ORDER BY (see above). Note that the “first row” of each set is
628       unpredictable unless ORDER BY is used to ensure that the desired row
629       appears first. For example:
630
631           SELECT DISTINCT ON (location) location, time, report
632               FROM weather_reports
633               ORDER BY location, time DESC;
634
635       retrieves the most recent weather report for each location. But if we
636       had not used ORDER BY to force descending order of time values for each
637       location, we'd have gotten a report from an unpredictable time for each
638       location.
639
640       The DISTINCT ON expression(s) must match the leftmost ORDER BY
641       expression(s). The ORDER BY clause will normally contain additional
642       expression(s) that determine the desired precedence of rows within each
643       DISTINCT ON group.
644
645       Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
646       cannot be specified with DISTINCT.
647
648   UNION Clause
649       The UNION clause has this general form:
650
651           select_statement UNION [ ALL | DISTINCT ] select_statement
652
653       select_statement is any SELECT statement without an ORDER BY, LIMIT,
654       FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE, or FOR KEY SHARE clause.
655       (ORDER BY and LIMIT can be attached to a subexpression if it is
656       enclosed in parentheses. Without parentheses, these clauses will be
657       taken to apply to the result of the UNION, not to its right-hand input
658       expression.)
659
660       The UNION operator computes the set union of the rows returned by the
661       involved SELECT statements. A row is in the set union of two result
662       sets if it appears in at least one of the result sets. The two SELECT
663       statements that represent the direct operands of the UNION must produce
664       the same number of columns, and corresponding columns must be of
665       compatible data types.
666
667       The result of UNION does not contain any duplicate rows unless the ALL
668       option is specified.  ALL prevents elimination of duplicates.
669       (Therefore, UNION ALL is usually significantly quicker than UNION; use
670       ALL when you can.)  DISTINCT can be written to explicitly specify the
671       default behavior of eliminating duplicate rows.
672
673       Multiple UNION operators in the same SELECT statement are evaluated
674       left to right, unless otherwise indicated by parentheses.
675
676       Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
677       cannot be specified either for a UNION result or for any input of a
678       UNION.
679
680   INTERSECT Clause
681       The INTERSECT clause has this general form:
682
683           select_statement INTERSECT [ ALL | DISTINCT ] select_statement
684
685       select_statement is any SELECT statement without an ORDER BY, LIMIT,
686       FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE, or FOR KEY SHARE clause.
687
688       The INTERSECT operator computes the set intersection of the rows
689       returned by the involved SELECT statements. A row is in the
690       intersection of two result sets if it appears in both result sets.
691
692       The result of INTERSECT does not contain any duplicate rows unless the
693       ALL option is specified. With ALL, a row that has m duplicates in the
694       left table and n duplicates in the right table will appear min(m,n)
695       times in the result set.  DISTINCT can be written to explicitly specify
696       the default behavior of eliminating duplicate rows.
697
698       Multiple INTERSECT operators in the same SELECT statement are evaluated
699       left to right, unless parentheses dictate otherwise.  INTERSECT binds
700       more tightly than UNION. That is, A UNION B INTERSECT C will be read as
701       A UNION (B INTERSECT C).
702
703       Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
704       cannot be specified either for an INTERSECT result or for any input of
705       an INTERSECT.
706
707   EXCEPT Clause
708       The EXCEPT clause has this general form:
709
710           select_statement EXCEPT [ ALL | DISTINCT ] select_statement
711
712       select_statement is any SELECT statement without an ORDER BY, LIMIT,
713       FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE, or FOR KEY SHARE clause.
714
715       The EXCEPT operator computes the set of rows that are in the result of
716       the left SELECT statement but not in the result of the right one.
717
718       The result of EXCEPT does not contain any duplicate rows unless the ALL
719       option is specified. With ALL, a row that has m duplicates in the left
720       table and n duplicates in the right table will appear max(m-n,0) times
721       in the result set.  DISTINCT can be written to explicitly specify the
722       default behavior of eliminating duplicate rows.
723
724       Multiple EXCEPT operators in the same SELECT statement are evaluated
725       left to right, unless parentheses dictate otherwise.  EXCEPT binds at
726       the same level as UNION.
727
728       Currently, FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE and FOR KEY SHARE
729       cannot be specified either for an EXCEPT result or for any input of an
730       EXCEPT.
731
732   ORDER BY Clause
733       The optional ORDER BY clause has this general form:
734
735           ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...]
736
737       The ORDER BY clause causes the result rows to be sorted according to
738       the specified expression(s). If two rows are equal according to the
739       leftmost expression, they are compared according to the next expression
740       and so on. If they are equal according to all specified expressions,
741       they are returned in an implementation-dependent order.
742
743       Each expression can be the name or ordinal number of an output column
744       (SELECT list item), or it can be an arbitrary expression formed from
745       input-column values.
746
747       The ordinal number refers to the ordinal (left-to-right) position of
748       the output column. This feature makes it possible to define an ordering
749       on the basis of a column that does not have a unique name. This is
750       never absolutely necessary because it is always possible to assign a
751       name to an output column using the AS clause.
752
753       It is also possible to use arbitrary expressions in the ORDER BY
754       clause, including columns that do not appear in the SELECT output list.
755       Thus the following statement is valid:
756
757           SELECT name FROM distributors ORDER BY code;
758
759       A limitation of this feature is that an ORDER BY clause applying to the
760       result of a UNION, INTERSECT, or EXCEPT clause can only specify an
761       output column name or number, not an expression.
762
763       If an ORDER BY expression is a simple name that matches both an output
764       column name and an input column name, ORDER BY will interpret it as the
765       output column name. This is the opposite of the choice that GROUP BY
766       will make in the same situation. This inconsistency is made to be
767       compatible with the SQL standard.
768
769       Optionally one can add the key word ASC (ascending) or DESC
770       (descending) after any expression in the ORDER BY clause. If not
771       specified, ASC is assumed by default. Alternatively, a specific
772       ordering operator name can be specified in the USING clause. An
773       ordering operator must be a less-than or greater-than member of some
774       B-tree operator family.  ASC is usually equivalent to USING < and DESC
775       is usually equivalent to USING >. (But the creator of a user-defined
776       data type can define exactly what the default sort ordering is, and it
777       might correspond to operators with other names.)
778
779       If NULLS LAST is specified, null values sort after all non-null values;
780       if NULLS FIRST is specified, null values sort before all non-null
781       values. If neither is specified, the default behavior is NULLS LAST
782       when ASC is specified or implied, and NULLS FIRST when DESC is
783       specified (thus, the default is to act as though nulls are larger than
784       non-nulls). When USING is specified, the default nulls ordering depends
785       on whether the operator is a less-than or greater-than operator.
786
787       Note that ordering options apply only to the expression they follow;
788       for example ORDER BY x, y DESC does not mean the same thing as ORDER BY
789       x DESC, y DESC.
790
791       Character-string data is sorted according to the collation that applies
792       to the column being sorted. That can be overridden at need by including
793       a COLLATE clause in the expression, for example ORDER BY mycolumn
794       COLLATE "en_US". For more information see Section 4.2.10 and
795       Section 23.2.
796
797   LIMIT Clause
798       The LIMIT clause consists of two independent sub-clauses:
799
800           LIMIT { count | ALL }
801           OFFSET start
802
803
804       count specifies the maximum number of rows to return, while start
805       specifies the number of rows to skip before starting to return rows.
806       When both are specified, start rows are skipped before starting to
807       count the count rows to be returned.
808
809       If the count expression evaluates to NULL, it is treated as LIMIT ALL,
810       i.e., no limit. If start evaluates to NULL, it is treated the same as
811       OFFSET 0.
812
813       SQL:2008 introduced a different syntax to achieve the same result,
814       which PostgreSQL also supports. It is:
815
816           OFFSET start { ROW | ROWS }
817           FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } ONLY
818
819       In this syntax, the start or count value is required by the standard to
820       be a literal constant, a parameter, or a variable name; as a PostgreSQL
821       extension, other expressions are allowed, but will generally need to be
822       enclosed in parentheses to avoid ambiguity. If count is omitted in a
823       FETCH clause, it defaults to 1.  ROW and ROWS as well as FIRST and NEXT
824       are noise words that don't influence the effects of these clauses.
825       According to the standard, the OFFSET clause must come before the FETCH
826       clause if both are present; but PostgreSQL is laxer and allows either
827       order.
828
829       When using LIMIT, it is a good idea to use an ORDER BY clause that
830       constrains the result rows into a unique order. Otherwise you will get
831       an unpredictable subset of the query's rows — you might be asking for
832       the tenth through twentieth rows, but tenth through twentieth in what
833       ordering? You don't know what ordering unless you specify ORDER BY.
834
835       The query planner takes LIMIT into account when generating a query
836       plan, so you are very likely to get different plans (yielding different
837       row orders) depending on what you use for LIMIT and OFFSET. Thus, using
838       different LIMIT/OFFSET values to select different subsets of a query
839       result will give inconsistent results unless you enforce a predictable
840       result ordering with ORDER BY. This is not a bug; it is an inherent
841       consequence of the fact that SQL does not promise to deliver the
842       results of a query in any particular order unless ORDER BY is used to
843       constrain the order.
844
845       It is even possible for repeated executions of the same LIMIT query to
846       return different subsets of the rows of a table, if there is not an
847       ORDER BY to enforce selection of a deterministic subset. Again, this is
848       not a bug; determinism of the results is simply not guaranteed in such
849       a case.
850
851   The Locking Clause
852       FOR UPDATE, FOR NO KEY UPDATE, FOR SHARE and FOR KEY SHARE are locking
853       clauses; they affect how SELECT locks rows as they are obtained from
854       the table.
855
856       The locking clause has the general form
857
858           FOR lock_strength [ OF table_name [, ...] ] [ NOWAIT | SKIP LOCKED ]
859
860       where lock_strength can be one of
861
862           UPDATE
863           NO KEY UPDATE
864           SHARE
865           KEY SHARE
866
867       For more information on each row-level lock mode, refer to
868       Section 13.3.2.
869
870       To prevent the operation from waiting for other transactions to commit,
871       use either the NOWAIT or SKIP LOCKED option. With NOWAIT, the statement
872       reports an error, rather than waiting, if a selected row cannot be
873       locked immediately. With SKIP LOCKED, any selected rows that cannot be
874       immediately locked are skipped. Skipping locked rows provides an
875       inconsistent view of the data, so this is not suitable for general
876       purpose work, but can be used to avoid lock contention with multiple
877       consumers accessing a queue-like table. Note that NOWAIT and SKIP
878       LOCKED apply only to the row-level lock(s) — the required ROW SHARE
879       table-level lock is still taken in the ordinary way (see Chapter 13).
880       You can use LOCK(7) with the NOWAIT option first, if you need to
881       acquire the table-level lock without waiting.
882
883       If specific tables are named in a locking clause, then only rows coming
884       from those tables are locked; any other tables used in the SELECT are
885       simply read as usual. A locking clause without a table list affects all
886       tables used in the statement. If a locking clause is applied to a view
887       or sub-query, it affects all tables used in the view or sub-query.
888       However, these clauses do not apply to WITH queries referenced by the
889       primary query. If you want row locking to occur within a WITH query,
890       specify a locking clause within the WITH query.
891
892       Multiple locking clauses can be written if it is necessary to specify
893       different locking behavior for different tables. If the same table is
894       mentioned (or implicitly affected) by more than one locking clause,
895       then it is processed as if it was only specified by the strongest one.
896       Similarly, a table is processed as NOWAIT if that is specified in any
897       of the clauses affecting it. Otherwise, it is processed as SKIP LOCKED
898       if that is specified in any of the clauses affecting it.
899
900       The locking clauses cannot be used in contexts where returned rows
901       cannot be clearly identified with individual table rows; for example
902       they cannot be used with aggregation.
903
904       When a locking clause appears at the top level of a SELECT query, the
905       rows that are locked are exactly those that are returned by the query;
906       in the case of a join query, the rows locked are those that contribute
907       to returned join rows. In addition, rows that satisfied the query
908       conditions as of the query snapshot will be locked, although they will
909       not be returned if they were updated after the snapshot and no longer
910       satisfy the query conditions. If a LIMIT is used, locking stops once
911       enough rows have been returned to satisfy the limit (but note that rows
912       skipped over by OFFSET will get locked). Similarly, if a locking clause
913       is used in a cursor's query, only rows actually fetched or stepped past
914       by the cursor will be locked.
915
916       When a locking clause appears in a sub-SELECT, the rows locked are
917       those returned to the outer query by the sub-query. This might involve
918       fewer rows than inspection of the sub-query alone would suggest, since
919       conditions from the outer query might be used to optimize execution of
920       the sub-query. For example,
921
922           SELECT * FROM (SELECT * FROM mytable FOR UPDATE) ss WHERE col1 = 5;
923
924       will lock only rows having col1 = 5, even though that condition is not
925       textually within the sub-query.
926
927       Previous releases failed to preserve a lock which is upgraded by a
928       later savepoint. For example, this code:
929
930           BEGIN;
931           SELECT * FROM mytable WHERE key = 1 FOR UPDATE;
932           SAVEPOINT s;
933           UPDATE mytable SET ... WHERE key = 1;
934           ROLLBACK TO s;
935
936       would fail to preserve the FOR UPDATE lock after the ROLLBACK TO. This
937       has been fixed in release 9.3.
938
939           Caution
940           It is possible for a SELECT command running at the READ COMMITTED
941           transaction isolation level and using ORDER BY and a locking clause
942           to return rows out of order. This is because ORDER BY is applied
943           first. The command sorts the result, but might then block trying to
944           obtain a lock on one or more of the rows. Once the SELECT unblocks,
945           some of the ordering column values might have been modified,
946           leading to those rows appearing to be out of order (though they are
947           in order in terms of the original column values). This can be
948           worked around at need by placing the FOR UPDATE/SHARE clause in a
949           sub-query, for example
950
951               SELECT * FROM (SELECT * FROM mytable FOR UPDATE) ss ORDER BY column1;
952
953           Note that this will result in locking all rows of mytable, whereas
954           FOR UPDATE at the top level would lock only the actually returned
955           rows. This can make for a significant performance difference,
956           particularly if the ORDER BY is combined with LIMIT or other
957           restrictions. So this technique is recommended only if concurrent
958           updates of the ordering columns are expected and a strictly sorted
959           result is required.
960
961           At the REPEATABLE READ or SERIALIZABLE transaction isolation level
962           this would cause a serialization failure (with a SQLSTATE of
963           '40001'), so there is no possibility of receiving rows out of order
964           under these isolation levels.
965
966   TABLE Command
967       The command
968
969           TABLE name
970
971       is equivalent to
972
973           SELECT * FROM name
974
975       It can be used as a top-level command or as a space-saving syntax
976       variant in parts of complex queries. Only the WITH, UNION, INTERSECT,
977       EXCEPT, ORDER BY, LIMIT, OFFSET, FETCH and FOR locking clauses can be
978       used with TABLE; the WHERE clause and any form of aggregation cannot be
979       used.
980

EXAMPLES

982       To join the table films with the table distributors:
983
984           SELECT f.title, f.did, d.name, f.date_prod, f.kind
985               FROM distributors d, films f
986               WHERE f.did = d.did
987
988                  title       | did |     name     | date_prod  |   kind
989           -------------------+-----+--------------+------------+----------
990            The Third Man     | 101 | British Lion | 1949-12-23 | Drama
991            The African Queen | 101 | British Lion | 1951-08-11 | Romantic
992            ...
993
994       To sum the column len of all films and group the results by kind:
995
996           SELECT kind, sum(len) AS total FROM films GROUP BY kind;
997
998              kind   | total
999           ----------+-------
1000            Action   | 07:34
1001            Comedy   | 02:58
1002            Drama    | 14:28
1003            Musical  | 06:42
1004            Romantic | 04:38
1005
1006       To sum the column len of all films, group the results by kind and show
1007       those group totals that are less than 5 hours:
1008
1009           SELECT kind, sum(len) AS total
1010               FROM films
1011               GROUP BY kind
1012               HAVING sum(len) < interval '5 hours';
1013
1014              kind   | total
1015           ----------+-------
1016            Comedy   | 02:58
1017            Romantic | 04:38
1018
1019       The following two examples are identical ways of sorting the individual
1020       results according to the contents of the second column (name):
1021
1022           SELECT * FROM distributors ORDER BY name;
1023           SELECT * FROM distributors ORDER BY 2;
1024
1025            did |       name
1026           -----+------------------
1027            109 | 20th Century Fox
1028            110 | Bavaria Atelier
1029            101 | British Lion
1030            107 | Columbia
1031            102 | Jean Luc Godard
1032            113 | Luso films
1033            104 | Mosfilm
1034            103 | Paramount
1035            106 | Toho
1036            105 | United Artists
1037            111 | Walt Disney
1038            112 | Warner Bros.
1039            108 | Westward
1040
1041       The next example shows how to obtain the union of the tables
1042       distributors and actors, restricting the results to those that begin
1043       with the letter W in each table. Only distinct rows are wanted, so the
1044       key word ALL is omitted.
1045
1046           distributors:               actors:
1047            did |     name              id |     name
1048           -----+--------------        ----+----------------
1049            108 | Westward               1 | Woody Allen
1050            111 | Walt Disney            2 | Warren Beatty
1051            112 | Warner Bros.           3 | Walter Matthau
1052            ...                         ...
1053
1054           SELECT distributors.name
1055               FROM distributors
1056               WHERE distributors.name LIKE 'W%'
1057           UNION
1058           SELECT actors.name
1059               FROM actors
1060               WHERE actors.name LIKE 'W%';
1061
1062                 name
1063           ----------------
1064            Walt Disney
1065            Walter Matthau
1066            Warner Bros.
1067            Warren Beatty
1068            Westward
1069            Woody Allen
1070
1071       This example shows how to use a function in the FROM clause, both with
1072       and without a column definition list:
1073
1074           CREATE FUNCTION distributors(int) RETURNS SETOF distributors AS $$
1075               SELECT * FROM distributors WHERE did = $1;
1076           $$ LANGUAGE SQL;
1077
1078           SELECT * FROM distributors(111);
1079            did |    name
1080           -----+-------------
1081            111 | Walt Disney
1082
1083           CREATE FUNCTION distributors_2(int) RETURNS SETOF record AS $$
1084               SELECT * FROM distributors WHERE did = $1;
1085           $$ LANGUAGE SQL;
1086
1087           SELECT * FROM distributors_2(111) AS (f1 int, f2 text);
1088            f1  |     f2
1089           -----+-------------
1090            111 | Walt Disney
1091
1092       Here is an example of a function with an ordinality column added:
1093
1094           SELECT * FROM unnest(ARRAY['a','b','c','d','e','f']) WITH ORDINALITY;
1095            unnest | ordinality
1096           --------+----------
1097            a      |        1
1098            b      |        2
1099            c      |        3
1100            d      |        4
1101            e      |        5
1102            f      |        6
1103           (6 rows)
1104
1105       This example shows how to use a simple WITH clause:
1106
1107           WITH t AS (
1108               SELECT random() as x FROM generate_series(1, 3)
1109             )
1110           SELECT * FROM t
1111           UNION ALL
1112           SELECT * FROM t
1113
1114                    x
1115           --------------------
1116             0.534150459803641
1117             0.520092216785997
1118            0.0735620250925422
1119             0.534150459803641
1120             0.520092216785997
1121            0.0735620250925422
1122
1123       Notice that the WITH query was evaluated only once, so that we got two
1124       sets of the same three random values.
1125
1126       This example uses WITH RECURSIVE to find all subordinates (direct or
1127       indirect) of the employee Mary, and their level of indirectness, from a
1128       table that shows only direct subordinates:
1129
1130           WITH RECURSIVE employee_recursive(distance, employee_name, manager_name) AS (
1131               SELECT 1, employee_name, manager_name
1132               FROM employee
1133               WHERE manager_name = 'Mary'
1134             UNION ALL
1135               SELECT er.distance + 1, e.employee_name, e.manager_name
1136               FROM employee_recursive er, employee e
1137               WHERE er.employee_name = e.manager_name
1138             )
1139           SELECT distance, employee_name FROM employee_recursive;
1140
1141       Notice the typical form of recursive queries: an initial condition,
1142       followed by UNION, followed by the recursive part of the query. Be sure
1143       that the recursive part of the query will eventually return no tuples,
1144       or else the query will loop indefinitely. (See Section 7.8 for more
1145       examples.)
1146
1147       This example uses LATERAL to apply a set-returning function
1148       get_product_names() for each row of the manufacturers table:
1149
1150           SELECT m.name AS mname, pname
1151           FROM manufacturers m, LATERAL get_product_names(m.id) pname;
1152
1153       Manufacturers not currently having any products would not appear in the
1154       result, since it is an inner join. If we wished to include the names of
1155       such manufacturers in the result, we could do:
1156
1157           SELECT m.name AS mname, pname
1158           FROM manufacturers m LEFT JOIN LATERAL get_product_names(m.id) pname ON true;
1159

COMPATIBILITY

1161       Of course, the SELECT statement is compatible with the SQL standard.
1162       But there are some extensions and some missing features.
1163
1164   Omitted FROM Clauses
1165       PostgreSQL allows one to omit the FROM clause. It has a straightforward
1166       use to compute the results of simple expressions:
1167
1168           SELECT 2+2;
1169
1170            ?column?
1171           ----------
1172                   4
1173
1174       Some other SQL databases cannot do this except by introducing a dummy
1175       one-row table from which to do the SELECT.
1176
1177       Note that if a FROM clause is not specified, the query cannot reference
1178       any database tables. For example, the following query is invalid:
1179
1180           SELECT distributors.* WHERE distributors.name = 'Westward';
1181
1182
1183       PostgreSQL releases prior to 8.1 would accept queries of this form, and
1184       add an implicit entry to the query's FROM clause for each table
1185       referenced by the query. This is no longer allowed.
1186
1187   Empty SELECT Lists
1188       The list of output expressions after SELECT can be empty, producing a
1189       zero-column result table. This is not valid syntax according to the SQL
1190       standard.  PostgreSQL allows it to be consistent with allowing
1191       zero-column tables. However, an empty list is not allowed when DISTINCT
1192       is used.
1193
1194   Omitting the AS Key Word
1195       In the SQL standard, the optional key word AS can be omitted before an
1196       output column name whenever the new column name is a valid column name
1197       (that is, not the same as any reserved keyword).  PostgreSQL is
1198       slightly more restrictive: AS is required if the new column name
1199       matches any keyword at all, reserved or not. Recommended practice is to
1200       use AS or double-quote output column names, to prevent any possible
1201       conflict against future keyword additions.
1202
1203       In FROM items, both the standard and PostgreSQL allow AS to be omitted
1204       before an alias that is an unreserved keyword. But this is impractical
1205       for output column names, because of syntactic ambiguities.
1206
1207   ONLY and Inheritance
1208       The SQL standard requires parentheses around the table name when
1209       writing ONLY, for example SELECT * FROM ONLY (tab1), ONLY (tab2) WHERE
1210       ....  PostgreSQL considers these parentheses to be optional.
1211
1212       PostgreSQL allows a trailing * to be written to explicitly specify the
1213       non-ONLY behavior of including child tables. The standard does not
1214       allow this.
1215
1216       (These points apply equally to all SQL commands supporting the ONLY
1217       option.)
1218
1219   TABLESAMPLE Clause Restrictions
1220       The TABLESAMPLE clause is currently accepted only on regular tables and
1221       materialized views. According to the SQL standard it should be possible
1222       to apply it to any FROM item.
1223
1224   Function Calls in FROM
1225       PostgreSQL allows a function call to be written directly as a member of
1226       the FROM list. In the SQL standard it would be necessary to wrap such a
1227       function call in a sub-SELECT; that is, the syntax FROM func(...) alias
1228       is approximately equivalent to FROM LATERAL (SELECT func(...)) alias.
1229       Note that LATERAL is considered to be implicit; this is because the
1230       standard requires LATERAL semantics for an UNNEST() item in FROM.
1231       PostgreSQL treats UNNEST() the same as other set-returning functions.
1232
1233   Namespace Available to GROUP BY and ORDER BY
1234       In the SQL-92 standard, an ORDER BY clause can only use output column
1235       names or numbers, while a GROUP BY clause can only use expressions
1236       based on input column names.  PostgreSQL extends each of these clauses
1237       to allow the other choice as well (but it uses the standard's
1238       interpretation if there is ambiguity).  PostgreSQL also allows both
1239       clauses to specify arbitrary expressions. Note that names appearing in
1240       an expression will always be taken as input-column names, not as
1241       output-column names.
1242
1243       SQL:1999 and later use a slightly different definition which is not
1244       entirely upward compatible with SQL-92. In most cases, however,
1245       PostgreSQL will interpret an ORDER BY or GROUP BY expression the same
1246       way SQL:1999 does.
1247
1248   Functional Dependencies
1249       PostgreSQL recognizes functional dependency (allowing columns to be
1250       omitted from GROUP BY) only when a table's primary key is included in
1251       the GROUP BY list. The SQL standard specifies additional conditions
1252       that should be recognized.
1253
1254   WINDOW Clause Restrictions
1255       The SQL standard provides additional options for the window
1256       frame_clause.  PostgreSQL currently supports only the options listed
1257       above.
1258
1259   LIMIT and OFFSET
1260       The clauses LIMIT and OFFSET are PostgreSQL-specific syntax, also used
1261       by MySQL. The SQL:2008 standard has introduced the clauses OFFSET ...
1262       FETCH {FIRST|NEXT} ...  for the same functionality, as shown above in
1263       LIMIT Clause. This syntax is also used by IBM DB2. (Applications
1264       written for Oracle frequently use a workaround involving the
1265       automatically generated rownum column, which is not available in
1266       PostgreSQL, to implement the effects of these clauses.)
1267
1268   FOR NO KEY UPDATE, FOR UPDATE, FOR SHARE, FOR KEY SHARE
1269       Although FOR UPDATE appears in the SQL standard, the standard allows it
1270       only as an option of DECLARE CURSOR.  PostgreSQL allows it in any
1271       SELECT query as well as in sub-SELECTs, but this is an extension. The
1272       FOR NO KEY UPDATE, FOR SHARE and FOR KEY SHARE variants, as well as the
1273       NOWAIT and SKIP LOCKED options, do not appear in the standard.
1274
1275   Data-Modifying Statements in WITH
1276       PostgreSQL allows INSERT, UPDATE, and DELETE to be used as WITH
1277       queries. This is not found in the SQL standard.
1278
1279   Nonstandard Clauses
1280       DISTINCT ON ( ... ) is an extension of the SQL standard.
1281
1282       ROWS FROM( ... ) is an extension of the SQL standard.
1283
1284
1285
1286PostgreSQL 10.7                      2019                            SELECT(7)
Impressum