1<!--
2doc/src/sgml/ref/select.sgml
3PostgreSQL documentation
4-->
5
6<refentry id="sql-select">
7 <indexterm zone="sql-select">
8  <primary>SELECT</primary>
9 </indexterm>
10
11 <indexterm zone="sql-select">
12  <primary>TABLE command</primary>
13 </indexterm>
14
15 <indexterm zone="sql-select">
16  <primary>WITH</primary>
17  <secondary>in SELECT</secondary>
18 </indexterm>
19
20 <refmeta>
21  <refentrytitle>SELECT</refentrytitle>
22  <manvolnum>7</manvolnum>
23  <refmiscinfo>SQL - Language Statements</refmiscinfo>
24 </refmeta>
25
26 <refnamediv>
27  <refname>SELECT</refname>
28  <refname>TABLE</refname>
29  <refname>WITH</refname>
30  <refpurpose>retrieve rows from a table or view</refpurpose>
31 </refnamediv>
32
33 <refsynopsisdiv>
34<synopsis>
35[ WITH [ RECURSIVE ] <replaceable class="parameter">with_query</replaceable> [, ...] ]
36SELECT [ ALL | DISTINCT [ ON ( <replaceable class="parameter">expression</replaceable> [, ...] ) ] ]
37    [ * | <replaceable class="parameter">expression</replaceable> [ [ AS ] <replaceable class="parameter">output_name</replaceable> ] [, ...] ]
38    [ FROM <replaceable class="parameter">from_item</replaceable> [, ...] ]
39    [ WHERE <replaceable class="parameter">condition</replaceable> ]
40    [ GROUP BY <replaceable class="parameter">grouping_element</replaceable> [, ...] ]
41    [ HAVING <replaceable class="parameter">condition</replaceable> ]
42    [ WINDOW <replaceable class="parameter">window_name</replaceable> AS ( <replaceable class="parameter">window_definition</replaceable> ) [, ...] ]
43    [ { UNION | INTERSECT | EXCEPT } [ ALL | DISTINCT ] <replaceable class="parameter">select</replaceable> ]
44    [ ORDER BY <replaceable class="parameter">expression</replaceable> [ ASC | DESC | USING <replaceable class="parameter">operator</replaceable> ] [ NULLS { FIRST | LAST } ] [, ...] ]
45    [ LIMIT { <replaceable class="parameter">count</replaceable> | ALL } ]
46    [ OFFSET <replaceable class="parameter">start</replaceable> [ ROW | ROWS ] ]
47    [ FETCH { FIRST | NEXT } [ <replaceable class="parameter">count</replaceable> ] { ROW | ROWS } { ONLY | WITH TIES } ]
48    [ FOR { UPDATE | NO KEY UPDATE | SHARE | KEY SHARE } [ OF <replaceable class="parameter">table_name</replaceable> [, ...] ] [ NOWAIT | SKIP LOCKED ] [...] ]
49
50<phrase>where <replaceable class="parameter">from_item</replaceable> can be one of:</phrase>
51
52    [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ] [ [ AS ] <replaceable class="parameter">alias</replaceable> [ ( <replaceable class="parameter">column_alias</replaceable> [, ...] ) ] ]
53                [ TABLESAMPLE <replaceable class="parameter">sampling_method</replaceable> ( <replaceable class="parameter">argument</replaceable> [, ...] ) [ REPEATABLE ( <replaceable class="parameter">seed</replaceable> ) ] ]
54    [ LATERAL ] ( <replaceable class="parameter">select</replaceable> ) [ AS ] <replaceable class="parameter">alias</replaceable> [ ( <replaceable class="parameter">column_alias</replaceable> [, ...] ) ]
55    <replaceable class="parameter">with_query_name</replaceable> [ [ AS ] <replaceable class="parameter">alias</replaceable> [ ( <replaceable class="parameter">column_alias</replaceable> [, ...] ) ] ]
56    [ LATERAL ] <replaceable class="parameter">function_name</replaceable> ( [ <replaceable class="parameter">argument</replaceable> [, ...] ] )
57                [ WITH ORDINALITY ] [ [ AS ] <replaceable class="parameter">alias</replaceable> [ ( <replaceable class="parameter">column_alias</replaceable> [, ...] ) ] ]
58    [ LATERAL ] <replaceable class="parameter">function_name</replaceable> ( [ <replaceable class="parameter">argument</replaceable> [, ...] ] ) [ AS ] <replaceable class="parameter">alias</replaceable> ( <replaceable class="parameter">column_definition</replaceable> [, ...] )
59    [ LATERAL ] <replaceable class="parameter">function_name</replaceable> ( [ <replaceable class="parameter">argument</replaceable> [, ...] ] ) AS ( <replaceable class="parameter">column_definition</replaceable> [, ...] )
60    [ LATERAL ] ROWS FROM( <replaceable class="parameter">function_name</replaceable> ( [ <replaceable class="parameter">argument</replaceable> [, ...] ] ) [ AS ( <replaceable class="parameter">column_definition</replaceable> [, ...] ) ] [, ...] )
61                [ WITH ORDINALITY ] [ [ AS ] <replaceable class="parameter">alias</replaceable> [ ( <replaceable class="parameter">column_alias</replaceable> [, ...] ) ] ]
62    <replaceable class="parameter">from_item</replaceable> [ NATURAL ] <replaceable class="parameter">join_type</replaceable> <replaceable class="parameter">from_item</replaceable> [ ON <replaceable class="parameter">join_condition</replaceable> | USING ( <replaceable class="parameter">join_column</replaceable> [, ...] ) ]
63
64<phrase>and <replaceable class="parameter">grouping_element</replaceable> can be one of:</phrase>
65
66    ( )
67    <replaceable class="parameter">expression</replaceable>
68    ( <replaceable class="parameter">expression</replaceable> [, ...] )
69    ROLLUP ( { <replaceable class="parameter">expression</replaceable> | ( <replaceable class="parameter">expression</replaceable> [, ...] ) } [, ...] )
70    CUBE ( { <replaceable class="parameter">expression</replaceable> | ( <replaceable class="parameter">expression</replaceable> [, ...] ) } [, ...] )
71    GROUPING SETS ( <replaceable class="parameter">grouping_element</replaceable> [, ...] )
72
73<phrase>and <replaceable class="parameter">with_query</replaceable> is:</phrase>
74
75    <replaceable class="parameter">with_query_name</replaceable> [ ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ] AS [ [ NOT ] MATERIALIZED ] ( <replaceable class="parameter">select</replaceable> | <replaceable class="parameter">values</replaceable> | <replaceable class="parameter">insert</replaceable> | <replaceable class="parameter">update</replaceable> | <replaceable class="parameter">delete</replaceable> )
76
77TABLE [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ * ]
78</synopsis>
79
80 </refsynopsisdiv>
81
82 <refsect1>
83  <title>Description</title>
84
85  <para>
86   <command>SELECT</command> retrieves rows from zero or more tables.
87   The general processing of <command>SELECT</command> is as follows:
88
89   <orderedlist>
90    <listitem>
91     <para>
92      All queries in the <literal>WITH</literal> list are computed.
93      These effectively serve as temporary tables that can be referenced
94      in the <literal>FROM</literal> list.  A <literal>WITH</literal> query
95      that is referenced more than once in <literal>FROM</literal> is
96      computed only once,
97      unless specified otherwise with <literal>NOT MATERIALIZED</literal>.
98      (See <xref linkend="sql-with"/> below.)
99     </para>
100    </listitem>
101
102    <listitem>
103     <para>
104      All elements in the <literal>FROM</literal> list are computed.
105      (Each element in the <literal>FROM</literal> list is a real or
106      virtual table.)  If more than one element is specified in the
107      <literal>FROM</literal> list, they are cross-joined together.
108      (See <xref linkend="sql-from"/> below.)
109     </para>
110    </listitem>
111
112    <listitem>
113     <para>
114      If the <literal>WHERE</literal> clause is specified, all rows
115      that do not satisfy the condition are eliminated from the
116      output.  (See <xref linkend="sql-where"/> below.)
117     </para>
118    </listitem>
119
120    <listitem>
121     <para>
122      If the <literal>GROUP BY</literal> clause is specified,
123      or if there are aggregate function calls, the
124      output is combined into groups of rows that match on one or more
125      values, and the results of aggregate functions are computed.
126      If the <literal>HAVING</literal> clause is present, it
127      eliminates groups that do not satisfy the given condition.  (See
128      <xref linkend="sql-groupby"/> and
129      <xref linkend="sql-having"/> below.)
130     </para>
131    </listitem>
132
133    <listitem>
134     <para>
135      The actual output rows are computed using the
136      <command>SELECT</command> output expressions for each selected
137      row or row group.  (See <xref linkend="sql-select-list"/> below.)
138     </para>
139    </listitem>
140
141    <listitem>
142     <para><literal>SELECT DISTINCT</literal> eliminates duplicate rows from the
143      result.  <literal>SELECT DISTINCT ON</literal> eliminates rows that
144      match on all the specified expressions.  <literal>SELECT ALL</literal>
145      (the default) will return all candidate rows, including
146      duplicates.  (See <xref linkend="sql-distinct"/> below.)
147     </para>
148    </listitem>
149
150    <listitem>
151     <para>
152      Using the operators <literal>UNION</literal>,
153      <literal>INTERSECT</literal>, and <literal>EXCEPT</literal>, the
154      output of more than one <command>SELECT</command> statement can
155      be combined to form a single result set.  The
156      <literal>UNION</literal> operator returns all rows that are in
157      one or both of the result sets.  The
158      <literal>INTERSECT</literal> operator returns all rows that are
159      strictly in both result sets.  The <literal>EXCEPT</literal>
160      operator returns the rows that are in the first result set but
161      not in the second.  In all three cases, duplicate rows are
162      eliminated unless <literal>ALL</literal> is specified.  The noise
163      word <literal>DISTINCT</literal> can be added to explicitly specify
164      eliminating duplicate rows.  Notice that <literal>DISTINCT</literal> is
165      the default behavior here, even though <literal>ALL</literal> is
166      the default for <command>SELECT</command> itself.  (See
167      <xref linkend="sql-union"/>, <xref linkend="sql-intersect"/>, and
168      <xref linkend="sql-except"/> below.)
169     </para>
170    </listitem>
171
172    <listitem>
173     <para>
174      If the <literal>ORDER BY</literal> clause is specified, the
175      returned rows are sorted in the specified order.  If
176      <literal>ORDER BY</literal> is not given, the rows are returned
177      in whatever order the system finds fastest to produce.  (See
178      <xref linkend="sql-orderby"/> below.)
179     </para>
180    </listitem>
181
182    <listitem>
183     <para>
184      If the <literal>LIMIT</literal> (or <literal>FETCH FIRST</literal>) or <literal>OFFSET</literal>
185      clause is specified, the <command>SELECT</command> statement
186      only returns a subset of the result rows. (See <xref
187      linkend="sql-limit"/> below.)
188     </para>
189    </listitem>
190
191    <listitem>
192     <para>
193      If <literal>FOR UPDATE</literal>, <literal>FOR NO KEY UPDATE</literal>, <literal>FOR SHARE</literal>
194      or <literal>FOR KEY SHARE</literal>
195      is specified, the
196      <command>SELECT</command> statement locks the selected rows
197      against concurrent updates.  (See <xref linkend="sql-for-update-share"/>
198      below.)
199     </para>
200    </listitem>
201   </orderedlist>
202  </para>
203
204  <para>
205   You must have <literal>SELECT</literal> privilege on each column used
206   in a <command>SELECT</command> command.  The use of <literal>FOR NO KEY UPDATE</literal>,
207   <literal>FOR UPDATE</literal>,
208   <literal>FOR SHARE</literal> or <literal>FOR KEY SHARE</literal> requires
209   <literal>UPDATE</literal> privilege as well (for at least one column
210   of each table so selected).
211  </para>
212 </refsect1>
213
214 <refsect1>
215  <title>Parameters</title>
216
217  <refsect2 id="sql-with" xreflabel="WITH Clause">
218   <title><literal>WITH</literal> Clause</title>
219
220   <para>
221    The <literal>WITH</literal> clause allows you to specify one or more
222    subqueries that can be referenced by name in the primary query.
223    The subqueries effectively act as temporary tables or views
224    for the duration of the primary query.
225    Each subquery can be a <command>SELECT</command>, <command>TABLE</command>, <command>VALUES</command>,
226    <command>INSERT</command>, <command>UPDATE</command> or
227    <command>DELETE</command> statement.
228    When writing a data-modifying statement (<command>INSERT</command>,
229    <command>UPDATE</command> or <command>DELETE</command>) in
230    <literal>WITH</literal>, it is usual to include a <literal>RETURNING</literal> clause.
231    It is the output of <literal>RETURNING</literal>, <emphasis>not</emphasis> the underlying
232    table that the statement modifies, that forms the temporary table that is
233    read by the primary query.  If <literal>RETURNING</literal> is omitted, the
234    statement is still executed, but it produces no output so it cannot be
235    referenced as a table by the primary query.
236   </para>
237
238   <para>
239    A name (without schema qualification) must be specified for each
240    <literal>WITH</literal> query.  Optionally, a list of column names
241    can be specified; if this is omitted,
242    the column names are inferred from the subquery.
243   </para>
244
245   <para>
246    If <literal>RECURSIVE</literal> is specified, it allows a
247    <command>SELECT</command> subquery to reference itself by name.  Such a
248    subquery must have the form
249<synopsis>
250<replaceable class="parameter">non_recursive_term</replaceable> UNION [ ALL | DISTINCT ] <replaceable class="parameter">recursive_term</replaceable>
251</synopsis>
252    where the recursive self-reference must appear on the right-hand
253    side of the <literal>UNION</literal>.  Only one recursive self-reference
254    is permitted per query.  Recursive data-modifying statements are not
255    supported, but you can use the results of a recursive
256    <command>SELECT</command> query in
257    a data-modifying statement.  See <xref linkend="queries-with"/> for
258    an example.
259   </para>
260
261   <para>
262    Another effect of <literal>RECURSIVE</literal> is that
263    <literal>WITH</literal> queries need not be ordered: a query
264    can reference another one that is later in the list.  (However,
265    circular references, or mutual recursion, are not implemented.)
266    Without <literal>RECURSIVE</literal>, <literal>WITH</literal> queries
267    can only reference sibling <literal>WITH</literal> queries
268    that are earlier in the <literal>WITH</literal> list.
269   </para>
270
271   <para>
272    When there are multiple queries in the <literal>WITH</literal>
273    clause, <literal>RECURSIVE</literal> should be written only once,
274    immediately after <literal>WITH</literal>.  It applies to all queries
275    in the <literal>WITH</literal> clause, though it has no effect on
276    queries that do not use recursion or forward references.
277   </para>
278
279   <para>
280    The primary query and the <literal>WITH</literal> queries are all
281    (notionally) executed at the same time.  This implies that the effects of
282    a data-modifying statement in <literal>WITH</literal> cannot be seen from
283    other parts of the query, other than by reading its <literal>RETURNING</literal>
284    output.  If two such data-modifying statements attempt to modify the same
285    row, the results are unspecified.
286   </para>
287
288   <para>
289    A key property of <literal>WITH</literal> queries is that they
290    are normally evaluated only once per execution of the primary query,
291    even if the primary query refers to them more than once.
292    In particular, data-modifying statements are guaranteed to be
293    executed once and only once, regardless of whether the primary query
294    reads all or any of their output.
295   </para>
296
297   <para>
298    However, a <literal>WITH</literal> query can be marked
299    <literal>NOT MATERIALIZED</literal> to remove this guarantee.  In that
300    case, the <literal>WITH</literal> query can be folded into the primary
301    query much as though it were a simple sub-<literal>SELECT</literal> in
302    the primary query's <literal>FROM</literal> clause.  This results in
303    duplicate computations if the primary query refers to
304    that <literal>WITH</literal> query more than once; but if each such use
305    requires only a few rows of the <literal>WITH</literal> query's total
306    output, <literal>NOT MATERIALIZED</literal> can provide a net savings by
307    allowing the queries to be optimized jointly.
308    <literal>NOT MATERIALIZED</literal> is ignored if it is attached to
309    a <literal>WITH</literal> query that is recursive or is not
310    side-effect-free (i.e., is not a plain <literal>SELECT</literal>
311    containing no volatile functions).
312   </para>
313
314   <para>
315    By default, a side-effect-free <literal>WITH</literal> query is folded
316    into the primary query if it is used exactly once in the primary
317    query's <literal>FROM</literal> clause.  This allows joint optimization
318    of the two query levels in situations where that should be semantically
319    invisible.  However, such folding can be prevented by marking the
320    <literal>WITH</literal> query as <literal>MATERIALIZED</literal>.
321    That might be useful, for example, if the <literal>WITH</literal> query
322    is being used as an optimization fence to prevent the planner from
323    choosing a bad plan.
324    <productname>PostgreSQL</productname> versions before v12 never did
325    such folding, so queries written for older versions might rely on
326    <literal>WITH</literal> to act as an optimization fence.
327   </para>
328
329   <para>
330    See <xref linkend="queries-with"/> for additional information.
331   </para>
332  </refsect2>
333
334  <refsect2 id="sql-from" xreflabel="FROM Clause">
335   <title><literal>FROM</literal> Clause</title>
336
337   <para>
338    The <literal>FROM</literal> clause specifies one or more source
339    tables for the <command>SELECT</command>.  If multiple sources are
340    specified, the result is the Cartesian product (cross join) of all
341    the sources.  But usually qualification conditions are added (via
342    <literal>WHERE</literal>) to restrict the returned rows to a small subset of the
343    Cartesian product.
344   </para>
345
346   <para>
347    The <literal>FROM</literal> clause can contain the following
348    elements:
349
350    <variablelist>
351     <varlistentry>
352      <term><replaceable class="parameter">table_name</replaceable></term>
353      <listitem>
354       <para>
355        The name (optionally schema-qualified) of an existing table or view.
356        If <literal>ONLY</literal> is specified before the table name, only that
357        table is scanned.  If <literal>ONLY</literal> is not specified, the table
358        and all its descendant tables (if any) are scanned.  Optionally,
359        <literal>*</literal> can be specified after the table name to explicitly
360        indicate that descendant tables are included.
361       </para>
362      </listitem>
363     </varlistentry>
364
365     <varlistentry>
366      <term><replaceable class="parameter">alias</replaceable></term>
367      <listitem>
368       <para>
369        A substitute name for the <literal>FROM</literal> item containing the
370        alias.  An alias is used for brevity or to eliminate ambiguity
371        for self-joins (where the same table is scanned multiple
372        times).  When an alias is provided, it completely hides the
373        actual name of the table or function; for example given
374        <literal>FROM foo AS f</literal>, the remainder of the
375        <command>SELECT</command> must refer to this <literal>FROM</literal>
376        item as <literal>f</literal> not <literal>foo</literal>.  If an alias is
377        written, a column alias list can also be written to provide
378        substitute names for one or more columns of the table.
379       </para>
380      </listitem>
381     </varlistentry>
382
383     <varlistentry>
384      <term><literal>TABLESAMPLE <replaceable class="parameter">sampling_method</replaceable> ( <replaceable class="parameter">argument</replaceable> [, ...] ) [ REPEATABLE ( <replaceable class="parameter">seed</replaceable> ) ]</literal></term>
385      <listitem>
386       <para>
387        A <literal>TABLESAMPLE</literal> clause after
388        a <replaceable class="parameter">table_name</replaceable> indicates that the
389        specified <replaceable class="parameter">sampling_method</replaceable>
390        should be used to retrieve a subset of the rows in that table.
391        This sampling precedes the application of any other filters such
392        as <literal>WHERE</literal> clauses.
393        The standard <productname>PostgreSQL</productname> distribution
394        includes two sampling methods, <literal>BERNOULLI</literal>
395        and <literal>SYSTEM</literal>, and other sampling methods can be
396        installed in the database via extensions.
397       </para>
398
399       <para>
400        The <literal>BERNOULLI</literal> and <literal>SYSTEM</literal> sampling methods
401        each accept a single <replaceable class="parameter">argument</replaceable>
402        which is the fraction of the table to sample, expressed as a
403        percentage between 0 and 100.  This argument can be
404        any <type>real</type>-valued expression.  (Other sampling methods might
405        accept more or different arguments.)  These two methods each return
406        a randomly-chosen sample of the table that will contain
407        approximately the specified percentage of the table's rows.
408        The <literal>BERNOULLI</literal> method scans the whole table and
409        selects or ignores individual rows independently with the specified
410        probability.
411        The <literal>SYSTEM</literal> method does block-level sampling with
412        each block having the specified chance of being selected; all rows
413        in each selected block are returned.
414        The <literal>SYSTEM</literal> method is significantly faster than
415        the <literal>BERNOULLI</literal> method when small sampling
416        percentages are specified, but it may return a less-random sample of
417        the table as a result of clustering effects.
418       </para>
419
420       <para>
421        The optional <literal>REPEATABLE</literal> clause specifies
422        a <replaceable class="parameter">seed</replaceable> number or expression to use
423        for generating random numbers within the sampling method.  The seed
424        value can be any non-null floating-point value.  Two queries that
425        specify the same seed and <replaceable class="parameter">argument</replaceable>
426        values will select the same sample of the table, if the table has
427        not been changed meanwhile.  But different seed values will usually
428        produce different samples.
429        If <literal>REPEATABLE</literal> is not given then a new random
430        sample is selected for each query, based upon a system-generated seed.
431        Note that some add-on sampling methods do not
432        accept <literal>REPEATABLE</literal>, and will always produce new
433        samples on each use.
434       </para>
435      </listitem>
436     </varlistentry>
437
438     <varlistentry>
439      <term><replaceable class="parameter">select</replaceable></term>
440      <listitem>
441       <para>
442        A sub-<command>SELECT</command> can appear in the
443        <literal>FROM</literal> clause.  This acts as though its
444        output were created as a temporary table for the duration of
445        this single <command>SELECT</command> command.  Note that the
446        sub-<command>SELECT</command> must be surrounded by
447        parentheses, and an alias <emphasis>must</emphasis> be
448        provided for it.  A
449        <xref linkend="sql-values"/> command
450        can also be used here.
451       </para>
452      </listitem>
453     </varlistentry>
454
455     <varlistentry>
456      <term><replaceable class="parameter">with_query_name</replaceable></term>
457      <listitem>
458       <para>
459        A <literal>WITH</literal> query is referenced by writing its name,
460        just as though the query's name were a table name.  (In fact,
461        the <literal>WITH</literal> query hides any real table of the same name
462        for the purposes of the primary query.  If necessary, you can
463        refer to a real table of the same name by schema-qualifying
464        the table's name.)
465        An alias can be provided in the same way as for a table.
466       </para>
467      </listitem>
468     </varlistentry>
469
470     <varlistentry>
471      <term><replaceable class="parameter">function_name</replaceable></term>
472      <listitem>
473       <para>
474        Function calls can appear in the <literal>FROM</literal>
475        clause.  (This is especially useful for functions that return
476        result sets, but any function can be used.)  This acts as
477        though the function's output were created as a temporary table for the
478        duration of this single <command>SELECT</command> command.
479        If the function's result type is composite (including the case of a
480        function with multiple <literal>OUT</literal> parameters), each
481        attribute becomes a separate column in the implicit table.
482       </para>
483
484       <para>
485        When the optional <command>WITH ORDINALITY</command> clause is added
486        to the function call, an additional column of type <type>bigint</type>
487        will be appended to the function's result column(s).  This column
488        numbers the rows of the function's result set, starting from 1.
489        By default, this column is named <literal>ordinality</literal>.
490       </para>
491
492       <para>
493        An alias can be provided in the same way as for a table.
494        If an alias is written, a column
495        alias list can also be written to provide substitute names for
496        one or more attributes of the function's composite return
497        type, including the ordinality column if present.
498       </para>
499
500       <para>
501        Multiple function calls can be combined into a
502        single <literal>FROM</literal>-clause item by surrounding them
503        with <literal>ROWS FROM( ... )</literal>.  The output of such an item is the
504        concatenation of the first row from each function, then the second
505        row from each function, etc.  If some of the functions produce fewer
506        rows than others, null values are substituted for the missing data, so
507        that the total number of rows returned is always the same as for the
508        function that produced the most rows.
509       </para>
510
511      <para>
512        If the function has been defined as returning the
513        <type>record</type> data type, then an alias or the key word
514        <literal>AS</literal> must be present, followed by a column
515        definition list in the form <literal>( <replaceable
516        class="parameter">column_name</replaceable> <replaceable
517        class="parameter">data_type</replaceable> <optional>, ...
518        </optional>)</literal>.  The column definition list must match the
519        actual number and types of columns returned by the function.
520       </para>
521
522       <para>
523        When using the <literal>ROWS FROM( ... )</literal> syntax, if one of the
524        functions requires a column definition list, it's preferred to put
525        the column definition list after the function call inside
526        <literal>ROWS FROM( ... )</literal>.  A column definition list can be placed
527        after the <literal>ROWS FROM( ... )</literal> construct only if there's just
528        a single function and no <literal>WITH ORDINALITY</literal> clause.
529       </para>
530
531       <para>
532        To use <literal>ORDINALITY</literal> together with a column definition
533        list, you must use the <literal>ROWS FROM( ... )</literal> syntax and put the
534        column definition list inside <literal>ROWS FROM( ... )</literal>.
535       </para>
536      </listitem>
537     </varlistentry>
538
539     <varlistentry>
540      <term><replaceable class="parameter">join_type</replaceable></term>
541      <listitem>
542       <para>
543        One of
544        <itemizedlist>
545         <listitem>
546          <para><literal>[ INNER ] JOIN</literal></para>
547         </listitem>
548         <listitem>
549          <para><literal>LEFT [ OUTER ] JOIN</literal></para>
550         </listitem>
551         <listitem>
552          <para><literal>RIGHT [ OUTER ] JOIN</literal></para>
553         </listitem>
554         <listitem>
555          <para><literal>FULL [ OUTER ] JOIN</literal></para>
556         </listitem>
557         <listitem>
558          <para><literal>CROSS JOIN</literal></para>
559         </listitem>
560        </itemizedlist>
561
562        For the <literal>INNER</literal> and <literal>OUTER</literal> join types, a
563        join condition must be specified, namely exactly one of
564        <literal>NATURAL</literal>, <literal>ON <replaceable
565        class="parameter">join_condition</replaceable></literal>, or
566        <literal>USING (<replaceable
567        class="parameter">join_column</replaceable> [, ...])</literal>.
568        See below for the meaning.  For <literal>CROSS JOIN</literal>,
569        none of these clauses can appear.
570       </para>
571
572       <para>
573        A <literal>JOIN</literal> clause combines two <literal>FROM</literal>
574        items, which for convenience we will refer to as <quote>tables</quote>,
575        though in reality they can be any type of <literal>FROM</literal> item.
576        Use parentheses if necessary to determine the order of nesting.
577        In the absence of parentheses, <literal>JOIN</literal>s nest
578        left-to-right.  In any case <literal>JOIN</literal> binds more
579        tightly than the commas separating <literal>FROM</literal>-list items.
580       </para>
581
582       <para><literal>CROSS JOIN</literal> and <literal>INNER JOIN</literal>
583        produce a simple Cartesian product, the same result as you get from
584        listing the two tables at the top level of <literal>FROM</literal>,
585        but restricted by the join condition (if any).
586        <literal>CROSS JOIN</literal> is equivalent to <literal>INNER JOIN ON
587        (TRUE)</literal>, that is, no rows are removed by qualification.
588        These join types are just a notational convenience, since they
589        do nothing you couldn't do with plain <literal>FROM</literal> and
590        <literal>WHERE</literal>.
591       </para>
592
593       <para><literal>LEFT OUTER JOIN</literal> returns all rows in the qualified
594        Cartesian product (i.e., all combined rows that pass its join
595        condition), plus one copy of each row in the left-hand table
596        for which there was no right-hand row that passed the join
597        condition.  This left-hand row is extended to the full width
598        of the joined table by inserting null values for the
599        right-hand columns.  Note that only the <literal>JOIN</literal>
600        clause's own condition is considered while deciding which rows
601        have matches.  Outer conditions are applied afterwards.
602       </para>
603
604       <para>
605        Conversely, <literal>RIGHT OUTER JOIN</literal> returns all the
606        joined rows, plus one row for each unmatched right-hand row
607        (extended with nulls on the left).  This is just a notational
608        convenience, since you could convert it to a <literal>LEFT
609        OUTER JOIN</literal> by switching the left and right tables.
610       </para>
611
612       <para><literal>FULL OUTER JOIN</literal> returns all the joined rows, plus
613        one row for each unmatched left-hand row (extended with nulls
614        on the right), plus one row for each unmatched right-hand row
615        (extended with nulls on the left).
616       </para>
617      </listitem>
618     </varlistentry>
619
620     <varlistentry>
621      <term><literal>ON <replaceable class="parameter">join_condition</replaceable></literal></term>
622      <listitem>
623       <para><replaceable class="parameter">join_condition</replaceable> is
624        an expression resulting in a value of type
625        <type>boolean</type> (similar to a <literal>WHERE</literal>
626        clause) that specifies which rows in a join are considered to
627        match.
628       </para>
629      </listitem>
630     </varlistentry>
631
632     <varlistentry>
633      <term><literal>USING ( <replaceable class="parameter">join_column</replaceable> [, ...] )</literal></term>
634      <listitem>
635       <para>
636        A clause of the form <literal>USING ( a, b, ... )</literal> is
637        shorthand for <literal>ON left_table.a = right_table.a AND
638        left_table.b = right_table.b ...</literal>.  Also,
639        <literal>USING</literal> implies that only one of each pair of
640        equivalent columns will be included in the join output, not
641        both.
642       </para>
643      </listitem>
644     </varlistentry>
645
646     <varlistentry>
647      <term><literal>NATURAL</literal></term>
648      <listitem>
649       <para>
650        <literal>NATURAL</literal> is shorthand for a
651        <literal>USING</literal> list that mentions all columns in the two
652        tables that have matching names.  If there are no common
653        column names, <literal>NATURAL</literal> is equivalent
654        to <literal>ON TRUE</literal>.
655       </para>
656      </listitem>
657     </varlistentry>
658
659     <varlistentry>
660      <term><literal>LATERAL</literal></term>
661      <listitem>
662       <para>
663        The <literal>LATERAL</literal> key word can precede a
664        sub-<command>SELECT</command> <literal>FROM</literal> item.  This allows the
665        sub-<command>SELECT</command> to refer to columns of <literal>FROM</literal>
666        items that appear before it in the <literal>FROM</literal> list.  (Without
667        <literal>LATERAL</literal>, each sub-<command>SELECT</command> is
668        evaluated independently and so cannot cross-reference any other
669        <literal>FROM</literal> item.)
670       </para>
671
672       <para><literal>LATERAL</literal> can also precede a function-call
673        <literal>FROM</literal> item, but in this case it is a noise word, because
674        the function expression can refer to earlier <literal>FROM</literal> items
675        in any case.
676       </para>
677
678       <para>
679        A <literal>LATERAL</literal> item can appear at top level in the
680        <literal>FROM</literal> list, or within a <literal>JOIN</literal> tree.  In the
681        latter case it can also refer to any items that are on the left-hand
682        side of a <literal>JOIN</literal> that it is on the right-hand side of.
683       </para>
684
685       <para>
686        When a <literal>FROM</literal> item contains <literal>LATERAL</literal>
687        cross-references, evaluation proceeds as follows: for each row of the
688        <literal>FROM</literal> item providing the cross-referenced column(s), or
689        set of rows of multiple <literal>FROM</literal> items providing the
690        columns, the <literal>LATERAL</literal> item is evaluated using that
691        row or row set's values of the columns.  The resulting row(s) are
692        joined as usual with the rows they were computed from.  This is
693        repeated for each row or set of rows from the column source table(s).
694       </para>
695
696       <para>
697        The column source table(s) must be <literal>INNER</literal> or
698        <literal>LEFT</literal> joined to the <literal>LATERAL</literal> item, else
699        there would not be a well-defined set of rows from which to compute
700        each set of rows for the <literal>LATERAL</literal> item.  Thus,
701        although a construct such as <literal><replaceable>X</replaceable> RIGHT JOIN
702        LATERAL <replaceable>Y</replaceable></literal> is syntactically valid, it is
703        not actually allowed for <replaceable>Y</replaceable> to reference
704        <replaceable>X</replaceable>.
705       </para>
706      </listitem>
707     </varlistentry>
708    </variablelist>
709   </para>
710  </refsect2>
711
712  <refsect2 id="sql-where" xreflabel="WHERE Clause">
713   <title><literal>WHERE</literal> Clause</title>
714
715   <para>
716    The optional <literal>WHERE</literal> clause has the general form
717<synopsis>
718WHERE <replaceable class="parameter">condition</replaceable>
719</synopsis>
720    where <replaceable class="parameter">condition</replaceable> is
721    any expression that evaluates to a result of type
722    <type>boolean</type>.  Any row that does not satisfy this
723    condition will be eliminated from the output.  A row satisfies the
724    condition if it returns true when the actual row values are
725    substituted for any variable references.
726   </para>
727  </refsect2>
728
729  <refsect2 id="sql-groupby" xreflabel="GROUP BY Clause">
730   <title><literal>GROUP BY</literal> Clause</title>
731
732   <para>
733    The optional <literal>GROUP BY</literal> clause has the general form
734<synopsis>
735GROUP BY <replaceable class="parameter">grouping_element</replaceable> [, ...]
736</synopsis>
737   </para>
738
739   <para>
740    <literal>GROUP BY</literal> will condense into a single row all
741    selected rows that share the same values for the grouped
742    expressions.  An <replaceable
743    class="parameter">expression</replaceable> used inside a
744    <replaceable class="parameter">grouping_element</replaceable>
745    can be an input column name, or the name or ordinal number of an
746    output column (<command>SELECT</command> list item), or an arbitrary
747    expression formed from input-column values.  In case of ambiguity,
748    a <literal>GROUP BY</literal> name will be interpreted as an
749    input-column name rather than an output column name.
750   </para>
751
752   <para>
753    If any of <literal>GROUPING SETS</literal>, <literal>ROLLUP</literal> or
754    <literal>CUBE</literal> are present as grouping elements, then the
755    <literal>GROUP BY</literal> clause as a whole defines some number of
756    independent <replaceable>grouping sets</replaceable>.  The effect of this is
757    equivalent to constructing a <literal>UNION ALL</literal> between
758    subqueries with the individual grouping sets as their
759    <literal>GROUP BY</literal> clauses.  For further details on the handling
760    of grouping sets see <xref linkend="queries-grouping-sets"/>.
761   </para>
762
763   <para>
764    Aggregate functions, if any are used, are computed across all rows
765    making up each group, producing a separate value for each group.
766    (If there are aggregate functions but no <literal>GROUP BY</literal>
767    clause, the query is treated as having a single group comprising all
768    the selected rows.)
769    The set of rows fed to each aggregate function can be further filtered by
770    attaching a <literal>FILTER</literal> clause to the aggregate function
771    call; see <xref linkend="syntax-aggregates"/> for more information.  When
772    a <literal>FILTER</literal> clause is present, only those rows matching it
773    are included in the input to that aggregate function.
774   </para>
775
776   <para>
777    When <literal>GROUP BY</literal> is present,
778    or any aggregate functions are present, it is not valid for
779    the <command>SELECT</command> list expressions to refer to
780    ungrouped columns except within aggregate functions or when the
781    ungrouped column is functionally dependent on the grouped columns,
782    since there would otherwise be more than one possible value to
783    return for an ungrouped column.  A functional dependency exists if
784    the grouped columns (or a subset thereof) are the primary key of
785    the table containing the ungrouped column.
786   </para>
787
788   <para>
789    Keep in mind that all aggregate functions are evaluated before
790    evaluating any <quote>scalar</quote> expressions in the <literal>HAVING</literal>
791    clause or <literal>SELECT</literal> list.  This means that, for example,
792    a <literal>CASE</literal> expression cannot be used to skip evaluation of
793    an aggregate function; see <xref linkend="syntax-express-eval"/>.
794   </para>
795
796   <para>
797    Currently, <literal>FOR NO KEY UPDATE</literal>, <literal>FOR UPDATE</literal>,
798    <literal>FOR SHARE</literal> and <literal>FOR KEY SHARE</literal> cannot be
799    specified with <literal>GROUP BY</literal>.
800   </para>
801  </refsect2>
802
803  <refsect2 id="sql-having" xreflabel="HAVING Clause">
804   <title><literal>HAVING</literal> Clause</title>
805
806   <para>
807    The optional <literal>HAVING</literal> clause has the general form
808<synopsis>
809HAVING <replaceable class="parameter">condition</replaceable>
810</synopsis>
811    where <replaceable class="parameter">condition</replaceable> is
812    the same as specified for the <literal>WHERE</literal> clause.
813   </para>
814
815   <para>
816    <literal>HAVING</literal> eliminates group rows that do not
817    satisfy the condition.  <literal>HAVING</literal> is different
818    from <literal>WHERE</literal>: <literal>WHERE</literal> filters
819    individual rows before the application of <literal>GROUP
820    BY</literal>, while <literal>HAVING</literal> filters group rows
821    created by <literal>GROUP BY</literal>.  Each column referenced in
822    <replaceable class="parameter">condition</replaceable> must
823    unambiguously reference a grouping column, unless the reference
824    appears within an aggregate function or the ungrouped column is
825    functionally dependent on the grouping columns.
826   </para>
827
828   <para>
829    The presence of <literal>HAVING</literal> turns a query into a grouped
830    query even if there is no <literal>GROUP BY</literal> clause.  This is the
831    same as what happens when the query contains aggregate functions but
832    no <literal>GROUP BY</literal> clause.  All the selected rows are considered to
833    form a single group, and the <command>SELECT</command> list and
834    <literal>HAVING</literal> clause can only reference table columns from
835    within aggregate functions.  Such a query will emit a single row if the
836    <literal>HAVING</literal> condition is true, zero rows if it is not true.
837   </para>
838
839   <para>
840    Currently, <literal>FOR NO KEY UPDATE</literal>, <literal>FOR UPDATE</literal>,
841    <literal>FOR SHARE</literal> and <literal>FOR KEY SHARE</literal> cannot be
842    specified with <literal>HAVING</literal>.
843   </para>
844  </refsect2>
845
846  <refsect2 id="sql-window" xreflabel="WINDOW Clause">
847   <title><literal>WINDOW</literal> Clause</title>
848
849   <para>
850    The optional <literal>WINDOW</literal> clause has the general form
851<synopsis>
852WINDOW <replaceable class="parameter">window_name</replaceable> AS ( <replaceable class="parameter">window_definition</replaceable> ) [, ...]
853</synopsis>
854    where <replaceable class="parameter">window_name</replaceable> is
855    a name that can be referenced from <literal>OVER</literal> clauses or
856    subsequent window definitions, and
857    <replaceable class="parameter">window_definition</replaceable> is
858<synopsis>
859[ <replaceable class="parameter">existing_window_name</replaceable> ]
860[ PARTITION BY <replaceable class="parameter">expression</replaceable> [, ...] ]
861[ ORDER BY <replaceable class="parameter">expression</replaceable> [ ASC | DESC | USING <replaceable class="parameter">operator</replaceable> ] [ NULLS { FIRST | LAST } ] [, ...] ]
862[ <replaceable class="parameter">frame_clause</replaceable> ]
863</synopsis>
864   </para>
865
866   <para>
867    If an <replaceable class="parameter">existing_window_name</replaceable>
868    is specified it must refer to an earlier entry in the <literal>WINDOW</literal>
869    list; the new window copies its partitioning clause from that entry,
870    as well as its ordering clause if any.  In this case the new window cannot
871    specify its own <literal>PARTITION BY</literal> clause, and it can specify
872    <literal>ORDER BY</literal> only if the copied window does not have one.
873    The new window always uses its own frame clause; the copied window
874    must not specify a frame clause.
875   </para>
876
877   <para>
878    The elements of the <literal>PARTITION BY</literal> list are interpreted in
879    much the same fashion as elements of a <link
880    linkend="sql-groupby"><literal>GROUP BY</literal></link> clause, except that
881    they are always simple expressions and never the name or number of an
882    output column.
883    Another difference is that these expressions can contain aggregate
884    function calls, which are not allowed in a regular <literal>GROUP BY</literal>
885    clause.  They are allowed here because windowing occurs after grouping
886    and aggregation.
887   </para>
888
889   <para>
890    Similarly, the elements of the <literal>ORDER BY</literal> list are interpreted
891    in much the same fashion as elements of a statement-level <link
892    linkend="sql-orderby"><literal>ORDER BY</literal></link> clause, except that
893    the expressions are always taken as simple expressions and never the name
894    or number of an output column.
895   </para>
896
897   <para>
898    The optional <replaceable class="parameter">frame_clause</replaceable> defines
899    the <firstterm>window frame</firstterm> for window functions that depend on the
900    frame (not all do).  The window frame is a set of related rows for
901    each row of the query (called the <firstterm>current row</firstterm>).
902    The <replaceable class="parameter">frame_clause</replaceable> can be one of
903
904<synopsis>
905{ RANGE | ROWS | GROUPS } <replaceable>frame_start</replaceable> [ <replaceable>frame_exclusion</replaceable> ]
906{ RANGE | ROWS | GROUPS } BETWEEN <replaceable>frame_start</replaceable> AND <replaceable>frame_end</replaceable> [ <replaceable>frame_exclusion</replaceable> ]
907</synopsis>
908
909    where <replaceable>frame_start</replaceable>
910    and <replaceable>frame_end</replaceable> can be one of
911
912<synopsis>
913UNBOUNDED PRECEDING
914<replaceable>offset</replaceable> PRECEDING
915CURRENT ROW
916<replaceable>offset</replaceable> FOLLOWING
917UNBOUNDED FOLLOWING
918</synopsis>
919
920    and <replaceable>frame_exclusion</replaceable> can be one of
921
922<synopsis>
923EXCLUDE CURRENT ROW
924EXCLUDE GROUP
925EXCLUDE TIES
926EXCLUDE NO OTHERS
927</synopsis>
928
929    If <replaceable>frame_end</replaceable> is omitted it defaults to <literal>CURRENT
930    ROW</literal>.  Restrictions are that
931    <replaceable>frame_start</replaceable> cannot be <literal>UNBOUNDED FOLLOWING</literal>,
932    <replaceable>frame_end</replaceable> cannot be <literal>UNBOUNDED PRECEDING</literal>,
933    and the <replaceable>frame_end</replaceable> choice cannot appear earlier in the
934    above list of <replaceable>frame_start</replaceable>
935    and <replaceable>frame_end</replaceable> options than
936    the <replaceable>frame_start</replaceable> choice does &mdash; for example
937    <literal>RANGE BETWEEN CURRENT ROW AND <replaceable>offset</replaceable>
938    PRECEDING</literal> is not allowed.
939   </para>
940
941   <para>
942    The default framing option is <literal>RANGE UNBOUNDED PRECEDING</literal>,
943    which is the same as <literal>RANGE BETWEEN UNBOUNDED PRECEDING AND
944    CURRENT ROW</literal>; it sets the frame to be all rows from the partition start
945    up through the current row's last <firstterm>peer</firstterm> (a row
946    that the window's <literal>ORDER BY</literal> clause considers
947    equivalent to the current row; all rows are peers if there
948    is no <literal>ORDER BY</literal>).
949    In general, <literal>UNBOUNDED PRECEDING</literal> means that the frame
950    starts with the first row of the partition, and similarly
951    <literal>UNBOUNDED FOLLOWING</literal> means that the frame ends with the last
952    row of the partition, regardless
953    of <literal>RANGE</literal>, <literal>ROWS</literal>
954    or <literal>GROUPS</literal> mode.
955    In <literal>ROWS</literal> mode, <literal>CURRENT ROW</literal> means
956    that the frame starts or ends with the current row; but
957    in <literal>RANGE</literal> or <literal>GROUPS</literal> mode it means
958    that the frame starts or ends with the current row's first or last peer
959    in the <literal>ORDER BY</literal> ordering.
960    The <replaceable>offset</replaceable> <literal>PRECEDING</literal> and
961    <replaceable>offset</replaceable> <literal>FOLLOWING</literal> options
962    vary in meaning depending on the frame mode.
963    In <literal>ROWS</literal> mode, the <replaceable>offset</replaceable>
964    is an integer indicating that the frame starts or ends that many rows
965    before or after the current row.
966    In <literal>GROUPS</literal> mode, the <replaceable>offset</replaceable>
967    is an integer indicating that the frame starts or ends that many peer
968    groups before or after the current row's peer group, where
969    a <firstterm>peer group</firstterm> is a group of rows that are
970    equivalent according to the window's <literal>ORDER BY</literal> clause.
971    In <literal>RANGE</literal> mode, use of
972    an <replaceable>offset</replaceable> option requires that there be
973    exactly one <literal>ORDER BY</literal> column in the window definition.
974    Then the frame contains those rows whose ordering column value is no
975    more than <replaceable>offset</replaceable> less than
976    (for <literal>PRECEDING</literal>) or more than
977    (for <literal>FOLLOWING</literal>) the current row's ordering column
978    value.  In these cases the data type of
979    the <replaceable>offset</replaceable> expression depends on the data
980    type of the ordering column.  For numeric ordering columns it is
981    typically of the same type as the ordering column, but for datetime
982    ordering columns it is an <type>interval</type>.
983    In all these cases, the value of the <replaceable>offset</replaceable>
984    must be non-null and non-negative.  Also, while
985    the <replaceable>offset</replaceable> does not have to be a simple
986    constant, it cannot contain variables, aggregate functions, or window
987    functions.
988   </para>
989
990   <para>
991    The <replaceable>frame_exclusion</replaceable> option allows rows around
992    the current row to be excluded from the frame, even if they would be
993    included according to the frame start and frame end options.
994    <literal>EXCLUDE CURRENT ROW</literal> excludes the current row from the
995    frame.
996    <literal>EXCLUDE GROUP</literal> excludes the current row and its
997    ordering peers from the frame.
998    <literal>EXCLUDE TIES</literal> excludes any peers of the current
999    row from the frame, but not the current row itself.
1000    <literal>EXCLUDE NO OTHERS</literal> simply specifies explicitly the
1001    default behavior of not excluding the current row or its peers.
1002   </para>
1003
1004   <para>
1005    Beware that the <literal>ROWS</literal> mode can produce unpredictable
1006    results if the <literal>ORDER BY</literal> ordering does not order the rows
1007    uniquely.  The <literal>RANGE</literal> and <literal>GROUPS</literal>
1008    modes are designed to ensure that rows that are peers in
1009    the <literal>ORDER BY</literal> ordering are treated alike: all rows of
1010    a given peer group will be in the frame or excluded from it.
1011   </para>
1012
1013   <para>
1014    The purpose of a <literal>WINDOW</literal> clause is to specify the
1015    behavior of <firstterm>window functions</firstterm> appearing in the query's
1016    <link linkend="sql-select-list"><command>SELECT</command> list</link> or
1017    <link linkend="sql-orderby"><literal>ORDER BY</literal></link> clause.
1018    These functions
1019    can reference the <literal>WINDOW</literal> clause entries by name
1020    in their <literal>OVER</literal> clauses.  A <literal>WINDOW</literal> clause
1021    entry does not have to be referenced anywhere, however; if it is not
1022    used in the query it is simply ignored.  It is possible to use window
1023    functions without any <literal>WINDOW</literal> clause at all, since
1024    a window function call can specify its window definition directly in
1025    its <literal>OVER</literal> clause.  However, the <literal>WINDOW</literal>
1026    clause saves typing when the same window definition is needed for more
1027    than one window function.
1028   </para>
1029
1030   <para>
1031    Currently, <literal>FOR NO KEY UPDATE</literal>, <literal>FOR UPDATE</literal>,
1032    <literal>FOR SHARE</literal> and <literal>FOR KEY SHARE</literal> cannot be
1033    specified with <literal>WINDOW</literal>.
1034   </para>
1035
1036   <para>
1037    Window functions are described in detail in
1038    <xref linkend="tutorial-window"/>,
1039    <xref linkend="syntax-window-functions"/>, and
1040    <xref linkend="queries-window"/>.
1041   </para>
1042  </refsect2>
1043
1044  <refsect2 id="sql-select-list" xreflabel="SELECT List">
1045   <title><command>SELECT</command> List</title>
1046
1047   <para>
1048    The <command>SELECT</command> list (between the key words
1049    <literal>SELECT</literal> and <literal>FROM</literal>) specifies expressions
1050    that form the output rows of the <command>SELECT</command>
1051    statement.  The expressions can (and usually do) refer to columns
1052    computed in the <literal>FROM</literal> clause.
1053   </para>
1054
1055   <para>
1056    Just as in a table, every output column of a <command>SELECT</command>
1057    has a name.  In a simple <command>SELECT</command> this name is just
1058    used to label the column for display, but when the <command>SELECT</command>
1059    is a sub-query of a larger query, the name is seen by the larger query
1060    as the column name of the virtual table produced by the sub-query.
1061    To specify the name to use for an output column, write
1062    <literal>AS</literal> <replaceable class="parameter">output_name</replaceable>
1063    after the column's expression.  (You can omit <literal>AS</literal>,
1064    but only if the desired output name does not match any
1065    <productname>PostgreSQL</productname> keyword (see <xref
1066    linkend="sql-keywords-appendix"/>).  For protection against possible
1067    future keyword additions, it is recommended that you always either
1068    write <literal>AS</literal> or double-quote the output name.)
1069    If you do not specify a column name, a name is chosen automatically
1070    by <productname>PostgreSQL</productname>.  If the column's expression
1071    is a simple column reference then the chosen name is the same as that
1072    column's name.  In more complex cases a function or type name may be
1073    used, or the system may fall back on a generated name such as
1074    <literal>?column?</literal>.
1075   </para>
1076
1077   <para>
1078    An output column's name can be used to refer to the column's value in
1079    <literal>ORDER BY</literal> and <literal>GROUP BY</literal> clauses, but not in the
1080    <literal>WHERE</literal> or <literal>HAVING</literal> clauses; there you must write
1081    out the expression instead.
1082   </para>
1083
1084   <para>
1085    Instead of an expression, <literal>*</literal> can be written in
1086    the output list as a shorthand for all the columns of the selected
1087    rows.  Also, you can write <literal><replaceable
1088    class="parameter">table_name</replaceable>.*</literal> as a
1089    shorthand for the columns coming from just that table.  In these
1090    cases it is not possible to specify new names with <literal>AS</literal>;
1091    the output column names will be the same as the table columns' names.
1092   </para>
1093
1094   <para>
1095    According to the SQL standard, the expressions in the output list should
1096    be computed before applying <literal>DISTINCT</literal>, <literal>ORDER
1097    BY</literal>, or <literal>LIMIT</literal>.  This is obviously necessary
1098    when using <literal>DISTINCT</literal>, since otherwise it's not clear
1099    what values are being made distinct.  However, in many cases it is
1100    convenient if output expressions are computed after <literal>ORDER
1101    BY</literal> and <literal>LIMIT</literal>; particularly if the output list
1102    contains any volatile or expensive functions.  With that behavior, the
1103    order of function evaluations is more intuitive and there will not be
1104    evaluations corresponding to rows that never appear in the output.
1105    <productname>PostgreSQL</productname> will effectively evaluate output expressions
1106    after sorting and limiting, so long as those expressions are not
1107    referenced in <literal>DISTINCT</literal>, <literal>ORDER BY</literal>
1108    or <literal>GROUP BY</literal>.  (As a counterexample, <literal>SELECT
1109    f(x) FROM tab ORDER BY 1</literal> clearly must evaluate <function>f(x)</function>
1110    before sorting.)  Output expressions that contain set-returning functions
1111    are effectively evaluated after sorting and before limiting, so
1112    that <literal>LIMIT</literal> will act to cut off the output from a
1113    set-returning function.
1114   </para>
1115
1116   <note>
1117    <para>
1118     <productname>PostgreSQL</productname> versions before 9.6 did not provide any
1119     guarantees about the timing of evaluation of output expressions versus
1120     sorting and limiting; it depended on the form of the chosen query plan.
1121    </para>
1122   </note>
1123  </refsect2>
1124
1125  <refsect2 id="sql-distinct" xreflabel="DISTINCT Clause">
1126   <title><literal>DISTINCT</literal> Clause</title>
1127
1128   <para>
1129    If <literal>SELECT DISTINCT</literal> is specified, all duplicate rows are
1130    removed from the result set (one row is kept from each group of
1131    duplicates).  <literal>SELECT ALL</literal> specifies the opposite: all rows are
1132    kept; that is the default.
1133   </para>
1134
1135   <para>
1136    <literal>SELECT DISTINCT ON ( <replaceable
1137    class="parameter">expression</replaceable> [, ...] )</literal>
1138    keeps only the first row of each set of rows where the given
1139    expressions evaluate to equal.  The <literal>DISTINCT ON</literal>
1140    expressions are interpreted using the same rules as for
1141    <literal>ORDER BY</literal> (see above).  Note that the <quote>first
1142    row</quote> of each set is unpredictable unless <literal>ORDER
1143    BY</literal> is used to ensure that the desired row appears first.  For
1144    example:
1145<programlisting>
1146SELECT DISTINCT ON (location) location, time, report
1147    FROM weather_reports
1148    ORDER BY location, time DESC;
1149</programlisting>
1150    retrieves the most recent weather report for each location.  But
1151    if we had not used <literal>ORDER BY</literal> to force descending order
1152    of time values for each location, we'd have gotten a report from
1153    an unpredictable time for each location.
1154   </para>
1155
1156   <para>
1157    The <literal>DISTINCT ON</literal> expression(s) must match the leftmost
1158    <literal>ORDER BY</literal> expression(s).  The <literal>ORDER BY</literal> clause
1159    will normally contain additional expression(s) that determine the
1160    desired precedence of rows within each <literal>DISTINCT ON</literal> group.
1161   </para>
1162
1163   <para>
1164    Currently, <literal>FOR NO KEY UPDATE</literal>, <literal>FOR UPDATE</literal>,
1165    <literal>FOR SHARE</literal> and <literal>FOR KEY SHARE</literal> cannot be
1166    specified with <literal>DISTINCT</literal>.
1167   </para>
1168  </refsect2>
1169
1170  <refsect2 id="sql-union" xreflabel="UNION Clause">
1171   <title><literal>UNION</literal> Clause</title>
1172
1173   <para>
1174    The <literal>UNION</literal> clause has this general form:
1175<synopsis>
1176<replaceable class="parameter">select_statement</replaceable> UNION [ ALL | DISTINCT ] <replaceable class="parameter">select_statement</replaceable>
1177</synopsis><replaceable class="parameter">select_statement</replaceable> is
1178    any <command>SELECT</command> statement without an <literal>ORDER
1179    BY</literal>, <literal>LIMIT</literal>, <literal>FOR NO KEY UPDATE</literal>, <literal>FOR UPDATE</literal>,
1180    <literal>FOR SHARE</literal>, or <literal>FOR KEY SHARE</literal> clause.
1181    (<literal>ORDER BY</literal> and <literal>LIMIT</literal> can be attached to a
1182    subexpression if it is enclosed in parentheses.  Without
1183    parentheses, these clauses will be taken to apply to the result of
1184    the <literal>UNION</literal>, not to its right-hand input
1185    expression.)
1186   </para>
1187
1188   <para>
1189    The <literal>UNION</literal> operator computes the set union of
1190    the rows returned by the involved <command>SELECT</command>
1191    statements.  A row is in the set union of two result sets if it
1192    appears in at least one of the result sets.  The two
1193    <command>SELECT</command> statements that represent the direct
1194    operands of the <literal>UNION</literal> must produce the same
1195    number of columns, and corresponding columns must be of compatible
1196    data types.
1197   </para>
1198
1199   <para>
1200    The result of <literal>UNION</literal> does not contain any duplicate
1201    rows unless the <literal>ALL</literal> option is specified.
1202    <literal>ALL</literal> prevents elimination of duplicates.  (Therefore,
1203    <literal>UNION ALL</literal> is usually significantly quicker than
1204    <literal>UNION</literal>; use <literal>ALL</literal> when you can.)
1205    <literal>DISTINCT</literal> can be written to explicitly specify the
1206    default behavior of eliminating duplicate rows.
1207   </para>
1208
1209   <para>
1210    Multiple <literal>UNION</literal> operators in the same
1211    <command>SELECT</command> statement are evaluated left to right,
1212    unless otherwise indicated by parentheses.
1213   </para>
1214
1215   <para>
1216    Currently, <literal>FOR NO KEY UPDATE</literal>, <literal>FOR UPDATE</literal>, <literal>FOR SHARE</literal> and
1217    <literal>FOR KEY SHARE</literal> cannot be
1218    specified either for a <literal>UNION</literal> result or for any input of a
1219    <literal>UNION</literal>.
1220   </para>
1221  </refsect2>
1222
1223  <refsect2 id="sql-intersect" xreflabel="INTERSECT Clause">
1224   <title><literal>INTERSECT</literal> Clause</title>
1225
1226   <para>
1227    The <literal>INTERSECT</literal> clause has this general form:
1228<synopsis>
1229<replaceable class="parameter">select_statement</replaceable> INTERSECT [ ALL | DISTINCT ] <replaceable class="parameter">select_statement</replaceable>
1230</synopsis><replaceable class="parameter">select_statement</replaceable> is
1231    any <command>SELECT</command> statement without an <literal>ORDER
1232    BY</literal>, <literal>LIMIT</literal>, <literal>FOR NO KEY UPDATE</literal>, <literal>FOR UPDATE</literal>,
1233    <literal>FOR SHARE</literal>, or <literal>FOR KEY SHARE</literal> clause.
1234   </para>
1235
1236   <para>
1237    The <literal>INTERSECT</literal> operator computes the set
1238    intersection of the rows returned by the involved
1239    <command>SELECT</command> statements.  A row is in the
1240    intersection of two result sets if it appears in both result sets.
1241   </para>
1242
1243   <para>
1244    The result of <literal>INTERSECT</literal> does not contain any
1245    duplicate rows unless the <literal>ALL</literal> option is specified.
1246    With <literal>ALL</literal>, a row that has <replaceable>m</replaceable> duplicates in the
1247    left table and <replaceable>n</replaceable> duplicates in the right table will appear
1248    min(<replaceable>m</replaceable>,<replaceable>n</replaceable>) times in the result set.
1249    <literal>DISTINCT</literal> can be written to explicitly specify the
1250    default behavior of eliminating duplicate rows.
1251   </para>
1252
1253   <para>
1254    Multiple <literal>INTERSECT</literal> operators in the same
1255    <command>SELECT</command> statement are evaluated left to right,
1256    unless parentheses dictate otherwise.
1257    <literal>INTERSECT</literal> binds more tightly than
1258    <literal>UNION</literal>.  That is, <literal>A UNION B INTERSECT
1259    C</literal> will be read as <literal>A UNION (B INTERSECT
1260    C)</literal>.
1261   </para>
1262
1263   <para>
1264    Currently, <literal>FOR NO KEY UPDATE</literal>, <literal>FOR UPDATE</literal>, <literal>FOR SHARE</literal> and
1265    <literal>FOR KEY SHARE</literal> cannot be
1266    specified either for an <literal>INTERSECT</literal> result or for any input of
1267    an <literal>INTERSECT</literal>.
1268   </para>
1269  </refsect2>
1270
1271  <refsect2 id="sql-except" xreflabel="EXCEPT Clause">
1272   <title><literal>EXCEPT</literal> Clause</title>
1273
1274   <para>
1275    The <literal>EXCEPT</literal> clause has this general form:
1276<synopsis>
1277<replaceable class="parameter">select_statement</replaceable> EXCEPT [ ALL | DISTINCT ] <replaceable class="parameter">select_statement</replaceable>
1278</synopsis><replaceable class="parameter">select_statement</replaceable> is
1279    any <command>SELECT</command> statement without an <literal>ORDER
1280    BY</literal>, <literal>LIMIT</literal>, <literal>FOR NO KEY UPDATE</literal>, <literal>FOR UPDATE</literal>,
1281    <literal>FOR SHARE</literal>, or <literal>FOR KEY SHARE</literal> clause.
1282   </para>
1283
1284   <para>
1285    The <literal>EXCEPT</literal> operator computes the set of rows
1286    that are in the result of the left <command>SELECT</command>
1287    statement but not in the result of the right one.
1288   </para>
1289
1290   <para>
1291    The result of <literal>EXCEPT</literal> does not contain any
1292    duplicate rows unless the <literal>ALL</literal> option is specified.
1293    With <literal>ALL</literal>, a row that has <replaceable>m</replaceable> duplicates in the
1294    left table and <replaceable>n</replaceable> duplicates in the right table will appear
1295    max(<replaceable>m</replaceable>-<replaceable>n</replaceable>,0) times in the result set.
1296    <literal>DISTINCT</literal> can be written to explicitly specify the
1297    default behavior of eliminating duplicate rows.
1298   </para>
1299
1300   <para>
1301    Multiple <literal>EXCEPT</literal> operators in the same
1302    <command>SELECT</command> statement are evaluated left to right,
1303    unless parentheses dictate otherwise.  <literal>EXCEPT</literal> binds at
1304    the same level as <literal>UNION</literal>.
1305   </para>
1306
1307   <para>
1308    Currently, <literal>FOR NO KEY UPDATE</literal>, <literal>FOR UPDATE</literal>, <literal>FOR SHARE</literal> and
1309    <literal>FOR KEY SHARE</literal> cannot be
1310    specified either for an <literal>EXCEPT</literal> result or for any input of
1311    an <literal>EXCEPT</literal>.
1312   </para>
1313  </refsect2>
1314
1315  <refsect2 id="sql-orderby" xreflabel="ORDER BY Clause">
1316   <title><literal>ORDER BY</literal> Clause</title>
1317
1318   <para>
1319    The optional <literal>ORDER BY</literal> clause has this general form:
1320<synopsis>
1321ORDER BY <replaceable class="parameter">expression</replaceable> [ ASC | DESC | USING <replaceable class="parameter">operator</replaceable> ] [ NULLS { FIRST | LAST } ] [, ...]
1322</synopsis>
1323    The <literal>ORDER BY</literal> clause causes the result rows to
1324    be sorted according to the specified expression(s).  If two rows are
1325    equal according to the leftmost expression, they are compared
1326    according to the next expression and so on.  If they are equal
1327    according to all specified expressions, they are returned in
1328    an implementation-dependent order.
1329   </para>
1330
1331   <para>
1332    Each <replaceable class="parameter">expression</replaceable> can be the
1333    name or ordinal number of an output column
1334    (<command>SELECT</command> list item), or it can be an arbitrary
1335    expression formed from input-column values.
1336   </para>
1337
1338   <para>
1339    The ordinal number refers to the ordinal (left-to-right) position
1340    of the output column. This feature makes it possible to define an
1341    ordering on the basis of a column that does not have a unique
1342    name.  This is never absolutely necessary because it is always
1343    possible to assign a name to an output column using the
1344    <literal>AS</literal> clause.
1345   </para>
1346
1347   <para>
1348    It is also possible to use arbitrary expressions in the
1349    <literal>ORDER BY</literal> clause, including columns that do not
1350    appear in the <command>SELECT</command> output list.  Thus the
1351    following statement is valid:
1352<programlisting>
1353SELECT name FROM distributors ORDER BY code;
1354</programlisting>
1355    A limitation of this feature is that an <literal>ORDER BY</literal>
1356    clause applying to the result of a <literal>UNION</literal>,
1357    <literal>INTERSECT</literal>, or <literal>EXCEPT</literal> clause can only
1358    specify an output column name or number, not an expression.
1359   </para>
1360
1361   <para>
1362    If an <literal>ORDER BY</literal> expression is a simple name that
1363    matches both an output column name and an input column name,
1364    <literal>ORDER BY</literal> will interpret it as the output column name.
1365    This is the opposite of the choice that <literal>GROUP BY</literal> will
1366    make in the same situation.  This inconsistency is made to be
1367    compatible with the SQL standard.
1368   </para>
1369
1370   <para>
1371    Optionally one can add the key word <literal>ASC</literal> (ascending) or
1372    <literal>DESC</literal> (descending) after any expression in the
1373    <literal>ORDER BY</literal> clause.  If not specified, <literal>ASC</literal> is
1374    assumed by default.  Alternatively, a specific ordering operator
1375    name can be specified in the <literal>USING</literal> clause.
1376    An ordering operator must be a less-than or greater-than
1377    member of some B-tree operator family.
1378    <literal>ASC</literal> is usually equivalent to <literal>USING &lt;</literal> and
1379    <literal>DESC</literal> is usually equivalent to <literal>USING &gt;</literal>.
1380    (But the creator of a user-defined data type can define exactly what the
1381    default sort ordering is, and it might correspond to operators with other
1382    names.)
1383   </para>
1384
1385   <para>
1386    If <literal>NULLS LAST</literal> is specified, null values sort after all
1387    non-null values; if <literal>NULLS FIRST</literal> is specified, null values
1388    sort before all non-null values.  If neither is specified, the default
1389    behavior is <literal>NULLS LAST</literal> when <literal>ASC</literal> is specified
1390    or implied, and <literal>NULLS FIRST</literal> when <literal>DESC</literal> is specified
1391    (thus, the default is to act as though nulls are larger than non-nulls).
1392    When <literal>USING</literal> is specified, the default nulls ordering depends
1393    on whether the operator is a less-than or greater-than operator.
1394   </para>
1395
1396   <para>
1397    Note that ordering options apply only to the expression they follow;
1398    for example <literal>ORDER BY x, y DESC</literal> does not mean
1399    the same thing as <literal>ORDER BY x DESC, y DESC</literal>.
1400   </para>
1401
1402   <para>
1403    Character-string data is sorted according to the collation that applies
1404    to the column being sorted.  That can be overridden at need by including
1405    a <literal>COLLATE</literal> clause in the
1406    <replaceable class="parameter">expression</replaceable>, for example
1407    <literal>ORDER BY mycolumn COLLATE "en_US"</literal>.
1408    For more information see <xref linkend="sql-syntax-collate-exprs"/> and
1409    <xref linkend="collation"/>.
1410   </para>
1411  </refsect2>
1412
1413  <refsect2 id="sql-limit" xreflabel="LIMIT Clause">
1414   <title><literal>LIMIT</literal> Clause</title>
1415
1416   <para>
1417    The <literal>LIMIT</literal> clause consists of two independent
1418    sub-clauses:
1419<synopsis>
1420LIMIT { <replaceable class="parameter">count</replaceable> | ALL }
1421OFFSET <replaceable class="parameter">start</replaceable>
1422</synopsis>
1423    The parameter <replaceable class="parameter">count</replaceable> specifies the
1424    maximum number of rows to return, while <replaceable
1425    class="parameter">start</replaceable> specifies the number of rows
1426    to skip before starting to return rows.  When both are specified,
1427    <replaceable class="parameter">start</replaceable> rows are skipped
1428    before starting to count the <replaceable
1429    class="parameter">count</replaceable> rows to be returned.
1430   </para>
1431
1432   <para>
1433    If the <replaceable class="parameter">count</replaceable> expression
1434    evaluates to NULL, it is treated as <literal>LIMIT ALL</literal>, i.e., no
1435    limit.  If <replaceable class="parameter">start</replaceable> evaluates
1436    to NULL, it is treated the same as <literal>OFFSET 0</literal>.
1437   </para>
1438
1439   <para>
1440    SQL:2008 introduced a different syntax to achieve the same result,
1441    which <productname>PostgreSQL</productname> also supports.  It is:
1442<synopsis>
1443OFFSET <replaceable class="parameter">start</replaceable> { ROW | ROWS }
1444FETCH { FIRST | NEXT } [ <replaceable class="parameter">count</replaceable> ] { ROW | ROWS } { ONLY | WITH TIES }
1445</synopsis>
1446    In this syntax, the <replaceable class="parameter">start</replaceable>
1447    or <replaceable class="parameter">count</replaceable> value is required by
1448    the standard to be a literal constant, a parameter, or a variable name;
1449    as a <productname>PostgreSQL</productname> extension, other expressions
1450    are allowed, but will generally need to be enclosed in parentheses to avoid
1451    ambiguity.
1452    If <replaceable class="parameter">count</replaceable> is
1453    omitted in a <literal>FETCH</literal> clause, it defaults to 1.
1454    The <literal>WITH TIES</literal> option is used to return any additional
1455    rows that tie for the last place in the result set according to
1456    the <literal>ORDER BY</literal> clause; <literal>ORDER BY</literal>
1457    is mandatory in this case, and <literal>SKIP LOCKED</literal> is
1458    not allowed.
1459    <literal>ROW</literal> and <literal>ROWS</literal> as well as
1460    <literal>FIRST</literal> and <literal>NEXT</literal> are noise
1461    words that don't influence the effects of these clauses.
1462    According to the standard, the <literal>OFFSET</literal> clause must come
1463    before the <literal>FETCH</literal> clause if both are present; but
1464    <productname>PostgreSQL</productname> is laxer and allows either order.
1465   </para>
1466
1467   <para>
1468    When using <literal>LIMIT</literal>, it is a good idea to use an
1469    <literal>ORDER BY</literal> clause that constrains the result rows into a
1470    unique order.  Otherwise you will get an unpredictable subset of
1471    the query's rows &mdash; you might be asking for the tenth through
1472    twentieth rows, but tenth through twentieth in what ordering?  You
1473    don't know what ordering unless you specify <literal>ORDER BY</literal>.
1474   </para>
1475
1476   <para>
1477    The query planner takes <literal>LIMIT</literal> into account when
1478    generating a query plan, so you are very likely to get different
1479    plans (yielding different row orders) depending on what you use
1480    for <literal>LIMIT</literal> and <literal>OFFSET</literal>.  Thus, using
1481    different <literal>LIMIT</literal>/<literal>OFFSET</literal> values to select
1482    different subsets of a query result <emphasis>will give
1483    inconsistent results</emphasis> unless you enforce a predictable
1484    result ordering with <literal>ORDER BY</literal>.  This is not a bug; it
1485    is an inherent consequence of the fact that SQL does not promise
1486    to deliver the results of a query in any particular order unless
1487    <literal>ORDER BY</literal> is used to constrain the order.
1488   </para>
1489
1490   <para>
1491    It is even possible for repeated executions of the same <literal>LIMIT</literal>
1492    query to return different subsets of the rows of a table, if there
1493    is not an <literal>ORDER BY</literal> to enforce selection of a deterministic
1494    subset.  Again, this is not a bug; determinism of the results is
1495    simply not guaranteed in such a case.
1496   </para>
1497  </refsect2>
1498
1499  <refsect2 id="sql-for-update-share" xreflabel="The Locking Clause">
1500   <title>The Locking Clause</title>
1501
1502   <para>
1503    <literal>FOR UPDATE</literal>, <literal>FOR NO KEY UPDATE</literal>, <literal>FOR SHARE</literal>
1504    and <literal>FOR KEY SHARE</literal>
1505    are <firstterm>locking clauses</firstterm>; they affect how <literal>SELECT</literal>
1506    locks rows as they are obtained from the table.
1507   </para>
1508
1509   <para>
1510    The locking clause has the general form
1511
1512<synopsis>
1513FOR <replaceable>lock_strength</replaceable> [ OF <replaceable class="parameter">table_name</replaceable> [, ...] ] [ NOWAIT | SKIP LOCKED ]
1514</synopsis>
1515
1516    where <replaceable>lock_strength</replaceable> can be one of
1517
1518<synopsis>
1519UPDATE
1520NO KEY UPDATE
1521SHARE
1522KEY SHARE
1523</synopsis>
1524   </para>
1525
1526   <para>
1527    For more information on each row-level lock mode, refer to
1528    <xref linkend="locking-rows"/>.
1529   </para>
1530
1531   <para>
1532    To prevent the operation from waiting for other transactions to commit,
1533    use either the <literal>NOWAIT</literal> or <literal>SKIP LOCKED</literal>
1534    option.  With <literal>NOWAIT</literal>, the statement reports an error, rather
1535    than waiting, if a selected row cannot be locked immediately.
1536    With <literal>SKIP LOCKED</literal>, any selected rows that cannot be
1537    immediately locked are skipped.  Skipping locked rows provides an
1538    inconsistent view of the data, so this is not suitable for general purpose
1539    work, but can be used to avoid lock contention with multiple consumers
1540    accessing a queue-like table.
1541    Note that <literal>NOWAIT</literal> and <literal>SKIP LOCKED</literal> apply only
1542    to the row-level lock(s) &mdash; the required <literal>ROW SHARE</literal>
1543    table-level lock is still taken in the ordinary way (see
1544    <xref linkend="mvcc"/>).  You can use
1545    <xref linkend="sql-lock"/>
1546    with the <literal>NOWAIT</literal> option first,
1547    if you need to acquire the table-level lock without waiting.
1548   </para>
1549
1550   <para>
1551    If specific tables are named in a locking clause,
1552    then only rows coming from those tables are locked; any other
1553    tables used in the <command>SELECT</command> are simply read as
1554    usual.  A locking
1555    clause without a table list affects all tables used in the statement.
1556    If a locking clause is
1557    applied to a view or sub-query, it affects all tables used in
1558    the view or sub-query.
1559    However, these clauses
1560    do not apply to <literal>WITH</literal> queries referenced by the primary query.
1561    If you want row locking to occur within a <literal>WITH</literal> query, specify
1562    a locking clause within the <literal>WITH</literal> query.
1563   </para>
1564
1565   <para>
1566    Multiple locking
1567    clauses can be written if it is necessary to specify different locking
1568    behavior for different tables.  If the same table is mentioned (or
1569    implicitly affected) by more than one locking clause,
1570    then it is processed as if it was only specified by the strongest one.
1571    Similarly, a table is processed
1572    as <literal>NOWAIT</literal> if that is specified in any of the clauses
1573    affecting it.  Otherwise, it is processed
1574    as <literal>SKIP LOCKED</literal> if that is specified in any of the
1575    clauses affecting it.
1576   </para>
1577
1578   <para>
1579    The locking clauses cannot be
1580    used in contexts where returned rows cannot be clearly identified with
1581    individual table rows; for example they cannot be used with aggregation.
1582   </para>
1583
1584   <para>
1585    When a locking clause
1586    appears at the top level of a <command>SELECT</command> query, the rows that
1587    are locked are exactly those that are returned by the query; in the
1588    case of a join query, the rows locked are those that contribute to
1589    returned join rows.  In addition, rows that satisfied the query
1590    conditions as of the query snapshot will be locked, although they
1591    will not be returned if they were updated after the snapshot
1592    and no longer satisfy the query conditions.  If a
1593    <literal>LIMIT</literal> is used, locking stops
1594    once enough rows have been returned to satisfy the limit (but note that
1595    rows skipped over by <literal>OFFSET</literal> will get locked).  Similarly,
1596    if a locking clause
1597    is used in a cursor's query, only rows actually fetched or stepped past
1598    by the cursor will be locked.
1599   </para>
1600
1601   <para>
1602    When a locking clause
1603    appears in a sub-<command>SELECT</command>, the rows locked are those
1604    returned to the outer query by the sub-query.  This might involve
1605    fewer rows than inspection of the sub-query alone would suggest,
1606    since conditions from the outer query might be used to optimize
1607    execution of the sub-query.  For example,
1608<programlisting>
1609SELECT * FROM (SELECT * FROM mytable FOR UPDATE) ss WHERE col1 = 5;
1610</programlisting>
1611    will lock only rows having <literal>col1 = 5</literal>, even though that
1612    condition is not textually within the sub-query.
1613   </para>
1614
1615  <para>
1616   Previous releases failed to preserve a lock which is upgraded by a later
1617   savepoint.  For example, this code:
1618<programlisting>
1619BEGIN;
1620SELECT * FROM mytable WHERE key = 1 FOR UPDATE;
1621SAVEPOINT s;
1622UPDATE mytable SET ... WHERE key = 1;
1623ROLLBACK TO s;
1624</programlisting>
1625   would fail to preserve the <literal>FOR UPDATE</literal> lock after the
1626   <command>ROLLBACK TO</command>.  This has been fixed in release 9.3.
1627  </para>
1628
1629  <caution>
1630   <para>
1631    It is possible for a <command>SELECT</command> command running at the <literal>READ
1632    COMMITTED</literal> transaction isolation level and using <literal>ORDER
1633    BY</literal> and a locking clause to return rows out of
1634    order.  This is because <literal>ORDER BY</literal> is applied first.
1635    The command sorts the result, but might then block trying to obtain a lock
1636    on one or more of the rows.  Once the <literal>SELECT</literal> unblocks, some
1637    of the ordering column values might have been modified, leading to those
1638    rows appearing to be out of order (though they are in order in terms
1639    of the original column values).  This can be worked around at need by
1640    placing the <literal>FOR UPDATE/SHARE</literal> clause in a sub-query,
1641    for example
1642<programlisting>
1643SELECT * FROM (SELECT * FROM mytable FOR UPDATE) ss ORDER BY column1;
1644</programlisting>
1645    Note that this will result in locking all rows of <structname>mytable</structname>,
1646    whereas <literal>FOR UPDATE</literal> at the top level would lock only the
1647    actually returned rows.  This can make for a significant performance
1648    difference, particularly if the <literal>ORDER BY</literal> is combined with
1649    <literal>LIMIT</literal> or other restrictions.  So this technique is recommended
1650    only if concurrent updates of the ordering columns are expected and a
1651    strictly sorted result is required.
1652   </para>
1653
1654   <para>
1655    At the <literal>REPEATABLE READ</literal> or <literal>SERIALIZABLE</literal>
1656    transaction isolation level this would cause a serialization failure (with
1657    a <literal>SQLSTATE</literal> of <literal>'40001'</literal>), so there is
1658    no possibility of receiving rows out of order under these isolation levels.
1659   </para>
1660  </caution>
1661  </refsect2>
1662
1663  <refsect2 id="sql-table">
1664   <title><literal>TABLE</literal> Command</title>
1665
1666   <para>
1667    The command
1668<programlisting>
1669TABLE <replaceable class="parameter">name</replaceable>
1670</programlisting>
1671    is equivalent to
1672<programlisting>
1673SELECT * FROM <replaceable class="parameter">name</replaceable>
1674</programlisting>
1675    It can be used as a top-level command or as a space-saving syntax
1676    variant in parts of complex queries. Only the <literal>WITH</literal>,
1677    <literal>UNION</literal>, <literal>INTERSECT</literal>, <literal>EXCEPT</literal>,
1678    <literal>ORDER BY</literal>, <literal>LIMIT</literal>, <literal>OFFSET</literal>,
1679    <literal>FETCH</literal> and <literal>FOR</literal> locking clauses can be used
1680    with <command>TABLE</command>; the <literal>WHERE</literal> clause and any form of
1681    aggregation cannot
1682    be used.
1683   </para>
1684  </refsect2>
1685 </refsect1>
1686
1687 <refsect1>
1688  <title>Examples</title>
1689
1690  <para>
1691   To join the table <literal>films</literal> with the table
1692   <literal>distributors</literal>:
1693
1694<programlisting>
1695SELECT f.title, f.did, d.name, f.date_prod, f.kind
1696    FROM distributors d, films f
1697    WHERE f.did = d.did
1698
1699       title       | did |     name     | date_prod  |   kind
1700-------------------+-----+--------------+------------+----------
1701 The Third Man     | 101 | British Lion | 1949-12-23 | Drama
1702 The African Queen | 101 | British Lion | 1951-08-11 | Romantic
1703 ...
1704</programlisting>
1705  </para>
1706
1707  <para>
1708   To sum the column <literal>len</literal> of all films and group
1709   the results by <literal>kind</literal>:
1710
1711<programlisting>
1712SELECT kind, sum(len) AS total FROM films GROUP BY kind;
1713
1714   kind   | total
1715----------+-------
1716 Action   | 07:34
1717 Comedy   | 02:58
1718 Drama    | 14:28
1719 Musical  | 06:42
1720 Romantic | 04:38
1721</programlisting>
1722  </para>
1723
1724  <para>
1725   To sum the column <literal>len</literal> of all films, group
1726   the results by <literal>kind</literal> and show those group totals
1727   that are less than 5 hours:
1728
1729<programlisting>
1730SELECT kind, sum(len) AS total
1731    FROM films
1732    GROUP BY kind
1733    HAVING sum(len) &lt; interval '5 hours';
1734
1735   kind   | total
1736----------+-------
1737 Comedy   | 02:58
1738 Romantic | 04:38
1739</programlisting>
1740  </para>
1741
1742  <para>
1743   The following two examples are identical ways of sorting the individual
1744   results according to the contents of the second column
1745   (<literal>name</literal>):
1746
1747<programlisting>
1748SELECT * FROM distributors ORDER BY name;
1749SELECT * FROM distributors ORDER BY 2;
1750
1751 did |       name
1752-----+------------------
1753 109 | 20th Century Fox
1754 110 | Bavaria Atelier
1755 101 | British Lion
1756 107 | Columbia
1757 102 | Jean Luc Godard
1758 113 | Luso films
1759 104 | Mosfilm
1760 103 | Paramount
1761 106 | Toho
1762 105 | United Artists
1763 111 | Walt Disney
1764 112 | Warner Bros.
1765 108 | Westward
1766</programlisting>
1767  </para>
1768
1769  <para>
1770   The next example shows how to obtain the union of the tables
1771   <literal>distributors</literal> and
1772   <literal>actors</literal>, restricting the results to those that begin
1773   with the letter W in each table.  Only distinct rows are wanted, so the
1774   key word <literal>ALL</literal> is omitted.
1775
1776<programlisting>
1777distributors:               actors:
1778 did |     name              id |     name
1779-----+--------------        ----+----------------
1780 108 | Westward               1 | Woody Allen
1781 111 | Walt Disney            2 | Warren Beatty
1782 112 | Warner Bros.           3 | Walter Matthau
1783 ...                         ...
1784
1785SELECT distributors.name
1786    FROM distributors
1787    WHERE distributors.name LIKE 'W%'
1788UNION
1789SELECT actors.name
1790    FROM actors
1791    WHERE actors.name LIKE 'W%';
1792
1793      name
1794----------------
1795 Walt Disney
1796 Walter Matthau
1797 Warner Bros.
1798 Warren Beatty
1799 Westward
1800 Woody Allen
1801</programlisting>
1802  </para>
1803
1804  <para>
1805   This example shows how to use a function in the <literal>FROM</literal>
1806   clause, both with and without a column definition list:
1807
1808<programlisting>
1809CREATE FUNCTION distributors(int) RETURNS SETOF distributors AS $$
1810    SELECT * FROM distributors WHERE did = $1;
1811$$ LANGUAGE SQL;
1812
1813SELECT * FROM distributors(111);
1814 did |    name
1815-----+-------------
1816 111 | Walt Disney
1817
1818CREATE FUNCTION distributors_2(int) RETURNS SETOF record AS $$
1819    SELECT * FROM distributors WHERE did = $1;
1820$$ LANGUAGE SQL;
1821
1822SELECT * FROM distributors_2(111) AS (f1 int, f2 text);
1823 f1  |     f2
1824-----+-------------
1825 111 | Walt Disney
1826</programlisting>
1827  </para>
1828
1829  <para>
1830   Here is an example of a function with an ordinality column added:
1831
1832<programlisting>
1833SELECT * FROM unnest(ARRAY['a','b','c','d','e','f']) WITH ORDINALITY;
1834 unnest | ordinality
1835--------+----------
1836 a      |        1
1837 b      |        2
1838 c      |        3
1839 d      |        4
1840 e      |        5
1841 f      |        6
1842(6 rows)
1843</programlisting>
1844  </para>
1845
1846  <para>
1847   This example shows how to use a simple <literal>WITH</literal> clause:
1848
1849<programlisting>
1850WITH t AS (
1851    SELECT random() as x FROM generate_series(1, 3)
1852  )
1853SELECT * FROM t
1854UNION ALL
1855SELECT * FROM t
1856
1857         x
1858--------------------
1859  0.534150459803641
1860  0.520092216785997
1861 0.0735620250925422
1862  0.534150459803641
1863  0.520092216785997
1864 0.0735620250925422
1865</programlisting>
1866
1867   Notice that the <literal>WITH</literal> query was evaluated only once,
1868   so that we got two sets of the same three random values.
1869  </para>
1870
1871  <para>
1872   This example uses <literal>WITH RECURSIVE</literal> to find all
1873   subordinates (direct or indirect) of the employee Mary, and their
1874   level of indirectness, from a table that shows only direct
1875   subordinates:
1876
1877<programlisting>
1878WITH RECURSIVE employee_recursive(distance, employee_name, manager_name) AS (
1879    SELECT 1, employee_name, manager_name
1880    FROM employee
1881    WHERE manager_name = 'Mary'
1882  UNION ALL
1883    SELECT er.distance + 1, e.employee_name, e.manager_name
1884    FROM employee_recursive er, employee e
1885    WHERE er.employee_name = e.manager_name
1886  )
1887SELECT distance, employee_name FROM employee_recursive;
1888</programlisting>
1889
1890   Notice the typical form of recursive queries:
1891   an initial condition, followed by <literal>UNION</literal>,
1892   followed by the recursive part of the query. Be sure that the
1893   recursive part of the query will eventually return no tuples, or
1894   else the query will loop indefinitely.  (See <xref linkend="queries-with"/>
1895   for more examples.)
1896  </para>
1897
1898  <para>
1899   This example uses <literal>LATERAL</literal> to apply a set-returning function
1900   <function>get_product_names()</function> for each row of the
1901   <structname>manufacturers</structname> table:
1902
1903<programlisting>
1904SELECT m.name AS mname, pname
1905FROM manufacturers m, LATERAL get_product_names(m.id) pname;
1906</programlisting>
1907
1908    Manufacturers not currently having any products would not appear in the
1909    result, since it is an inner join.  If we wished to include the names of
1910    such manufacturers in the result, we could do:
1911
1912<programlisting>
1913SELECT m.name AS mname, pname
1914FROM manufacturers m LEFT JOIN LATERAL get_product_names(m.id) pname ON true;
1915</programlisting></para>
1916 </refsect1>
1917
1918 <refsect1>
1919  <title>Compatibility</title>
1920
1921  <para>
1922   Of course, the <command>SELECT</command> statement is compatible
1923   with the SQL standard.  But there are some extensions and some
1924   missing features.
1925  </para>
1926
1927  <refsect2>
1928   <title>Omitted <literal>FROM</literal> Clauses</title>
1929
1930   <para>
1931    <productname>PostgreSQL</productname> allows one to omit the
1932    <literal>FROM</literal> clause.  It has a straightforward use to
1933    compute the results of simple expressions:
1934<programlisting>
1935SELECT 2+2;
1936
1937 ?column?
1938----------
1939        4
1940</programlisting>
1941    Some other <acronym>SQL</acronym> databases cannot do this except
1942    by introducing a dummy one-row table from which to do the
1943    <command>SELECT</command>.
1944   </para>
1945
1946   <para>
1947    Note that if a <literal>FROM</literal> clause is not specified,
1948    the query cannot reference any database tables. For example, the
1949    following query is invalid:
1950<programlisting>
1951SELECT distributors.* WHERE distributors.name = 'Westward';
1952</programlisting><productname>PostgreSQL</productname> releases prior to
1953    8.1 would accept queries of this form, and add an implicit entry
1954    to the query's <literal>FROM</literal> clause for each table
1955    referenced by the query. This is no longer allowed.
1956   </para>
1957  </refsect2>
1958
1959  <refsect2>
1960   <title>Empty <literal>SELECT</literal> Lists</title>
1961
1962   <para>
1963    The list of output expressions after <literal>SELECT</literal> can be
1964    empty, producing a zero-column result table.
1965    This is not valid syntax according to the SQL standard.
1966    <productname>PostgreSQL</productname> allows it to be consistent with
1967    allowing zero-column tables.
1968    However, an empty list is not allowed when <literal>DISTINCT</literal> is used.
1969   </para>
1970  </refsect2>
1971
1972  <refsect2>
1973   <title>Omitting the <literal>AS</literal> Key Word</title>
1974
1975   <para>
1976    In the SQL standard, the optional key word <literal>AS</literal> can be
1977    omitted before an output column name whenever the new column name
1978    is a valid column name (that is, not the same as any reserved
1979    keyword).  <productname>PostgreSQL</productname> is slightly more
1980    restrictive: <literal>AS</literal> is required if the new column name
1981    matches any keyword at all, reserved or not.  Recommended practice is
1982    to use <literal>AS</literal> or double-quote output column names, to prevent
1983    any possible conflict against future keyword additions.
1984   </para>
1985
1986   <para>
1987    In <literal>FROM</literal> items, both the standard and
1988    <productname>PostgreSQL</productname> allow <literal>AS</literal> to
1989    be omitted before an alias that is an unreserved keyword.  But
1990    this is impractical for output column names, because of syntactic
1991    ambiguities.
1992   </para>
1993  </refsect2>
1994
1995  <refsect2>
1996   <title><literal>ONLY</literal> and Inheritance</title>
1997
1998   <para>
1999    The SQL standard requires parentheses around the table name when
2000    writing <literal>ONLY</literal>, for example <literal>SELECT * FROM ONLY
2001    (tab1), ONLY (tab2) WHERE ...</literal>.  <productname>PostgreSQL</productname>
2002    considers these parentheses to be optional.
2003   </para>
2004
2005   <para>
2006    <productname>PostgreSQL</productname> allows a trailing <literal>*</literal> to be written to
2007    explicitly specify the non-<literal>ONLY</literal> behavior of including
2008    child tables.  The standard does not allow this.
2009   </para>
2010
2011   <para>
2012    (These points apply equally to all SQL commands supporting the
2013    <literal>ONLY</literal> option.)
2014   </para>
2015  </refsect2>
2016
2017  <refsect2>
2018   <title><literal>TABLESAMPLE</literal> Clause Restrictions</title>
2019
2020   <para>
2021    The <literal>TABLESAMPLE</literal> clause is currently accepted only on
2022    regular tables and materialized views.  According to the SQL standard
2023    it should be possible to apply it to any <literal>FROM</literal> item.
2024   </para>
2025  </refsect2>
2026
2027  <refsect2>
2028   <title>Function Calls in <literal>FROM</literal></title>
2029
2030   <para>
2031    <productname>PostgreSQL</productname> allows a function call to be
2032    written directly as a member of the <literal>FROM</literal> list.  In the SQL
2033    standard it would be necessary to wrap such a function call in a
2034    sub-<command>SELECT</command>; that is, the syntax
2035    <literal>FROM <replaceable>func</replaceable>(...) <replaceable>alias</replaceable></literal>
2036    is approximately equivalent to
2037    <literal>FROM LATERAL (SELECT <replaceable>func</replaceable>(...)) <replaceable>alias</replaceable></literal>.
2038    Note that <literal>LATERAL</literal> is considered to be implicit; this is
2039    because the standard requires <literal>LATERAL</literal> semantics for an
2040    <literal>UNNEST()</literal> item in <literal>FROM</literal>.
2041    <productname>PostgreSQL</productname> treats <literal>UNNEST()</literal> the
2042    same as other set-returning functions.
2043   </para>
2044  </refsect2>
2045
2046  <refsect2>
2047   <title>Namespace Available to <literal>GROUP BY</literal> and <literal>ORDER BY</literal></title>
2048
2049   <para>
2050    In the SQL-92 standard, an <literal>ORDER BY</literal> clause can
2051    only use output column names or numbers, while a <literal>GROUP
2052    BY</literal> clause can only use expressions based on input column
2053    names.  <productname>PostgreSQL</productname> extends each of
2054    these clauses to allow the other choice as well (but it uses the
2055    standard's interpretation if there is ambiguity).
2056    <productname>PostgreSQL</productname> also allows both clauses to
2057    specify arbitrary expressions.  Note that names appearing in an
2058    expression will always be taken as input-column names, not as
2059    output-column names.
2060   </para>
2061
2062   <para>
2063    SQL:1999 and later use a slightly different definition which is not
2064    entirely upward compatible with SQL-92.
2065    In most cases, however, <productname>PostgreSQL</productname>
2066    will interpret an <literal>ORDER BY</literal> or <literal>GROUP
2067    BY</literal> expression the same way SQL:1999 does.
2068   </para>
2069  </refsect2>
2070
2071  <refsect2>
2072   <title>Functional Dependencies</title>
2073
2074   <para>
2075    <productname>PostgreSQL</productname> recognizes functional dependency
2076    (allowing columns to be omitted from <literal>GROUP BY</literal>) only when
2077    a table's primary key is included in the <literal>GROUP BY</literal> list.
2078    The SQL standard specifies additional conditions that should be
2079    recognized.
2080   </para>
2081  </refsect2>
2082
2083  <refsect2>
2084   <title><literal>LIMIT</literal> and <literal>OFFSET</literal></title>
2085
2086   <para>
2087    The clauses <literal>LIMIT</literal> and <literal>OFFSET</literal>
2088    are <productname>PostgreSQL</productname>-specific syntax, also
2089    used by <productname>MySQL</productname>.  The SQL:2008 standard
2090    has introduced the clauses <literal>OFFSET ... FETCH {FIRST|NEXT}
2091    ...</literal> for the same functionality, as shown above
2092    in <xref linkend="sql-limit"/>.  This
2093    syntax is also used by <productname>IBM DB2</productname>.
2094    (Applications written for <productname>Oracle</productname>
2095    frequently use a workaround involving the automatically
2096    generated <literal>rownum</literal> column, which is not available in
2097    PostgreSQL, to implement the effects of these clauses.)
2098   </para>
2099  </refsect2>
2100
2101  <refsect2>
2102   <title><literal>FOR NO KEY UPDATE</literal>, <literal>FOR UPDATE</literal>, <literal>FOR SHARE</literal>, <literal>FOR KEY SHARE</literal></title>
2103
2104   <para>
2105    Although <literal>FOR UPDATE</literal> appears in the SQL standard, the
2106    standard allows it only as an option of <command>DECLARE CURSOR</command>.
2107    <productname>PostgreSQL</productname> allows it in any <command>SELECT</command>
2108    query as well as in sub-<command>SELECT</command>s, but this is an extension.
2109    The <literal>FOR NO KEY UPDATE</literal>, <literal>FOR SHARE</literal> and
2110    <literal>FOR KEY SHARE</literal> variants, as well as the <literal>NOWAIT</literal>
2111    and <literal>SKIP LOCKED</literal> options, do not appear in the
2112    standard.
2113   </para>
2114  </refsect2>
2115
2116  <refsect2>
2117   <title>Data-Modifying Statements in <literal>WITH</literal></title>
2118
2119   <para>
2120    <productname>PostgreSQL</productname> allows <command>INSERT</command>,
2121    <command>UPDATE</command>, and <command>DELETE</command> to be used as <literal>WITH</literal>
2122    queries.  This is not found in the SQL standard.
2123   </para>
2124  </refsect2>
2125
2126  <refsect2>
2127   <title>Nonstandard Clauses</title>
2128
2129   <para>
2130    <literal>DISTINCT ON ( ... )</literal> is an extension of the
2131    SQL standard.
2132   </para>
2133
2134   <para>
2135    <literal>ROWS FROM( ... )</literal> is an extension of the SQL standard.
2136   </para>
2137
2138   <para>
2139    The <literal>MATERIALIZED</literal> and <literal>NOT
2140    MATERIALIZED</literal> options of <literal>WITH</literal> are extensions
2141    of the SQL standard.
2142   </para>
2143  </refsect2>
2144
2145 </refsect1>
2146</refentry>
2147