1SELECT(7)                        SQL Commands                        SELECT(7)
2
3
4

NAME

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

SYNOPSIS

10       [ WITH [ RECURSIVE ] with_query [, ...] ]
11       SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ]
12           * | expression [ [ AS ] output_name ] [, ...]
13           [ FROM from_item [, ...] ]
14           [ WHERE condition ]
15           [ GROUP BY expression [, ...] ]
16           [ HAVING condition [, ...] ]
17           [ WINDOW window_name AS ( window_definition ) [, ...] ]
18           [ { UNION | INTERSECT | EXCEPT } [ ALL ] select ]
19           [ ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...] ]
20           [ LIMIT { count | ALL } ]
21           [ OFFSET start [ ROW | ROWS ] ]
22           [ FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } ONLY ]
23           [ FOR { UPDATE | SHARE } [ OF table_name [, ...] ] [ NOWAIT ] [...] ]
24
25       where from_item can be one of:
26
27           [ ONLY ] table_name [ * ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
28           ( select ) [ AS ] alias [ ( column_alias [, ...] ) ]
29           with_query_name [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
30           function_name ( [ argument [, ...] ] ) [ AS ] alias [ ( column_alias [, ...] | column_definition [, ...] ) ]
31           function_name ( [ argument [, ...] ] ) AS ( column_definition [, ...] )
32           from_item [ NATURAL ] join_type from_item [ ON join_condition | USING ( join_column [, ...] ) ]
33
34       and with_query is:
35
36           with_query_name [ ( column_name [, ...] ) ] AS ( select )
37
38       TABLE { [ ONLY ] table_name [ * ] | with_query_name }
39
40

DESCRIPTION

42       SELECT retrieves rows from zero or more tables.  The general processing
43       of SELECT is as follows:
44
45       1.     All queries in the WITH list are  computed.   These  effectively
46              serve  as  temporary  tables  that can be referenced in the FROM
47              list. A WITH query that is referenced more than once in FROM  is
48              computed only once.  (See WITH Clause [select(7)] below.)
49
50       2.     All  elements  in  the FROM list are computed.  (Each element in
51              the FROM list is a real or virtual table.) If more than one ele‐
52              ment  is  specified  in  the  FROM  list,  they are cross-joined
53              together.  (See FROM Clause [select(7)] below.)
54
55       3.     If the WHERE clause is specified, all rows that do  not  satisfy
56              the  condition are eliminated from the output. (See WHERE Clause
57              [select(7)] below.)
58
59       4.     If the GROUP BY clause is specified, the output is divided  into
60              groups  of  rows that match on one or more values. If the HAVING
61              clause is present, it eliminates groups that do not satisfy  the
62              given  condition.  (See  GROUP  BY Clause [select(7)] and HAVING
63              Clause [select(7)] below.)
64
65       5.     The actual output rows are  computed  using  the  SELECT  output
66              expressions  for each selected row. (See SELECT List [select(7)]
67              below.)
68
69       6.     Using the operators UNION, INTERSECT, and EXCEPT, the output  of
70              more  than one SELECT statement can be combined to form a single
71              result set. The UNION operator returns all rows that are in  one
72              or  both  of the result sets. The INTERSECT operator returns all
73              rows that are strictly in both result sets. The EXCEPT  operator
74              returns the rows that are in the first result set but not in the
75              second. In all three cases, duplicate rows are eliminated unless
76              ALL  is  specified.  (See  UNION  Clause  [select(7)], INTERSECT
77              Clause [select(7)], and EXCEPT Clause [select(7)] below.)
78
79       7.     If the ORDER BY clause  is  specified,  the  returned  rows  are
80              sorted  in  the  specified  order. If ORDER BY is not given, the
81              rows are returned in whatever order the system finds fastest  to
82              produce. (See ORDER BY Clause [select(7)] below.)
83
84       8.     DISTINCT  eliminates duplicate rows from the result. DISTINCT ON
85              eliminates rows that match on all the specified expressions. ALL
86              (the  default)  will return all candidate rows, including dupli‐
87              cates. (See DISTINCT Clause [select(7)] below.)
88
89       9.     If the LIMIT (or FETCH FIRST) or OFFSET clause is specified, the
90              SELECT  statement only returns a subset of the result rows. (See
91              LIMIT Clause [select(7)] below.)
92
93       10.    If FOR UPDATE or FOR SHARE is specified,  the  SELECT  statement
94              locks  the  selected  rows  against concurrent updates. (See FOR
95              UPDATE/FOR SHARE Clause [select(7)] below.)
96
97       You must have SELECT privilege on each column used in a SELECT command.
98       The  use  of  FOR UPDATE or FOR SHARE requires UPDATE privilege as well
99       (for at least one column of each table so selected).
100

PARAMETERS

102   WITH CLAUSE
103       The WITH clause allows you to specify one or more subqueries  that  can
104       be referenced by name in the primary query.  The subqueries effectively
105       act as temporary tables or views for the duration of the primary query.
106
107       A name (without schema qualification) must be specified for  each  WITH
108       query.  Optionally, a list of column names can be specified; if this is
109       omitted, the column names are inferred from the subquery.
110
111       If RECURSIVE is specified, it allows a subquery to reference itself  by
112       name. Such a subquery must have the form
113
114       non_recursive_term UNION [ ALL ] recursive_term
115
116       where  the  recursive self-reference must appear on the right-hand side
117       of the UNION. Only one recursive self-reference is permitted per query.
118
119       Another effect of RECURSIVE is that WITH queries need not be ordered: a
120       query  can  reference  another one that is later in the list. (However,
121       circular references, or mutual recursion, are not implemented.)   With‐
122       out  RECURSIVE,  WITH  queries  can only reference sibling WITH queries
123       that are earlier in the WITH list.
124
125       A useful property of WITH queries is that they are evaluated only  once
126       per execution of the primary query, even if the primary query refers to
127       them more than once.
128
129       See in the documentation for additional information.
130
131   FROM CLAUSE
132       The FROM clause specifies one or more source tables for the SELECT.  If
133       multiple  sources  are  specified,  the result is the Cartesian product
134       (cross join) of all the sources. But usually  qualification  conditions
135       are added to restrict the returned rows to a small subset of the Carte‐
136       sian product.
137
138       The FROM clause can contain the following elements:
139
140       table_name
141              The name (optionally schema-qualified) of an existing  table  or
142              view.  If ONLY is specified before the table name, only that ta‐
143              ble is scanned. If ONLY is not specified, the table and all  its
144              descendant  tables  (if  any)  are scanned. Optionally, * can be
145              specified after the  table  name  to  explicitly  indicate  that
146              descendant tables are included.
147
148       alias  A  substitute  name  for  the FROM item containing the alias. An
149              alias is used for brevity or to eliminate  ambiguity  for  self-
150              joins  (where the same table is scanned multiple times). When an
151              alias is provided, it completely hides the actual  name  of  the
152              table  or function; for example given FROM foo AS f, the remain‐
153              der of the SELECT must refer to this FROM item as f not foo.  If
154              an  alias is written, a column alias list can also be written to
155              provide substitute names for one or more columns of the table.
156
157       select A sub-SELECT can appear in the FROM clause. This acts as  though
158              its output were created as a temporary table for the duration of
159              this single SELECT command. Note that  the  sub-SELECT  must  be
160              surrounded by parentheses, and an alias must be provided for it.
161              A VALUES [values(7)] command can also be used here.
162
163       with_query_name
164              A WITH query is referenced by writing its name, just  as  though
165              the  query's  name  were  a table name. (In fact, the WITH query
166              hides any real table of the same name for the  purposes  of  the
167              primary  query.  If  necessary, you can refer to a real table of
168              the same name by schema-qualifying the table's name.)  An  alias
169              can be provided in the same way as for a table.
170
171       function_name
172              Function  calls  can  appear  in the FROM clause. (This is espe‐
173              cially useful for functions that return  result  sets,  but  any
174              function  can be used.) This acts as though its output were cre‐
175              ated as a temporary table for the duration of this single SELECT
176              command.  An  alias  can also be used. If an alias is written, a
177              column alias list can also  be  written  to  provide  substitute
178              names  for  one  or  more attributes of the function's composite
179              return type. If the function has been defined as  returning  the
180              record  data  type,  then  an  alias  or the key word AS must be
181              present, followed by a column definition list in the form ( col‐
182              umn_name  data_type  [, ... ] ). The column definition list must
183              match the actual number and types of  columns  returned  by  the
184              function.
185
186       join_type
187              One of
188
189              · [ INNER ] JOIN
190
191              · LEFT [ OUTER ] JOIN
192
193              · RIGHT [ OUTER ] JOIN
194
195              · FULL [ OUTER ] JOIN
196
197              · CROSS JOIN
198
199       For the INNER and OUTER join types, a join condition must be specified,
200       namely exactly one of NATURAL, ON join_condition, or USING (join_column
201       [,  ...]).   See  below  for the meaning. For CROSS JOIN, none of these
202       clauses can appear.
203
204       A JOIN clause combines two FROM items. Use parentheses if necessary  to
205       determine  the  order  of nesting. In the absence of parentheses, JOINs
206       nest left-to-right. In any case JOIN binds more tightly than the commas
207       separating FROM items.
208
209       CROSS  JOIN and INNER JOIN produce a simple Cartesian product, the same
210       result as you get from listing the two items at the top level of  FROM,
211       but  restricted  by the join condition (if any).  CROSS JOIN is equiva‐
212       lent to INNER JOIN ON (TRUE), that is, no rows are removed by  qualifi‐
213       cation.  These join types are just a notational convenience, since they
214       do nothing you couldn't do with plain FROM and WHERE.
215
216       LEFT OUTER JOIN returns all rows in  the  qualified  Cartesian  product
217       (i.e.,  all  combined rows that pass its join condition), plus one copy
218       of each row in the left-hand table for which there  was  no  right-hand
219       row  that  passed the join condition. This left-hand row is extended to
220       the full width of the joined table by inserting  null  values  for  the
221       right-hand  columns.  Note that only the JOIN clause's own condition is
222       considered while deciding which rows have matches. Outer conditions are
223       applied afterwards.
224
225       Conversely,  RIGHT OUTER JOIN returns all the joined rows, plus one row
226       for each unmatched right-hand row (extended with nulls  on  the  left).
227       This  is just a notational convenience, since you could convert it to a
228       LEFT OUTER JOIN by switching the left and right inputs.
229
230       FULL OUTER JOIN returns all the joined rows,  plus  one  row  for  each
231       unmatched  left-hand  row  (extended with nulls on the right), plus one
232       row for each unmatched right-hand  row  (extended  with  nulls  on  the
233       left).
234
235       ON join_condition
236              join_condition  is  an  expression  resulting in a value of type
237              boolean (similar to a WHERE clause) that specifies which rows in
238              a join are considered to match.
239
240       USING ( join_column [, ...] )
241              A  clause  of  the  form USING ( a, b, ... ) is shorthand for ON
242              left_table.a = right_table.a AND  left_table.b  =  right_table.b
243              ....  Also,  USING implies that only one of each pair of equiva‐
244              lent columns will be included in the join output, not both.
245
246       NATURAL
247              NATURAL is shorthand for a USING list that mentions all  columns
248              in the two tables that have the same names.
249
250   WHERE CLAUSE
251       The optional WHERE clause has the general form
252
253       WHERE condition
254
255       where  condition  is  any expression that evaluates to a result of type
256       boolean. Any row that does not satisfy this condition  will  be  elimi‐
257       nated from the output. A row satisfies the condition if it returns true
258       when the actual row values are substituted for any variable references.
259
260   GROUP BY CLAUSE
261       The optional GROUP BY clause has the general form
262
263       GROUP BY expression [, ...]
264
265
266       GROUP BY will condense into a single row all selected rows  that  share
267       the same values for the grouped expressions. expression can be an input
268       column name, or the name or ordinal number of an output column  (SELECT
269       list item), or an arbitrary expression formed from input-column values.
270       In case of ambiguity, a GROUP BY name will be interpreted as an  input-
271       column name rather than an output column name.
272
273       Aggregate functions, if any are used, are computed across all rows mak‐
274       ing up each group, producing a separate value for each  group  (whereas
275       without  GROUP BY, an aggregate produces a single value computed across
276       all the selected rows).  When GROUP BY is present, it is not valid  for
277       the SELECT list expressions to refer to ungrouped columns except within
278       aggregate functions, since there would be more than one possible  value
279       to return for an ungrouped column.
280
281   HAVING CLAUSE
282       The optional HAVING clause has the general form
283
284       HAVING condition
285
286       where condition is the same as specified for the WHERE clause.
287
288       HAVING  eliminates group rows that do not satisfy the condition. HAVING
289       is different from WHERE:  WHERE  filters  individual  rows  before  the
290       application  of  GROUP  BY,  while HAVING filters group rows created by
291       GROUP BY. Each column referenced in condition must unambiguously refer‐
292       ence  a  grouping column, unless the reference appears within an aggre‐
293       gate function.
294
295       The presence of HAVING turns a query into a grouped query even if there
296       is  no GROUP BY clause. This is the same as what happens when the query
297       contains aggregate functions but no GROUP BY clause. All  the  selected
298       rows  are  considered  to  form a single group, and the SELECT list and
299       HAVING clause can only reference table columns  from  within  aggregate
300       functions.  Such a query will emit a single row if the HAVING condition
301       is true, zero rows if it is not true.
302
303   WINDOW CLAUSE
304       The optional WINDOW clause has the general form
305
306       WINDOW window_name AS ( window_definition ) [, ...]
307
308       where window_name is a name that can be referenced from OVER clauses or
309       subsequent window definitions, and window_definition is
310
311       [ existing_window_name ]
312       [ PARTITION BY expression [, ...] ]
313       [ ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...] ]
314       [ frame_clause ]
315
316
317       If  an  existing_window_name  is  specified it must refer to an earlier
318       entry in the WINDOW list; the new window copies its partitioning clause
319       from  that  entry,  as well as its ordering clause if any. In this case
320       the new window cannot specify its own PARTITION BY clause, and  it  can
321       specify  ORDER BY only if the copied window does not have one.  The new
322       window always uses its own frame clause; the  copied  window  must  not
323       specify a frame clause.
324
325       The  elements of the PARTITION BY list are interpreted in much the same
326       fashion as elements of a GROUP BY Clause [select(7)], except that  they
327       are always simple expressions and never the name or number of an output
328       column.  Another difference  is  that  these  expressions  can  contain
329       aggregate  function  calls, which are not allowed in a regular GROUP BY
330       clause. They are allowed here because windowing occurs  after  grouping
331       and aggregation.
332
333       Similarly,  the  elements  of the ORDER BY list are interpreted in much
334       the same fashion as elements of an ORDER BY Clause [select(7)],  except
335       that  the  expressions are always taken as simple expressions and never
336       the name or number of an output column.
337
338       The optional frame_clause defines the window frame for window functions
339       that depend on the frame (not all do). It can be one of
340
341       RANGE UNBOUNDED PRECEDING
342       RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
343       RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
344       ROWS UNBOUNDED PRECEDING
345       ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW
346       ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
347
348       The  first  two  are  equivalent and are also the default: they set the
349       frame to be all rows from the partition start up  through  the  current
350       row's last peer in the ORDER BY ordering (which means all rows if there
351       is no ORDER BY). The options  RANGE  BETWEEN  UNBOUNDED  PRECEDING  AND
352       UNBOUNDED  FOLLOWING and ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED
353       FOLLOWING are also equivalent: they always select all rows in the  par‐
354       tition.   Lastly,  ROWS  UNBOUNDED  PRECEDING or its verbose equivalent
355       ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW  select  all  rows  up
356       through  the  current row (regardless of duplicates).  Beware that this
357       option can produce implementation-dependent results  if  the  ORDER  BY
358       ordering does not order the rows uniquely.
359
360       The  purpose  of  a  WINDOW clause is to specify the behavior of window
361       functions appearing in the query's SELECT List [select(7)] or ORDER  BY
362       Clause  [select(7)].  These  functions  can reference the WINDOW clause
363       entries by name in their OVER clauses. A WINDOW clause entry  does  not
364       have to be referenced anywhere, however; if it is not used in the query
365       it is simply ignored. It is possible to use  window  functions  without
366       any  WINDOW clause at all, since a window function call can specify its
367       window definition directly in its  OVER  clause.  However,  the  WINDOW
368       clause  saves typing when the same window definition is needed for more
369       than one window function.
370
371       Window functions are described in detail in in  the  documentation,  in
372       the documentation, and in the documentation.
373
374   SELECT LIST
375       The  SELECT  list  (between  the  key  words SELECT and FROM) specifies
376       expressions that form the output rows  of  the  SELECT  statement.  The
377       expressions  can (and usually do) refer to columns computed in the FROM
378       clause.
379
380       Just as in a table, every output column of a SELECT has a  name.  In  a
381       simple  SELECT  this name is just used to label the column for display,
382       but when the SELECT is a sub-query of a larger query, the name is  seen
383       by the larger query as the column name of the virtual table produced by
384       the sub-query.  To specify the name to use for an output column,  write
385       AS  output_name  after  the  column's expression. (You can omit AS, but
386       only if the desired output name does not match any  PostgreSQL  keyword
387       (see in the documentation). For protection against possible future key‐
388       word additions, it is recommended that you always either  write  AS  or
389       double-quote  the output name.)  If you do not specify a column name, a
390       name is chosen automatically by PostgreSQL. If the column's  expression
391       is  a  simple column reference then the chosen name is the same as that
392       column's name; in more complex cases  a  generated  name  looking  like
393       ?columnN? is usually chosen.
394
395       An  output  column's name can be used to refer to the column's value in
396       ORDER BY and GROUP BY clauses, but not in the WHERE or HAVING  clauses;
397       there you must write out the expression instead.
398
399       Instead  of  an  expression,  *  can be written in the output list as a
400       shorthand for all the columns of the selected rows. Also, you can write
401       table_name.*  as  a shorthand for the columns coming from just that ta‐
402       ble. In these cases it is not possible to specify new  names  with  AS;
403       the output column names will be the same as the table columns' names.
404
405   UNION CLAUSE
406       The UNION clause has this general form:
407
408       select_statement UNION [ ALL ] select_statement
409
410       select_statement  is  any  SELECT statement without an ORDER BY, LIMIT,
411       FOR UPDATE, or FOR SHARE clause.  (ORDER BY and LIMIT can  be  attached
412       to  a subexpression if it is enclosed in parentheses. Without parenthe‐
413       ses, these clauses will be taken to apply to the result of  the  UNION,
414       not to its right-hand input expression.)
415
416       The  UNION  operator computes the set union of the rows returned by the
417       involved SELECT statements. A row is in the set  union  of  two  result
418       sets  if  it appears in at least one of the result sets. The two SELECT
419       statements that represent the direct operands of the UNION must produce
420       the  same  number of columns, and corresponding columns must be of com‐
421       patible data types.
422
423       The result of UNION does not contain any duplicate rows unless the  ALL
424       option  is  specified.  ALL prevents elimination of duplicates. (There‐
425       fore, UNION ALL is usually significantly quicker than  UNION;  use  ALL
426       when you can.)
427
428       Multiple  UNION  operators  in  the same SELECT statement are evaluated
429       left to right, unless otherwise indicated by parentheses.
430
431       Currently, FOR UPDATE and FOR SHARE cannot be specified  either  for  a
432       UNION result or for any input of a UNION.
433
434   INTERSECT CLAUSE
435       The INTERSECT clause has this general form:
436
437       select_statement INTERSECT [ ALL ] select_statement
438
439       select_statement  is  any  SELECT statement without an ORDER BY, LIMIT,
440       FOR UPDATE, or FOR SHARE clause.
441
442       The INTERSECT operator  computes  the  set  intersection  of  the  rows
443       returned  by  the involved SELECT statements. A row is in the intersec‐
444       tion of two result sets if it appears in both result sets.
445
446       The result of INTERSECT does not contain any duplicate rows unless  the
447       ALL  option is specified.  With ALL, a row that has m duplicates in the
448       left table and n duplicates in the right  table  will  appear  min(m,n)
449       times in the result set.
450
451       Multiple INTERSECT operators in the same SELECT statement are evaluated
452       left to right, unless parentheses dictate otherwise.   INTERSECT  binds
453       more tightly than UNION. That is, A UNION B INTERSECT C will be read as
454       A UNION (B INTERSECT C).
455
456       Currently, FOR UPDATE and FOR SHARE cannot be specified either  for  an
457       INTERSECT result or for any input of an INTERSECT.
458
459   EXCEPT CLAUSE
460       The EXCEPT clause has this general form:
461
462       select_statement EXCEPT [ ALL ] select_statement
463
464       select_statement  is  any  SELECT statement without an ORDER BY, LIMIT,
465       FOR UPDATE, or FOR SHARE clause.
466
467       The EXCEPT operator computes the set of rows that are in the result  of
468       the left SELECT statement but not in the result of the right one.
469
470       The result of EXCEPT does not contain any duplicate rows unless the ALL
471       option is specified.  With ALL, a row that has m duplicates in the left
472       table  and n duplicates in the right table will appear max(m-n,0) times
473       in the result set.
474
475       Multiple EXCEPT operators in the same SELECT  statement  are  evaluated
476       left  to  right,  unless parentheses dictate otherwise. EXCEPT binds at
477       the same level as UNION.
478
479       Currently, FOR UPDATE and FOR SHARE cannot be specified either  for  an
480       EXCEPT result or for any input of an EXCEPT.
481
482   ORDER BY CLAUSE
483       The optional ORDER BY clause has this general form:
484
485       ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...]
486
487       The  ORDER  BY  clause causes the result rows to be sorted according to
488       the specified expression(s). If two rows are  equal  according  to  the
489       leftmost expression, they are compared according to the next expression
490       and so on. If they are equal according to  all  specified  expressions,
491       they are returned in an implementation-dependent order.
492
493       Each  expression  can be the name or ordinal number of an output column
494       (SELECT list item), or it can be an arbitrary  expression  formed  from
495       input-column values.
496
497       The  ordinal  number  refers to the ordinal (left-to-right) position of
498       the output column. This feature makes it possible to define an ordering
499       on  the  basis  of  a  column that does not have a unique name. This is
500       never absolutely necessary because it is always possible  to  assign  a
501       name to an output column using the AS clause.
502
503       It  is  also  possible  to  use  arbitrary  expressions in the ORDER BY
504       clause, including columns that do not appear in the SELECT output list.
505       Thus the following statement is valid:
506
507       SELECT name FROM distributors ORDER BY code;
508
509       A limitation of this feature is that an ORDER BY clause applying to the
510       result of a UNION, INTERSECT, or EXCEPT clause can only specify an out‐
511       put column name or number, not an expression.
512
513       If  an ORDER BY expression is a simple name that matches both an output
514       column name and an input column name, ORDER BY will interpret it as the
515       output  column  name.  This is the opposite of the choice that GROUP BY
516       will make in the same situation. This inconsistency is made to be  com‐
517       patible with the SQL standard.
518
519       Optionally  one  can add the key word ASC (ascending) or DESC (descend‐
520       ing) after any expression in the ORDER BY clause. If not specified, ASC
521       is assumed by default. Alternatively, a specific ordering operator name
522       can be specified in the USING clause.  An ordering operator must  be  a
523       less-than  or  greater-than member of some B-tree operator family.  ASC
524       is usually equivalent to USING < and  DESC  is  usually  equivalent  to
525       USING  >.   (But  the  creator  of  a user-defined data type can define
526       exactly what the default sort ordering is, and it might  correspond  to
527       operators with other names.)
528
529       If NULLS LAST is specified, null values sort after all non-null values;
530       if NULLS FIRST is specified, null values sort before all non-null  val‐
531       ues.  If  neither is specified, the default behavior is NULLS LAST when
532       ASC is specified or implied, and NULLS FIRST  when  DESC  is  specified
533       (thus,  the  default  is  to  act  as though nulls are larger than non-
534       nulls).  When USING is specified, the default nulls ordering depends on
535       whether the operator is a less-than or greater-than operator.
536
537       Note  that  ordering  options apply only to the expression they follow;
538       for example ORDER BY x, y DESC does not mean the same thing as ORDER BY
539       x DESC, y DESC.
540
541       Character-string data is sorted according to the locale-specific colla‐
542       tion order that was established when the database was created.
543
544   DISTINCT CLAUSE
545       If DISTINCT is specified, all  duplicate  rows  are  removed  from  the
546       result  set (one row is kept from each group of duplicates). ALL speci‐
547       fies the opposite: all rows are kept; that is the default.
548
549       DISTINCT ON ( expression [, ...] ) keeps only the first row of each set
550       of  rows where the given expressions evaluate to equal. The DISTINCT ON
551       expressions are interpreted using the same rules as for ORDER  BY  (see
552       above). Note that the ``first row'' of each set is unpredictable unless
553       ORDER BY is used to ensure that the  desired  row  appears  first.  For
554       example:
555
556       SELECT DISTINCT ON (location) location, time, report
557           FROM weather_reports
558           ORDER BY location, time DESC;
559
560       retrieves  the  most recent weather report for each location. But if we
561       had not used ORDER BY to force descending order of time values for each
562       location, we'd have gotten a report from an unpredictable time for each
563       location.
564
565       The DISTINCT ON expression(s) must match the leftmost ORDER BY  expres‐
566       sion(s).  The  ORDER BY clause will normally contain additional expres‐
567       sion(s) that determine the desired precedence of rows within each  DIS‐
568       TINCT ON group.
569
570   LIMIT CLAUSE
571       The LIMIT clause consists of two independent sub-clauses:
572
573       LIMIT { count | ALL }
574       OFFSET start
575
576       count specifies the maximum number of rows to return, while start spec‐
577       ifies the number of rows to skip before starting to return  rows.  When
578       both are specified, start rows are skipped before starting to count the
579       count rows to be returned.
580
581       If the count expression evaluates to NULL, it is treated as LIMIT  ALL,
582       i.e.,  no  limit. If start evaluates to NULL, it is treated the same as
583       OFFSET 0.
584
585       SQL:2008 introduced a different syntax to achieve the same thing, which
586       PostgreSQL also supports. It is:
587
588       OFFSET start { ROW | ROWS }
589       FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } ONLY
590
591       Both  clauses  are optional, but if present the OFFSET clause must come
592       before the FETCH clause. ROW and ROWS as well as  FIRST  and  NEXT  are
593       noise  words that don't influence the effects of these clauses. In this
594       syntax, when using expressions other than simple constants for start or
595       count, parentheses will be necessary in most cases. If count is omitted
596       in FETCH, it defaults to 1.
597
598       When using LIMIT, it is a good idea to use an ORDER BY clause that con‐
599       strains  the result rows into a unique order. Otherwise you will get an
600       unpredictable subset of the query's rows — you might be asking for  the
601       tenth  through  twentieth  rows,  but  tenth  through twentieth in what
602       ordering? You don't know what ordering unless you specify ORDER BY.
603
604       The query planner takes LIMIT into  account  when  generating  a  query
605       plan, so you are very likely to get different plans (yielding different
606       row orders) depending on what you use for LIMIT and OFFSET. Thus, using
607       different  LIMIT/OFFSET  values  to select different subsets of a query
608       result will give inconsistent results unless you enforce a  predictable
609       result  ordering  with  ORDER  BY. This is not a bug; it is an inherent
610       consequence of the fact that  SQL  does  not  promise  to  deliver  the
611       results  of  a query in any particular order unless ORDER BY is used to
612       constrain the order.
613
614       It is even possible for repeated executions of the same LIMIT query  to
615       return  different  subsets  of  the rows of a table, if there is not an
616       ORDER BY to enforce selection of a deterministic subset. Again, this is
617       not  a bug; determinism of the results is simply not guaranteed in such
618       a case.
619
620   FOR UPDATE/FOR SHARE CLAUSE
621       The FOR UPDATE clause has this form:
622
623       FOR UPDATE [ OF table_name [, ...] ] [ NOWAIT ]
624
625
626       The closely related FOR SHARE clause has this form:
627
628       FOR SHARE [ OF table_name [, ...] ] [ NOWAIT ]
629
630
631       FOR UPDATE causes the rows retrieved by  the  SELECT  statement  to  be
632       locked  as though for update. This prevents them from being modified or
633       deleted by other transactions until the current transaction ends.  That
634       is,  other  transactions  that  attempt  UPDATE,  DELETE, or SELECT FOR
635       UPDATE of these rows will be  blocked  until  the  current  transaction
636       ends.   Also,  if  an UPDATE, DELETE, or SELECT FOR UPDATE from another
637       transaction has already locked a  selected  row  or  rows,  SELECT  FOR
638       UPDATE  will  wait for the other transaction to complete, and will then
639       lock and return the updated row (or no row, if the  row  was  deleted).
640       For further discussion see in the documentation.
641
642       To prevent the operation from waiting for other transactions to commit,
643       use the NOWAIT option. SELECT  FOR  UPDATE  NOWAIT  reports  an  error,
644       rather  than  waiting,  if a selected row cannot be locked immediately.
645       Note that NOWAIT applies only to the row-level lock(s) —  the  required
646       ROW  SHARE  table-level lock is still taken in the ordinary way (see in
647       the documentation). You can use the NOWAIT option of LOCK [lock(7)]  if
648       you need to acquire the table-level lock without waiting.
649
650       FOR  SHARE  behaves  similarly, except that it acquires a shared rather
651       than exclusive lock on each retrieved row. A shared lock  blocks  other
652       transactions  from  performing  UPDATE, DELETE, or SELECT FOR UPDATE on
653       these rows, but it does not prevent them  from  performing  SELECT  FOR
654       SHARE.
655
656       If specific tables are named in FOR UPDATE or FOR SHARE, then only rows
657       coming from those tables are locked;  any  other  tables  used  in  the
658       SELECT are simply read as usual. A FOR UPDATE or FOR SHARE clause with‐
659       out a table list affects all tables used in the command.  If FOR UPDATE
660       or  FOR  SHARE is applied to a view or sub-query, it affects all tables
661       used in the view or sub-query.  However, FOR UPDATE/FOR  SHARE  do  not
662       apply to WITH queries referenced by the primary query.  If you want row
663       locking to occur within a WITH query, specify FOR UPDATE or  FOR  SHARE
664       within the WITH query.
665
666       Multiple  FOR UPDATE and FOR SHARE clauses can be written if it is nec‐
667       essary to specify different locking behavior for different  tables.  If
668       the same table is mentioned (or implicitly affected) by both FOR UPDATE
669       and FOR SHARE clauses, then it is processed as FOR UPDATE. Similarly, a
670       table is processed as NOWAIT if that is specified in any of the clauses
671       affecting it.
672
673       FOR UPDATE and FOR SHARE cannot be used in contexts where returned rows
674       cannot  be  clearly  identified with individual table rows; for example
675       they cannot be used with aggregation.
676
677              Caution: Avoid locking a row and  then  modifying  it  within  a
678              later  savepoint or PL/pgSQL exception block. A subsequent roll‐
679              back would cause the lock to be lost. For example:
680
681              BEGIN;
682              SELECT * FROM mytable WHERE key = 1 FOR UPDATE;
683              SAVEPOINT s;
684              UPDATE mytable SET ... WHERE key = 1;
685              ROLLBACK TO s;
686
687              After the ROLLBACK, the row is effectively unlocked, rather than
688              returned to its pre-savepoint state of being locked but not mod‐
689              ified.  This hazard occurs if a row locked in the current trans‐
690              action is updated or deleted, or if a shared lock is upgraded to
691              exclusive: in all these cases, the former lock state is  forgot‐
692              ten.  If  the transaction is then rolled back to a state between
693              the original locking command and the subsequent change, the  row
694              will  appear  not to be locked at all. This is an implementation
695              deficiency which will be addressed in a future release of  Post‐
696              greSQL.
697
698
699              Caution:  It  is  possible for a SELECT command using both LIMIT
700              and FOR UPDATE/SHARE clauses to return fewer rows than specified
701              by  LIMIT.   This is because LIMIT is applied first. The command
702              selects the specified number of rows, but might then block  try‐
703              ing  to  obtain  a lock on one or more of them.  Once the SELECT
704              unblocks, the row might have been deleted or updated so that  it
705              does  not  meet the query WHERE condition anymore, in which case
706              it will not be returned.
707
708
709              Caution: Similarly, it is possible for a  SELECT  command  using
710              ORDER  BY and FOR UPDATE/SHARE to return rows out of order. This
711              is because ORDER BY is applied first.  The  command  orders  the
712              result,  but  might then block trying to obtain a lock on one or
713              more of the rows. Once the SELECT unblocks, one of  the  ordered
714              columns might have been modified and be returned out of order. A
715              workaround is to perform SELECT ... FOR  UPDATE/SHARE  and  then
716              SELECT ... ORDER BY.
717
718
719   TABLE COMMAND
720       The command
721
722       TABLE name
723
724       is completely equivalent to
725
726       SELECT * FROM name
727
728       It can be used as a top-level command or as a space-saving syntax vari‐
729       ant in parts of complex queries.
730

