SELECT [ALL|DISTINCT [ON column] ] expression [ AS name ] [, ...] [ INTO [TABLE] new_table ] [ FROM table [alias ] [, ...] ] [ WHERE condition ] [ GROUP BY column [, ...] ] [ HAVING condition [, ...] ] [ UNION [ALL] select ] [ ORDER BY column [ ASC | DESC ] [, ...] ]
The name of a table's column or an expression.
Specifies another name for a column or an expression using the AS clause. name cannot be used in the WHERE condition. It can, however, be referenced in associated ORDER BY or GROUP BY clauses.
If the INTO TABLE clause is specified, the result of the query will be stored in another table with the indicated name. If new_table does not exist, it will be created automatically. Refer to SELECT INTO for more information.
Note: The CREATE TABLE AS statement will also create a new table from a select query.
The name of an existing table referenced by the FROM clause.
An alternate name for the preceding table. It is used for brevity or to eliminate ambiguity for joins within a single table.
A boolean expression giving a result of true or false. See the WHERE clause.
The name of a table's column.
A select statement with all features except the ORDER BY clause.
The complete set of rows resulting from the query specification.
The count of rows returned by the query.
SELECT will get all rows which satisfy the WHERE condition or all rows of a table if WHERE is omitted.
The GROUP BY clause allows a user to divide a table conceptually into groups. (See GROUP BY clause).
The HAVING clause specifies a grouped table derived by the elimination of groups from the result of the previously specified clause. (See HAVING clause).
The ORDER BY clause allows a user to specify that he/she wishes the rows sorted according to the ASCending or DESCending mode operator. (See ORDER BY clause)
The UNION clause specifies a table derived from a Cartesian product union join. (See UNION clause).
You must have SELECT privilege to a table to read its values (See GRANT/REVOKE statements).
The optional WHERE condition has the general form:
WHERE expr cond_op expr [ log_op ... ]where cond_op can be one of: =, <, <=, >, >=, <> or a conditional operator like ALL, ANY, IN, LIKE, et cetera and log_op can be one of: AND, OR, NOT. The comparison returns either TRUE or FALSE and all instances will be discarded if the expression evaluates to FALSE.
GROUP BY specifies a grouped table derived by the application of the this clause:
GROUP BY column [, ...]
The optional HAVING condition has the general form:
HAVING cond_exprwhere cond_expr is the same as specified for the WHERE clause.
HAVING specifies a grouped table derived by the elimination of groups from the result of the previously specified clause that do not meet the cond_expr.
Each column referenced in cond_expr shall unambiguously reference a grouping column.
ORDER BY column [ ASC | DESC ] [, ...]
column can be either a column name or an ordinal number.
The ordinal numbers refers to the ordinal (left-to-right) position of the column. This feature makes it possible to define an ordering on the basis of a column that does not have a proper name. This is never absolutely necessary because it is always possible assign a name to a calculated column using the AS clause, e.g.:
SELECT title, date_prod + 1 AS newlen FROM films ORDER BY newlen;
The columns in the ORDER BY must appear in the SELECT clause. Thus the following statement is illegal:
SELECT name FROM distributors ORDER BY code;
Optionally one may add the keyword DESC (descending) or ASC (ascending) after each column name in the ORDER BY clause. If not specified, ASC is assumed by default.
table_query UNION [ ALL ] table_query [ ORDER BY column [ ASC | DESC ] [, ...] ]where table_query specifies any select expression without an ORDER BY clause.
The UNION operator specifies a table derived from a Cartesian product. The two tables that represent the direct operands of the UNION must have the same number of columns, and corresponding columns must be of compatible data types.
By default, the result of UNION does not contain any duplicate rows unless the ALL clause is specified.
Multiple UNION operators in the same SELECT statement are evaluated left to right. Note that the ALL keyword is not global in nature, being applied only for the current pair of table results.
To join the table films with the table distributors:
SELECT f.title, f.did, d.name, f.date_prod, f.kind FROM distributors d, films f WHERE f.did = d.did title |did|name | date_prod|kind -------------------------+---+----------------+----------+---------- The Third Man |101|British Lion |1949-12-23|Drama The African Queen |101|British Lion |1951-08-11|Romantic Une Femme est une Femme |102|Jean Luc Godard |1961-03-12|Romantic Vertigo |103|Paramount |1958-11-14|Action Becket |103|Paramount |1964-02-03|Drama 48 Hrs |103|Paramount |1982-10-22|Action War and Peace |104|Mosfilm |1967-02-12|Drama West Side Story |105|United Artists |1961-01-03|Musical Bananas |105|United Artists |1971-07-13|Comedy Yojimbo |106|Toho |1961-06-16|Drama There's a Girl in my Soup|107|Columbia |1970-06-11|Comedy Taxi Driver |107|Columbia |1975-05-15|Action Absence of Malice |107|Columbia |1981-11-15|Action Storia di una donna |108|Westward |1970-08-15|Romantic The King and I |109|20th Century Fox|1956-08-11|Musical Das Boot |110|Bavaria Atelier |1981-11-11|Drama Bed Knobs and Broomsticks|111|Walt Disney | |Musical
To sum the column len of all films and group the reults by kind:
SELECT kind, SUM(len) AS total FROM films GROUP BY kind; kind |total ----------+------ Action | 07:34 Comedy | 02:58 Drama | 14:28 Musical | 06:42 Romantic | 04:38
To sum the column len of all films, group the reults by kind and show those group totals that are less than 5 hours:
SELECT kind, SUM(len) AS total FROM films GROUP BY kind HAVING SUM(len) < INTERVAL '5 hour'; kind |total ----------+------ Comedy | 02:58 Romantic | 04:38
The following two examples are identical ways of sorting the individual results according to the contents of the second column (name):
SELECT * FROM distributors ORDER BY name; SELECT * FROM distributors ORDER BY 2; did|name ---+---------------- 109|20th Century Fox 110|Bavaria Atelier 101|British Lion 107|Columbia 102|Jean Luc Godard 113|Luso films 104|Mosfilm 103|Paramount 106|Toho 105|United Artists 111|Walt Disney 112|Warner Bros. 108|Westward
This example shows how to obtain the union of the tables distributors and actors, restricting the results to those that begin with letter W in each table. Only distinct rows are to be used, so the ALL keyword is omitted:
-- distributors: actors: -- did|name id|name -- ---+------------ --+-------------- -- 108|Westward 1|Woody Allen -- 111|Walt Disney 2|Warren Beatty -- 112|Warner Bros. 3|Walter Matthau -- ... ... SELECT distributors.name FROM distributors WHERE distributors.name LIKE 'W%' UNION SELECT actors.name FROM actors WHERE actors.name LIKE 'W%' name -------------- Walt Disney Walter Matthau Warner Bros. Warren Beatty Westward Woody Allen
In the SQL92 standard, the optional keyword "AS" is just noise and can be omitted without affecting the meaning. The Postgres parser requires this keyword when renaming columns because the type extensibility features lead to parsing ambiguities in this context.
In the SQL92 standard, the new column name specified in an "AS" clause may be referenced in GROUP BY and HAVING clauses. This is not currently allowed in Postgres.
The SQL92 syntax for UNION allows an additional CORRESPONDING BY clause:
table_query UNION [ALL] [CORRESPONDING [BY (column [,...])]] table_query
The CORRESPONDING BY clause is not supported by Postgres.