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

NAME

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

SYNOPSIS

10       SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ]
11           * | expression [ AS output_name ] [, ...]
12           [ FROM from_item [, ...] ]
13           [ WHERE condition ]
14           [ GROUP BY expression [, ...] ]
15           [ HAVING condition [, ...] ]
16           [ { UNION | INTERSECT | EXCEPT } [ ALL ] select ]
17           [ ORDER BY expression [ ASC | DESC | USING operator ] [, ...] ]
18           [ LIMIT { count | ALL } ]
19           [ OFFSET start ]
20           [ FOR { UPDATE | SHARE } [ OF table_name [, ...] ] [ NOWAIT ] [...] ]
21
22       where from_item can be one of:
23
24           [ ONLY ] table_name [ * ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
25           ( select ) [ AS ] alias [ ( column_alias [, ...] ) ]
26           function_name ( [ argument [, ...] ] ) [ AS ] alias [ ( column_alias [, ...] | column_definition [, ...] ) ]
27           function_name ( [ argument [, ...] ] ) AS ( column_definition [, ...] )
28           from_item [ NATURAL ] join_type from_item [ ON join_condition | USING ( join_column [, ...] ) ]
29
30

DESCRIPTION

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

PARAMETERS

86   FROM CLAUSE
87       The FROM clause specifies one or more source tables for the SELECT.  If
88       multiple  sources  are  specified,  the result is the Cartesian product
89       (cross join) of all the sources. But usually  qualification  conditions
90       are added to restrict the returned rows to a small subset of the Carte‐
91       sian product.
92
93       The FROM clause can contain the following elements:
94
95       table_name
96              The name (optionally schema-qualified) of an existing  table  or
97              view.  If ONLY is specified, only that table is scanned. If ONLY
98              is not specified, the table and all its  descendant  tables  (if
99              any)  are  scanned. * can be appended to the table name to indi‐
100              cate that descendant tables are to be scanned, but in  the  cur‐
101              rent  version, this is the default behavior. (In releases before
102              7.1, ONLY was the default behavior.) The default behavior can be
103              modified by changing the sql_inheritance configuration option.
104
105       alias  A  substitute  name  for  the FROM item containing the alias. An
106              alias is used for brevity or to eliminate  ambiguity  for  self-
107              joins  (where the same table is scanned multiple times). When an
108              alias is provided, it completely hides the actual  name  of  the
109              table  or function; for example given FROM foo AS f, the remain‐
110              der of the SELECT must refer to this FROM item as f not foo.  If
111              an  alias is written, a column alias list can also be written to
112              provide substitute names for one or more columns of the table.
113
114       select A sub-SELECT can appear in the FROM clause. This acts as  though
115              its output were created as a temporary table for the duration of
116              this single SELECT command. Note that  the  sub-SELECT  must  be
117              surrounded by parentheses, and an alias must be provided for it.
118              A VALUES [values(7)] command can also be used here.
119
120       function_name
121              Function calls can appear in the FROM  clause.  (This  is  espe‐
122              cially  useful  for  functions  that return result sets, but any
123              function can be used.) This acts as though its output were  cre‐
124              ated as a temporary table for the duration of this single SELECT
125              command. An alias may also be used. If an alias  is  written,  a
126              column  alias  list  can  also  be written to provide substitute
127              names for one or more attributes  of  the  function's  composite
128              return  type.  If the function has been defined as returning the
129              record data type, then an alias or  the  key  word  AS  must  be
130              present, followed by a column definition list in the form ( col‐
131              umn_name data_type [, ... ] ). The column definition  list  must
132              match  the  actual  number  and types of columns returned by the
133              function.
134
135       join_type
136              One of
137
138              · [ INNER ] JOIN
139
140              · LEFT [ OUTER ] JOIN
141
142              · RIGHT [ OUTER ] JOIN
143
144              · FULL [ OUTER ] JOIN
145
146              · CROSS JOIN
147
148       For the INNER and OUTER join types, a join condition must be specified,
149       namely exactly one of NATURAL, ON join_condition, or USING (join_column
150       [, ...]).  See below for the meaning. For CROSS  JOIN,  none  of  these
151       clauses may appear.
152
153       A  JOIN clause combines two FROM items. Use parentheses if necessary to
154       determine the order of nesting. In the absence  of  parentheses,  JOINs
155       nest left-to-right. In any case JOIN binds more tightly than the commas
156       separating FROM items.
157
158       CROSS JOIN and INNER JOIN produce a simple Cartesian product, the  same
159       result  as you get from listing the two items at the top level of FROM,
160       but restricted by the join condition (if any).  CROSS JOIN  is  equiva‐
161       lent  to INNER JOIN ON (TRUE), that is, no rows are removed by qualifi‐
162       cation.  These join types are just a notational convenience, since they
163       do nothing you couldn't do with plain FROM and WHERE.
164
165       LEFT  OUTER  JOIN  returns  all rows in the qualified Cartesian product
166       (i.e., all combined rows that pass its join condition), plus  one  copy
167       of  each  row  in the left-hand table for which there was no right-hand
168       row that passed the join condition. This left-hand row is  extended  to
169       the  full  width  of  the joined table by inserting null values for the
170       right-hand columns. Note that only the JOIN clause's own  condition  is
171       considered while deciding which rows have matches. Outer conditions are
172       applied afterwards.
173
174       Conversely, RIGHT OUTER JOIN returns all the joined rows, plus one  row
175       for  each  unmatched  right-hand row (extended with nulls on the left).
176       This is just a notational convenience, since you could convert it to  a
177       LEFT OUTER JOIN by switching the left and right inputs.
178
179       FULL  OUTER  JOIN  returns  all  the joined rows, plus one row for each
180       unmatched left-hand row (extended with nulls on the  right),  plus  one
181       row  for  each  unmatched  right-hand  row  (extended with nulls on the
182       left).
183
184       ON join_condition
185              join_condition is an expression resulting in  a  value  of  type
186              boolean (similar to a WHERE clause) that specifies which rows in
187              a join are considered to match.
188
189       USING (join_column [, ...])
190              A clause of the form USING ( a, b, ... )  is  shorthand  for  ON
191              left_table.a  =  right_table.a  AND left_table.b = right_table.b
192              .... Also, USING implies that only one of each pair  of  equiva‐
193              lent columns will be included in the join output, not both.
194
195       NATURAL
196              NATURAL  is shorthand for a USING list that mentions all columns
197              in the two tables that have the same names.
198
199   WHERE CLAUSE
200       The optional WHERE clause has the general form
201
202       WHERE condition
203
204       where condition is any expression that evaluates to a  result  of  type
205       boolean.  Any  row  that does not satisfy this condition will be elimi‐
206       nated from the output. A row satisfies the condition if it returns true
207       when the actual row values are substituted for any variable references.
208
209   GROUP BY CLAUSE
210       The optional GROUP BY clause has the general form
211
212       GROUP BY expression [, ...]
213
214
215       GROUP  BY  will condense into a single row all selected rows that share
216       the same values for the grouped expressions. expression can be an input
217       column  name, or the name or ordinal number of an output column (SELECT
218       list item), or an arbitrary expression formed from input-column values.
219       In  case of ambiguity, a GROUP BY name will be interpreted as an input-
220       column name rather than an output column name.
221
222       Aggregate functions, if any are used, are computed across all rows mak‐
223       ing  up  each group, producing a separate value for each group (whereas
224       without GROUP BY, an aggregate produces a single value computed  across
225       all  the selected rows).  When GROUP BY is present, it is not valid for
226       the SELECT list expressions to refer to ungrouped columns except within
227       aggregate  functions, since there would be more than one possible value
228       to return for an ungrouped column.
229
230   HAVING CLAUSE
231       The optional HAVING clause has the general form
232
233       HAVING condition
234
235       where condition is the same as specified for the WHERE clause.
236
237       HAVING eliminates group rows that do not satisfy the condition.  HAVING
238       is  different  from  WHERE:  WHERE  filters  individual rows before the
239       application of GROUP BY, while HAVING filters  group  rows  created  by
240       GROUP BY. Each column referenced in condition must unambiguously refer‐
241       ence a grouping column, unless the reference appears within  an  aggre‐
242       gate function.
243
244       The presence of HAVING turns a query into a grouped query even if there
245       is no GROUP BY clause. This is the same as what happens when the  query
246       contains  aggregate  functions but no GROUP BY clause. All the selected
247       rows are considered to form a single group, and  the  SELECT  list  and
248       HAVING  clause  can  only reference table columns from within aggregate
249       functions. Such a query will emit a single row if the HAVING  condition
250       is true, zero rows if it is not true.
251
252   SELECT LIST
253       The  SELECT  list  (between  the  key  words SELECT and FROM) specifies
254       expressions that form the output rows  of  the  SELECT  statement.  The
255       expressions  can (and usually do) refer to columns computed in the FROM
256       clause. Using the clause AS output_name, another name can be  specified
257       for  an  output column. This name is primarily used to label the column
258       for display. It can also be used to refer  to  the  column's  value  in
259       ORDER  BY and GROUP BY clauses, but not in the WHERE or HAVING clauses;
260       there you must write out the expression instead.
261
262       Instead of an expression, * can be written in  the  output  list  as  a
263       shorthand for all the columns of the selected rows. Also, one can write
264       table_name.* as a shorthand for the columns coming from just  that  ta‐
265       ble.
266
267   UNION CLAUSE
268       The UNION clause has this general form:
269
270       select_statement UNION [ ALL ] select_statement
271
272       select_statement  is  any  SELECT statement without an ORDER BY, LIMIT,
273       FOR UPDATE, or FOR SHARE clause.  (ORDER BY and LIMIT can  be  attached
274       to  a subexpression if it is enclosed in parentheses. Without parenthe‐
275       ses, these clauses will be taken to apply to the result of  the  UNION,
276       not to its right-hand input expression.)
277
278       The  UNION  operator computes the set union of the rows returned by the
279       involved SELECT statements. A row is in the set  union  of  two  result
280       sets  if  it appears in at least one of the result sets. The two SELECT
281       statements that represent the direct operands of the UNION must produce
282       the  same  number of columns, and corresponding columns must be of com‐
283       patible data types.
284
285       The result of UNION does not contain any duplicate rows unless the  ALL
286       option  is  specified.  ALL prevents elimination of duplicates. (There‐
287       fore, UNION ALL is usually significantly quicker than  UNION;  use  ALL
288       when you can.)
289
290       Multiple  UNION  operators  in  the same SELECT statement are evaluated
291       left to right, unless otherwise indicated by parentheses.
292
293       Currently, FOR UPDATE and FOR SHARE may not be specified either  for  a
294       UNION result or for any input of a UNION.
295
296   INTERSECT CLAUSE
297       The INTERSECT clause has this general form:
298
299       select_statement INTERSECT [ ALL ] select_statement
300
301       select_statement  is  any  SELECT statement without an ORDER BY, LIMIT,
302       FOR UPDATE, or FOR SHARE clause.
303
304       The INTERSECT operator  computes  the  set  intersection  of  the  rows
305       returned  by  the involved SELECT statements. A row is in the intersec‐
306       tion of two result sets if it appears in both result sets.
307
308       The result of INTERSECT does not contain any duplicate rows unless  the
309       ALL  option is specified.  With ALL, a row that has m duplicates in the
310       left table and n duplicates in the right  table  will  appear  min(m,n)
311       times in the result set.
312
313       Multiple INTERSECT operators in the same SELECT statement are evaluated
314       left to right, unless parentheses dictate otherwise.   INTERSECT  binds
315       more tightly than UNION. That is, A UNION B INTERSECT C will be read as
316       A UNION (B INTERSECT C).
317
318       Currently, FOR UPDATE and FOR SHARE may not be specified either for  an
319       INTERSECT result or for any input of an INTERSECT.
320
321   EXCEPT CLAUSE
322       The EXCEPT clause has this general form:
323
324       select_statement EXCEPT [ ALL ] select_statement
325
326       select_statement  is  any  SELECT statement without an ORDER BY, LIMIT,
327       FOR UPDATE, or FOR SHARE clause.
328
329       The EXCEPT operator computes the set of rows that are in the result  of
330       the left SELECT statement but not in the result of the right one.
331
332       The result of EXCEPT does not contain any duplicate rows unless the ALL
333       option is specified.  With ALL, a row that has m duplicates in the left
334       table  and n duplicates in the right table will appear max(m-n,0) times
335       in the result set.
336
337       Multiple EXCEPT operators in the same SELECT  statement  are  evaluated
338       left  to  right,  unless parentheses dictate otherwise. EXCEPT binds at
339       the same level as UNION.
340
341       Currently, FOR UPDATE and FOR SHARE may not be specified either for  an
342       EXCEPT result or for any input of an EXCEPT.
343
344   ORDER BY CLAUSE
345       The optional ORDER BY clause has this general form:
346
347       ORDER BY expression [ ASC | DESC | USING operator ] [, ...]
348
349       expression  can  be  the  name  or  ordinal  number of an output column
350       (SELECT list item), or it can be an arbitrary  expression  formed  from
351       input-column values.
352
353       The  ORDER  BY  clause causes the result rows to be sorted according to
354       the specified expressions. If two rows are equal according to the left‐
355       most  expression, the are compared according to the next expression and
356       so on. If they are equal according to all specified  expressions,  they
357       are returned in an implementation-dependent order.
358
359       The  ordinal  number  refers to the ordinal (left-to-right) position of
360       the result column. This feature makes it possible to define an ordering
361       on  the  basis  of  a  column that does not have a unique name. This is
362       never absolutely necessary because it is always possible  to  assign  a
363       name to a result column using the AS clause.
364
365       It  is  also  possible  to  use  arbitrary  expressions in the ORDER BY
366       clause, including columns that do not appear in the SELECT result list.
367       Thus the following statement is valid:
368
369       SELECT name FROM distributors ORDER BY code;
370
371       A limitation of this feature is that an ORDER BY clause applying to the
372       result of a UNION, INTERSECT, or EXCEPT clause may only specify an out‐
373       put column name or number, not an expression.
374
375       If  an  ORDER BY expression is a simple name that matches both a result
376       column name and an input column name, ORDER BY will interpret it as the
377       result  column  name.  This is the opposite of the choice that GROUP BY
378       will make in the same situation. This inconsistency is made to be  com‐
379       patible with the SQL standard.
380
381       Optionally  one  may add the key word ASC (ascending) or DESC (descend‐
382       ing) after any expression in the ORDER BY clause. If not specified, ASC
383       is assumed by default. Alternatively, a specific ordering operator name
384       may be specified in the USING clause.  ASC  is  usually  equivalent  to
385       USING < and DESC is usually equivalent to USING >.  (But the creator of
386       a user-defined data type can  define  exactly  what  the  default  sort
387       ordering is, and it might correspond to operators with other names.)
388
389       The  null value sorts higher than any other value. In other words, with
390       ascending sort order, null values sort at the end, and with  descending
391       sort order, null values sort at the beginning.
392
393       Character-string data is sorted according to the locale-specific colla‐
394       tion order that was established when the database cluster was  initial‐
395       ized.
396
397   DISTINCT CLAUSE
398       If  DISTINCT  is  specified,  all  duplicate  rows are removed from the
399       result set (one row is kept from each group of duplicates). ALL  speci‐
400       fies the opposite: all rows are kept; that is the default.
401
402       DISTINCT ON ( expression [, ...] ) keeps only the first row of each set
403       of rows where the given expressions evaluate to equal. The DISTINCT  ON
404       expressions  are  interpreted using the same rules as for ORDER BY (see
405       above). Note that the ``first row'' of each set is unpredictable unless
406       ORDER  BY  is  used  to  ensure that the desired row appears first. For
407       example,
408
409       SELECT DISTINCT ON (location) location, time, report
410           FROM weather_reports
411           ORDER BY location, time DESC;
412
413       retrieves the most recent weather report for each location. But  if  we
414       had not used ORDER BY to force descending order of time values for each
415       location, we'd have gotten a report from an unpredictable time for each
416       location.
417
418       The  DISTINCT ON expression(s) must match the leftmost ORDER BY expres‐
419       sion(s). The ORDER BY clause will normally contain  additional  expres‐
420       sion(s)  that determine the desired precedence of rows within each DIS‐
421       TINCT ON group.
422
423   LIMIT CLAUSE
424       The LIMIT clause consists of two independent sub-clauses:
425
426       LIMIT { count | ALL }
427       OFFSET start
428
429       count specifies the maximum number of rows to return, while start spec‐
430       ifies  the  number of rows to skip before starting to return rows. When
431       both are specified, start rows are skipped before starting to count the
432       count rows to be returned.
433
434       When using LIMIT, it is a good idea to use an ORDER BY clause that con‐
435       strains the result rows into a unique order. Otherwise you will get  an
436       unpredictable  subset  of  the query's rows — you may be asking for the
437       tenth through twentieth rows,  but  tenth  through  twentieth  in  what
438       ordering? You don't know what ordering unless you specify ORDER BY.
439
440       The  query  planner  takes  LIMIT  into account when generating a query
441       plan, so you are very likely to get different plans (yielding different
442       row orders) depending on what you use for LIMIT and OFFSET. Thus, using
443       different LIMIT/OFFSET values to select different subsets  of  a  query
444       result  will give inconsistent results unless you enforce a predictable
445       result ordering with ORDER BY. This is not a bug;  it  is  an  inherent
446       consequence  of  the  fact  that  SQL  does  not promise to deliver the
447       results of a query in any particular order unless ORDER BY is  used  to
448       constrain the order.
449
450   FOR UPDATE/FOR SHARE CLAUSE
451       The FOR UPDATE clause has this form:
452
453       FOR UPDATE [ OF table_name [, ...] ] [ NOWAIT ]
454
455
456       The closely related FOR SHARE clause has this form:
457
458       FOR SHARE [ OF table_name [, ...] ] [ NOWAIT ]
459
460
461       FOR  UPDATE  causes  the  rows  retrieved by the SELECT statement to be
462       locked as though for update. This prevents them from being modified  or
463       deleted  by other transactions until the current transaction ends. That
464       is, other transactions that  attempt  UPDATE,  DELETE,  or  SELECT  FOR
465       UPDATE  of  these  rows  will  be blocked until the current transaction
466       ends.  Also, if an UPDATE, DELETE, or SELECT FOR  UPDATE  from  another
467       transaction  has  already  locked  a  selected  row or rows, SELECT FOR
468       UPDATE will wait for the other transaction to complete, and  will  then
469       lock  and  return  the updated row (or no row, if the row was deleted).
470       For further discussion see in the documentation.
471
472       To prevent the operation from waiting for other transactions to commit,
473       use  the  NOWAIT  option.  SELECT  FOR  UPDATE NOWAIT reports an error,
474       rather than waiting, if a selected row cannot  be  locked  immediately.
475       Note  that  NOWAIT applies only to the row-level lock(s) — the required
476       ROW SHARE table-level lock is still taken in the ordinary way  (see  in
477       the  documentation). You can use the NOWAIT option of LOCK [lock(7)] if
478       you need to acquire the table-level lock without waiting.
479
480       FOR SHARE behaves similarly, except that it acquires  a  shared  rather
481       than  exclusive  lock on each retrieved row. A shared lock blocks other
482       transactions from performing UPDATE, DELETE, or SELECT  FOR  UPDATE  on
483       these  rows,  but  it  does not prevent them from performing SELECT FOR
484       SHARE.
485
486       If specific tables are named in FOR UPDATE or FOR SHARE, then only rows
487       coming  from  those  tables  are  locked;  any other tables used in the
488       SELECT are simply read as usual. A FOR UPDATE or FOR SHARE clause with‐
489       out a table list affects all tables used in the command.  If FOR UPDATE
490       or FOR SHARE is applied to a view or sub-query, it affects  all  tables
491       used in the view or sub-query.
492
493       Multiple  FOR UPDATE and FOR SHARE clauses can be written if it is nec‐
494       essary to specify different locking behavior for different  tables.  If
495       the same table is mentioned (or implicitly affected) by both FOR UPDATE
496       and FOR SHARE clauses, then it is processed as FOR UPDATE. Similarly, a
497       table is processed as NOWAIT if that is specified in any of the clauses
498       affecting it.
499
500       FOR UPDATE and FOR SHARE cannot be used in contexts where returned rows
501       can't  be  clearly  identified  with individual table rows; for example
502       they can't be used with aggregation.
503
504              Caution: Avoid locking a row and  then  modifying  it  within  a
505              later  savepoint or PL/pgSQL exception block. A subsequent roll‐
506              back would cause the lock to be lost. For example,
507
508              BEGIN;
509              SELECT * FROM mytable WHERE key = 1 FOR UPDATE;
510              SAVEPOINT s;
511              UPDATE mytable SET ... WHERE key = 1;
512              ROLLBACK TO s;
513
514              After the ROLLBACK, the row is effectively unlocked, rather than
515              returned to its pre-savepoint state of being locked but not mod‐
516              ified.  This hazard occurs if a row locked in the current trans‐
517              action is updated or deleted, or if a shared lock is upgraded to
518              exclusive: in all these cases, the former lock state is  forgot‐
519              ten.  If  the transaction is then rolled back to a state between
520              the original locking command and the subsequent change, the  row
521              will  appear  not to be locked at all. This is an implementation
522              deficiency which will be addressed in a future release of  Post‐
523              greSQL.
524
525
526              Caution:  It  is  possible for a SELECT command using both LIMIT
527              and FOR UPDATE/SHARE clauses to return fewer rows than specified
528              by  LIMIT.   This is because LIMIT is applied first. The command
529              selects the specified number of rows, but might then block  try‐
530              ing  to  obtain  lock  on  one or more of them.  Once the SELECT
531              unblocks, the row might have been deleted or updated so that  it
532              does  not  meet the query WHERE condition anymore, in which case
533              it will not be returned.
534
535

EXAMPLES

537       To join the table films with the table distributors:
538
539       SELECT f.title, f.did, d.name, f.date_prod, f.kind
540           FROM distributors d, films f
541           WHERE f.did = d.did
542
543              title       | did |     name     | date_prod  |   kind
544       -------------------+-----+--------------+------------+----------
545        The Third Man     | 101 | British Lion | 1949-12-23 | Drama
546        The African Queen | 101 | British Lion | 1951-08-11 | Romantic
547        ...
548
549
550       To sum the column len of all films and group the results by kind:
551
552       SELECT kind, sum(len) AS total FROM films GROUP BY kind;
553
554          kind   | total
555       ----------+-------
556        Action   | 07:34
557        Comedy   | 02:58
558        Drama    | 14:28
559        Musical  | 06:42
560        Romantic | 04:38
561
562
563       To sum the column len of all films, group the results by kind and  show
564       those group totals that are less than 5 hours:
565
566       SELECT kind, sum(len) AS total
567           FROM films
568           GROUP BY kind
569           HAVING sum(len) < interval '5 hours';
570
571          kind   | total
572       ----------+-------
573        Comedy   | 02:58
574        Romantic | 04:38
575
576
577       The following two examples are identical ways of sorting the individual
578       results according to the contents of the second column (name):
579
580       SELECT * FROM distributors ORDER BY name;
581       SELECT * FROM distributors ORDER BY 2;
582
583        did |       name
584       -----+------------------
585        109 | 20th Century Fox
586        110 | Bavaria Atelier
587        101 | British Lion
588        107 | Columbia
589        102 | Jean Luc Godard
590        113 | Luso films
591        104 | Mosfilm
592        103 | Paramount
593        106 | Toho
594        105 | United Artists
595        111 | Walt Disney
596        112 | Warner Bros.
597        108 | Westward
598
599
600       The next example shows how to obtain the union of the tables  distribu‐
601       tors  and  actors, restricting the results to those that begin with the
602       letter W in each table. Only distinct rows are wanted, so the key  word
603       ALL is omitted.
604
605       distributors:               actors:
606        did |     name              id |     name
607       -----+--------------        ----+----------------
608        108 | Westward               1 | Woody Allen
609        111 | Walt Disney            2 | Warren Beatty
610        112 | Warner Bros.           3 | Walter Matthau
611        ...                         ...
612
613       SELECT distributors.name
614           FROM distributors
615           WHERE distributors.name LIKE 'W%'
616       UNION
617       SELECT actors.name
618           FROM actors
619           WHERE actors.name LIKE 'W%';
620
621             name
622       ----------------
623        Walt Disney
624        Walter Matthau
625        Warner Bros.
626        Warren Beatty
627        Westward
628        Woody Allen
629
630
631       This  example shows how to use a function in the FROM clause, both with
632       and without a column definition list:
633
634       CREATE FUNCTION distributors(int) RETURNS SETOF distributors AS $$
635           SELECT * FROM distributors WHERE did = $1;
636       $$ LANGUAGE SQL;
637
638       SELECT * FROM distributors(111);
639        did |    name
640       -----+-------------
641        111 | Walt Disney
642
643       CREATE FUNCTION distributors_2(int) RETURNS SETOF record AS $$
644           SELECT * FROM distributors WHERE did = $1;
645       $$ LANGUAGE SQL;
646
647       SELECT * FROM distributors_2(111) AS (f1 int, f2 text);
648        f1  |     f2
649       -----+-------------
650        111 | Walt Disney
651
652

COMPATIBILITY

654       Of course, the SELECT statement is compatible with  the  SQL  standard.
655       But there are some extensions and some missing features.
656
657   OMITTED FROM CLAUSES
658       PostgreSQL allows one to omit the FROM clause. It has a straightforward
659       use to compute the results of simple expressions:
660
661       SELECT 2+2;
662
663        ?column?
664       ----------
665               4
666
667       Some other SQL databases cannot do this except by introducing  a  dummy
668       one-row table from which to do the SELECT.
669
670       Note that if a FROM clause is not specified, the query cannot reference
671       any database tables. For example, the following query is invalid:
672
673       SELECT distributors.* WHERE distributors.name = 'Westward';
674
675       PostgreSQL releases prior to 8.1 would accept queries of this form, and
676       add  an implicit entry to the query's FROM clause for each table refer‐
677       enced by the query. This is no longer the default behavior, because  it
678       does  not comply with the SQL standard, and is considered by many to be
679       error-prone. For compatibility with  applications  that  rely  on  this
680       behavior the add_missing_from configuration variable can be enabled.
681
682   THE AS KEY WORD
683       In  the SQL standard, the optional key word AS is just noise and can be
684       omitted without affecting the meaning. The PostgreSQL  parser  requires
685       this key word when renaming output columns because the type extensibil‐
686       ity features lead to parsing ambiguities without it.  AS is optional in
687       FROM items, however.
688
689   NAMESPACE AVAILABLE TO GROUP BY AND ORDER BY
690       In  the  SQL-92 standard, an ORDER BY clause may only use result column
691       names or numbers, while a GROUP BY  clause  may  only  use  expressions
692       based  on  input column names. PostgreSQL extends each of these clauses
693       to allow the other choice as well (but it uses the standard's interpre‐
694       tation  if there is ambiguity).  PostgreSQL also allows both clauses to
695       specify arbitrary expressions. Note that names appearing in an  expres‐
696       sion  will  always be taken as input-column names, not as result-column
697       names.
698
699       SQL:1999 and later use a slightly different  definition  which  is  not
700       entirely  upward compatible with SQL-92.  In most cases, however, Post‐
701       greSQL will interpret an ORDER BY or GROUP BY expression the  same  way
702       SQL:1999 does.
703
704   NONSTANDARD CLAUSES
705       The  clauses  DISTINCT ON, LIMIT, and OFFSET are not defined in the SQL
706       standard.
707
708
709
710SQL - Language Statements         2008-06-08                          SELECT()
Impressum