EXAMPLES

732       To join the table films with the table distributors:
733
734       SELECT f.title, f.did, d.name, f.date_prod, f.kind
735           FROM distributors d, films f
736           WHERE f.did = d.did
737
738              title       | did |     name     | date_prod  |   kind
739       -------------------+-----+--------------+------------+----------
740        The Third Man     | 101 | British Lion | 1949-12-23 | Drama
741        The African Queen | 101 | British Lion | 1951-08-11 | Romantic
742        ...
743
744
745       To sum the column len of all films and group the results by kind:
746
747       SELECT kind, sum(len) AS total FROM films GROUP BY kind;
748
749          kind   | total
750       ----------+-------
751        Action   | 07:34
752        Comedy   | 02:58
753        Drama    | 14:28
754        Musical  | 06:42
755        Romantic | 04:38
756
757
758       To sum the column len of all films, group the results by kind and  show
759       those group totals that are less than 5 hours:
760
761       SELECT kind, sum(len) AS total
762           FROM films
763           GROUP BY kind
764           HAVING sum(len) < interval '5 hours';
765
766          kind   | total
767       ----------+-------
768        Comedy   | 02:58
769        Romantic | 04:38
770
771
772       The following two examples are identical ways of sorting the individual
773       results according to the contents of the second column (name):
774
775       SELECT * FROM distributors ORDER BY name;
776       SELECT * FROM distributors ORDER BY 2;
777
778        did |       name
779       -----+------------------
780        109 | 20th Century Fox
781        110 | Bavaria Atelier
782        101 | British Lion
783        107 | Columbia
784        102 | Jean Luc Godard
785        113 | Luso films
786        104 | Mosfilm
787        103 | Paramount
788        106 | Toho
789        105 | United Artists
790        111 | Walt Disney
791        112 | Warner Bros.
792        108 | Westward
793
794
795       The next example shows how to obtain the union of the tables  distribu‐
796       tors  and  actors, restricting the results to those that begin with the
797       letter W in each table. Only distinct rows are wanted, so the key  word
798       ALL is omitted.
799
800       distributors:               actors:
801        did |     name              id |     name
802       -----+--------------        ----+----------------
803        108 | Westward               1 | Woody Allen
804        111 | Walt Disney            2 | Warren Beatty
805        112 | Warner Bros.           3 | Walter Matthau
806        ...                         ...
807
808       SELECT distributors.name
809           FROM distributors
810           WHERE distributors.name LIKE 'W%'
811       UNION
812       SELECT actors.name
813           FROM actors
814           WHERE actors.name LIKE 'W%';
815
816             name
817       ----------------
818        Walt Disney
819        Walter Matthau
820        Warner Bros.
821        Warren Beatty
822        Westward
823        Woody Allen
824
825
826       This  example shows how to use a function in the FROM clause, both with
827       and without a column definition list:
828
829       CREATE FUNCTION distributors(int) RETURNS SETOF distributors AS $$
830           SELECT * FROM distributors WHERE did = $1;
831       $$ LANGUAGE SQL;
832
833       SELECT * FROM distributors(111);
834        did |    name
835       -----+-------------
836        111 | Walt Disney
837
838       CREATE FUNCTION distributors_2(int) RETURNS SETOF record AS $$
839           SELECT * FROM distributors WHERE did = $1;
840       $$ LANGUAGE SQL;
841
842       SELECT * FROM distributors_2(111) AS (f1 int, f2 text);
843        f1  |     f2
844       -----+-------------
845        111 | Walt Disney
846
847
848       This example shows how to use a simple WITH clause:
849
850       WITH t AS (
851           SELECT random() as x FROM generate_series(1, 3)
852         )
853       SELECT * FROM t
854       UNION ALL
855       SELECT * FROM t
856
857                x
858       --------------------
859         0.534150459803641
860         0.520092216785997
861        0.0735620250925422
862         0.534150459803641
863         0.520092216785997
864        0.0735620250925422
865
866       Notice that the WITH query was evaluated only once, so that we got  two
867       sets of the same three random values.
868
869       This  example  uses  WITH RECURSIVE to find all subordinates (direct or
870       indirect) of the employee Mary, and their level of indirectness, from a
871       table that shows only direct subordinates:
872
873       WITH RECURSIVE employee_recursive(distance, employee_name, manager_name) AS (
874           SELECT 1, employee_name, manager_name
875           FROM employee
876           WHERE manager_name = 'Mary'
877         UNION ALL
878           SELECT er.distance + 1, e.employee_name, e.manager_name
879           FROM employee_recursive er, employee e
880           WHERE er.employee_name = e.manager_name
881         )
882       SELECT distance, employee_name FROM employee_recursive;
883
884       Notice  the  typical  form  of recursive queries: an initial condition,
885       followed by UNION, followed by the recursive part of the query. Be sure
886       that  the recursive part of the query will eventually return no tuples,
887       or else the query will loop indefinitely. (See in the documentation for
888       more examples.)
889

COMPATIBILITY

891       Of  course,  the  SELECT statement is compatible with the SQL standard.
892       But there are some extensions and some missing features.
893
894   OMITTED FROM CLAUSES
895       PostgreSQL allows one to omit the FROM clause. It has a straightforward
896       use to compute the results of simple expressions:
897
898       SELECT 2+2;
899
900        ?column?
901       ----------
902               4
903
904       Some  other  SQL databases cannot do this except by introducing a dummy
905       one-row table from which to do the SELECT.
906
907       Note that if a FROM clause is not specified, the query cannot reference
908       any database tables. For example, the following query is invalid:
909
910       SELECT distributors.* WHERE distributors.name = 'Westward';
911
912       PostgreSQL releases prior to 8.1 would accept queries of this form, and
913       add an implicit entry to the query's FROM clause for each table  refer‐
914       enced  by the query. This is no longer the default behavior, because it
915       does not comply with the SQL standard, and is considered by many to  be
916       error-prone.  For  compatibility  with  applications  that rely on this
917       behavior the add_missing_from configuration variable can be enabled.
918
919   OMITTING THE AS KEY WORD
920       In the SQL standard, the optional key word AS can be omitted before  an
921       output  column name whenever the new column name is a valid column name
922       (that is, not the same as any reserved keyword). PostgreSQL is slightly
923       more  restrictive:  AS  is  required if the new column name matches any
924       keyword at all, reserved or not. Recommended practice is to use  AS  or
925       double-quote  output  column  names,  to  prevent any possible conflict
926       against future keyword additions.
927
928       In FROM items, both the standard and PostgreSQL allow AS to be  omitted
929       before  an alias that is an unreserved keyword. But this is impractical
930       for output column names, because of syntactic ambiguities.
931
932   ONLY AND INHERITANCE
933       The SQL standard requires parentheses around the table name when  writ‐
934       ing ONLY, for example SELECT * FROM ONLY (tab1), ONLY (tab2) WHERE ....
935       PostgreSQL considers these parentheses to be optional.
936
937       PostgreSQL allows a trailing * to be written to explicitly specify  the
938       non-ONLY  behavior  of  including  child  tables. The standard does not
939       allow this.
940
941       (These points apply equally to all SQL  commands  supporting  the  ONLY
942       option.)
943
944   NAMESPACE AVAILABLE TO GROUP BY AND ORDER BY
945       In  the  SQL-92 standard, an ORDER BY clause can only use output column
946       names or numbers, while a GROUP BY  clause  can  only  use  expressions
947       based  on  input column names. PostgreSQL extends each of these clauses
948       to allow the other choice as well (but it uses the standard's interpre‐
949       tation  if there is ambiguity).  PostgreSQL also allows both clauses to
950       specify arbitrary expressions. Note that names appearing in an  expres‐
951       sion  will  always be taken as input-column names, not as output-column
952       names.
953
954       SQL:1999 and later use a slightly different  definition  which  is  not
955       entirely  upward compatible with SQL-92.  In most cases, however, Post‐
956       greSQL will interpret an ORDER BY or GROUP BY expression the  same  way
957       SQL:1999 does.
958
959   WINDOW CLAUSE RESTRICTIONS
960       The   SQL   standard   provides   additional  options  for  the  window
961       frame_clause.  PostgreSQL currently supports only  the  options  listed
962       above.
963
964   LIMIT AND OFFSET
965       The  clauses LIMIT and OFFSET are PostgreSQL-specific syntax, also used
966       by MySQL. The SQL:2008 standard has introduced the clauses  OFFSET  ...
967       FETCH  {FIRST|NEXT}  ...  for the same functionality, as shown above in
968       LIMIT Clause [select(7)], and this syntax is  also  used  by  IBM  DB2.
969       (Applications  written for Oracle frequently use a workaround involving
970       the automatically generated rownum column, not available in PostgreSQL,
971       to implement the effects of these clauses.)
972
973   NONSTANDARD CLAUSES
974       The clause DISTINCT ON is not defined in the SQL standard.
975
976
977
978SQL - Language Statements         2014-02-17                         SELECT(7)
Impressum