1SELECT(7) PostgreSQL 9.2.24 Documentation SELECT(7)
2
3
4
6 SELECT, TABLE, WITH - retrieve rows from a table or view
7
9 [ WITH [ RECURSIVE ] with_query [, ...] ]
10 SELECT [ ALL | DISTINCT [ ON ( expression [, ...] ) ] ]
11 * | expression [ [ AS ] output_name ] [, ...]
12 [ FROM from_item [, ...] ]
13 [ WHERE condition ]
14 [ GROUP BY expression [, ...] ]
15 [ HAVING condition [, ...] ]
16 [ WINDOW window_name AS ( window_definition ) [, ...] ]
17 [ { UNION | INTERSECT | EXCEPT } [ ALL | DISTINCT ] select ]
18 [ ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...] ]
19 [ LIMIT { count | ALL } ]
20 [ OFFSET start [ ROW | ROWS ] ]
21 [ FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } ONLY ]
22 [ FOR { UPDATE | SHARE } [ OF table_name [, ...] ] [ NOWAIT ] [...] ]
23
24 where from_item can be one of:
25
26 [ ONLY ] table_name [ * ] [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
27 ( select ) [ AS ] alias [ ( column_alias [, ...] ) ]
28 with_query_name [ [ AS ] alias [ ( column_alias [, ...] ) ] ]
29 function_name ( [ argument [, ...] ] ) [ AS ] alias [ ( column_alias [, ...] | column_definition [, ...] ) ]
30 function_name ( [ argument [, ...] ] ) AS ( column_definition [, ...] )
31 from_item [ NATURAL ] join_type from_item [ ON join_condition | USING ( join_column [, ...] ) ]
32
33 and with_query is:
34
35 with_query_name [ ( column_name [, ...] ) ] AS ( select | values | insert | update | delete )
36
37 TABLE [ ONLY ] table_name [ * ]
38
40 SELECT retrieves rows from zero or more tables. The general processing
41 of SELECT is as follows:
42
43 1. All queries in the WITH list are computed. These effectively serve
44 as temporary tables that can be referenced in the FROM list. A WITH
45 query that is referenced more than once in FROM is computed only
46 once. (See WITH Clause below.)
47
48 2. All elements in the FROM list are computed. (Each element in the
49 FROM list is a real or virtual table.) If more than one element is
50 specified in the FROM list, they are cross-joined together. (See
51 FROM Clause below.)
52
53 3. If the WHERE clause is specified, all rows that do not satisfy the
54 condition are eliminated from the output. (See WHERE Clause below.)
55
56 4. If the GROUP BY clause is specified, the output is combined into
57 groups of rows that match on one or more values. If the HAVING
58 clause is present, it eliminates groups that do not satisfy the
59 given condition. (See GROUP BY Clause and HAVING Clause below.)
60
61 5. The actual output rows are computed using the SELECT output
62 expressions for each selected row or row group. (See SELECT List
63 below.)
64
65 6. SELECT DISTINCT eliminates duplicate rows from the result. SELECT
66 DISTINCT ON eliminates rows that match on all the specified
67 expressions. SELECT ALL (the default) will return all candidate
68 rows, including duplicates. (See DISTINCT Clause below.)
69
70 7. Using the operators UNION, INTERSECT, and EXCEPT, the output of
71 more than one SELECT statement can be combined to form a single
72 result set. The UNION operator returns all rows that are in one or
73 both of the result sets. The INTERSECT operator returns all rows
74 that are strictly in both result sets. The EXCEPT operator returns
75 the rows that are in the first result set but not in the second. In
76 all three cases, duplicate rows are eliminated unless ALL is
77 specified. The noise word DISTINCT can be added to explicitly
78 specify eliminating duplicate rows. Notice that DISTINCT is the
79 default behavior here, even though ALL is the default for SELECT
80 itself. (See UNION Clause, INTERSECT Clause, and EXCEPT Clause
81 below.)
82
83 8. If the ORDER BY clause is specified, the returned rows are sorted
84 in the specified order. If ORDER BY is not given, the rows are
85 returned in whatever order the system finds fastest to produce.
86 (See ORDER BY Clause below.)
87
88 9. If the LIMIT (or FETCH FIRST) or OFFSET clause is specified, the
89 SELECT statement only returns a subset of the result rows. (See
90 LIMIT Clause below.)
91
92 10. If FOR UPDATE or FOR SHARE is specified, the SELECT statement locks
93 the selected rows against concurrent updates. (See FOR UPDATE/FOR
94 SHARE Clause below.)
95
96 You must have SELECT privilege on each column used in a SELECT command.
97 The use of FOR UPDATE or FOR SHARE requires UPDATE privilege as well
98 (for at least one column of each table so selected).
99
101 WITH Clause
102 The WITH clause allows you to specify one or more subqueries that can
103 be referenced by name in the primary query. The subqueries effectively
104 act as temporary tables or views for the duration of the primary query.
105 Each subquery can be a SELECT, VALUES, INSERT, UPDATE or DELETE
106 statement. When writing a data-modifying statement (INSERT, UPDATE or
107 DELETE) in WITH, it is usual to include a RETURNING clause. It is the
108 output of RETURNING, not the underlying table that the statement
109 modifies, that forms the temporary table that is read by the primary
110 query. If RETURNING is omitted, the statement is still executed, but it
111 produces no output so it cannot be referenced as a table by the primary
112 query.
113
114 A name (without schema qualification) must be specified for each WITH
115 query. Optionally, a list of column names can be specified; if this is
116 omitted, the column names are inferred from the subquery.
117
118 If RECURSIVE is specified, it allows a SELECT subquery to reference
119 itself by name. Such a subquery must have the form
120
121 non_recursive_term UNION [ ALL | DISTINCT ] recursive_term
122
123 where the recursive self-reference must appear on the right-hand side
124 of the UNION. Only one recursive self-reference is permitted per query.
125 Recursive data-modifying statements are not supported, but you can use
126 the results of a recursive SELECT query in a data-modifying statement.
127 See Section 7.8, “WITH Queries (Common Table Expressions)”, in the
128 documentation for an example.
129
130 Another effect of RECURSIVE is that WITH queries need not be ordered: a
131 query can reference another one that is later in the list. (However,
132 circular references, or mutual recursion, are not implemented.) Without
133 RECURSIVE, WITH queries can only reference sibling WITH queries that
134 are earlier in the WITH list.
135
136 A key property of WITH queries is that they are evaluated only once per
137 execution of the primary query, even if the primary query refers to
138 them more than once. In particular, data-modifying statements are
139 guaranteed to be executed once and only once, regardless of whether the
140 primary query reads all or any of their output.
141
142 The primary query and the WITH queries are all (notionally) executed at
143 the same time. This implies that the effects of a data-modifying
144 statement in WITH cannot be seen from other parts of the query, other
145 than by reading its RETURNING output. If two such data-modifying
146 statements attempt to modify the same row, the results are unspecified.
147
148 See Section 7.8, “WITH Queries (Common Table Expressions)”, in the
149 documentation for additional information.
150
151 FROM Clause
152 The FROM clause specifies one or more source tables for the SELECT. If
153 multiple sources are specified, the result is the Cartesian product
154 (cross join) of all the sources. But usually qualification conditions
155 are added to restrict the returned rows to a small subset of the
156 Cartesian product.
157
158 The FROM clause can contain the following elements:
159
160 table_name
161 The name (optionally schema-qualified) of an existing table or
162 view. If ONLY is specified before the table name, only that table
163 is scanned. If ONLY is not specified, the table and all its
164 descendant tables (if any) are scanned. Optionally, * can be
165 specified after the table name to explicitly indicate that
166 descendant tables are included.
167
168 alias
169 A substitute name for the FROM item containing the alias. An alias
170 is used for brevity or to eliminate ambiguity for self-joins (where
171 the same table is scanned multiple times). When an alias is
172 provided, it completely hides the actual name of the table or
173 function; for example given FROM foo AS f, the remainder of the
174 SELECT must refer to this FROM item as f not foo. If an alias is
175 written, a column alias list can also be written to provide
176 substitute names for one or more columns of the table.
177
178 select
179 A sub-SELECT can appear in the FROM clause. This acts as though its
180 output were created as a temporary table for the duration of this
181 single SELECT command. Note that the sub-SELECT must be surrounded
182 by parentheses, and an alias must be provided for it. A VALUES(7)
183 command can also be used here.
184
185 with_query_name
186 A WITH query is referenced by writing its name, just as though the
187 query's name were a table name. (In fact, the WITH query hides any
188 real table of the same name for the purposes of the primary query.
189 If necessary, you can refer to a real table of the same name by
190 schema-qualifying the table's name.) An alias can be provided in
191 the same way as for a table.
192
193 function_name
194 Function calls can appear in the FROM clause. (This is especially
195 useful for functions that return result sets, but any function can
196 be used.) This acts as though its output were created as a
197 temporary table for the duration of this single SELECT command. An
198 alias can also be used. If an alias is written, a column alias list
199 can also be written to provide substitute names for one or more
200 attributes of the function's composite return type. If the function
201 has been defined as returning the record data type, then an alias
202 or the key word AS must be present, followed by a column definition
203 list in the form ( column_name data_type [, ... ] ). The column
204 definition list must match the actual number and types of columns
205 returned by the function.
206
207 join_type
208 One of
209
210 · [ INNER ] JOIN
211
212 · LEFT [ OUTER ] JOIN
213
214 · RIGHT [ OUTER ] JOIN
215
216 · FULL [ OUTER ] JOIN
217
218 · CROSS JOIN
219
220 For the INNER and OUTER join types, a join condition must be
221 specified, namely exactly one of NATURAL, ON join_condition, or
222 USING (join_column [, ...]). See below for the meaning. For CROSS
223 JOIN, none of these clauses can appear.
224
225 A JOIN clause combines two FROM items. Use parentheses if necessary
226 to determine the order of nesting. In the absence of parentheses,
227 JOINs nest left-to-right. In any case JOIN binds more tightly than
228 the commas separating FROM items.
229
230 CROSS JOIN and INNER JOIN produce a simple Cartesian product, the
231 same result as you get from listing the two items at the top level
232 of FROM, but restricted by the join condition (if any). CROSS JOIN
233 is equivalent to INNER JOIN ON (TRUE), that is, no rows are removed
234 by qualification. These join types are just a notational
235 convenience, since they do nothing you couldn't do with plain FROM
236 and WHERE.
237
238 LEFT OUTER JOIN returns all rows in the qualified Cartesian product
239 (i.e., all combined rows that pass its join condition), plus one
240 copy of each row in the left-hand table for which there was no
241 right-hand row that passed the join condition. This left-hand row
242 is extended to the full width of the joined table by inserting null
243 values for the right-hand columns. Note that only the JOIN clause's
244 own condition is considered while deciding which rows have matches.
245 Outer conditions are applied afterwards.
246
247 Conversely, RIGHT OUTER JOIN returns all the joined rows, plus one
248 row for each unmatched right-hand row (extended with nulls on the
249 left). This is just a notational convenience, since you could
250 convert it to a LEFT OUTER JOIN by switching the left and right
251 inputs.
252
253 FULL OUTER JOIN returns all the joined rows, plus one row for each
254 unmatched left-hand row (extended with nulls on the right), plus
255 one row for each unmatched right-hand row (extended with nulls on
256 the left).
257
258 ON join_condition
259 join_condition is an expression resulting in a value of type
260 boolean (similar to a WHERE clause) that specifies which rows in a
261 join are considered to match.
262
263 USING ( join_column [, ...] )
264 A clause of the form USING ( a, b, ... ) is shorthand for ON
265 left_table.a = right_table.a AND left_table.b = right_table.b ....
266 Also, USING implies that only one of each pair of equivalent
267 columns will be included in the join output, not both.
268
269 NATURAL
270 NATURAL is shorthand for a USING list that mentions all columns in
271 the two tables that have matching names. If there are no common
272 column names, NATURAL is equivalent to ON TRUE.
273
274 WHERE Clause
275 The optional WHERE clause has the general form
276
277 WHERE condition
278
279 where condition is any expression that evaluates to a result of type
280 boolean. Any row that does not satisfy this condition will be
281 eliminated from the output. A row satisfies the condition if it returns
282 true when the actual row values are substituted for any variable
283 references.
284
285 GROUP BY Clause
286 The optional GROUP BY clause has the general form
287
288 GROUP BY expression [, ...]
289
290 GROUP BY will condense into a single row all selected rows that share
291 the same values for the grouped expressions. expression can be an
292 input column name, or the name or ordinal number of an output column
293 (SELECT list item), or an arbitrary expression formed from input-column
294 values. In case of ambiguity, a GROUP BY name will be interpreted as an
295 input-column name rather than an output column name.
296
297 Aggregate functions, if any are used, are computed across all rows
298 making up each group, producing a separate value for each group
299 (whereas without GROUP BY, an aggregate produces a single value
300 computed across all the selected rows). When GROUP BY is present, it is
301 not valid for the SELECT list expressions to refer to ungrouped columns
302 except within aggregate functions or if the ungrouped column is
303 functionally dependent on the grouped columns, since there would
304 otherwise be more than one possible value to return for an ungrouped
305 column. A functional dependency exists if the grouped columns (or a
306 subset thereof) are the primary key of the table containing the
307 ungrouped column.
308
309 HAVING Clause
310 The optional HAVING clause has the general form
311
312 HAVING condition
313
314 where condition is the same as specified for the WHERE clause.
315
316 HAVING eliminates group rows that do not satisfy the condition. HAVING
317 is different from WHERE: WHERE filters individual rows before the
318 application of GROUP BY, while HAVING filters group rows created by
319 GROUP BY. Each column referenced in condition must unambiguously
320 reference a grouping column, unless the reference appears within an
321 aggregate function.
322
323 The presence of HAVING turns a query into a grouped query even if there
324 is no GROUP BY clause. This is the same as what happens when the query
325 contains aggregate functions but no GROUP BY clause. All the selected
326 rows are considered to form a single group, and the SELECT list and
327 HAVING clause can only reference table columns from within aggregate
328 functions. Such a query will emit a single row if the HAVING condition
329 is true, zero rows if it is not true.
330
331 WINDOW Clause
332 The optional WINDOW clause has the general form
333
334 WINDOW window_name AS ( window_definition ) [, ...]
335
336 where window_name is a name that can be referenced from OVER clauses or
337 subsequent window definitions, and window_definition is
338
339 [ existing_window_name ]
340 [ PARTITION BY expression [, ...] ]
341 [ ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...] ]
342 [ frame_clause ]
343
344 If an existing_window_name is specified it must refer to an earlier
345 entry in the WINDOW list; the new window copies its partitioning clause
346 from that entry, as well as its ordering clause if any. In this case
347 the new window cannot specify its own PARTITION BY clause, and it can
348 specify ORDER BY only if the copied window does not have one. The new
349 window always uses its own frame clause; the copied window must not
350 specify a frame clause.
351
352 The elements of the PARTITION BY list are interpreted in much the same
353 fashion as elements of a GROUP BY Clause, except that they are always
354 simple expressions and never the name or number of an output column.
355 Another difference is that these expressions can contain aggregate
356 function calls, which are not allowed in a regular GROUP BY clause.
357 They are allowed here because windowing occurs after grouping and
358 aggregation.
359
360 Similarly, the elements of the ORDER BY list are interpreted in much
361 the same fashion as elements of an ORDER BY Clause, except that the
362 expressions are always taken as simple expressions and never the name
363 or number of an output column.
364
365 The optional frame_clause defines the window frame for window functions
366 that depend on the frame (not all do). The window frame is a set of
367 related rows for each row of the query (called the current row). The
368 frame_clause can be one of
369
370 { RANGE | ROWS } frame_start
371 { RANGE | ROWS } BETWEEN frame_start AND frame_end
372
373 where frame_start and frame_end can be one of
374
375 UNBOUNDED PRECEDING
376 value PRECEDING
377 CURRENT ROW
378 value FOLLOWING
379 UNBOUNDED FOLLOWING
380
381 If frame_end is omitted it defaults to CURRENT ROW. Restrictions are
382 that frame_start cannot be UNBOUNDED FOLLOWING, frame_end cannot be
383 UNBOUNDED PRECEDING, and the frame_end choice cannot appear earlier in
384 the above list than the frame_start choice — for example RANGE BETWEEN
385 CURRENT ROW AND value PRECEDING is not allowed.
386
387 The default framing option is RANGE UNBOUNDED PRECEDING, which is the
388 same as RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW; it sets the
389 frame to be all rows from the partition start up through the current
390 row's last peer in the ORDER BY ordering (which means all rows if there
391 is no ORDER BY). In general, UNBOUNDED PRECEDING means that the frame
392 starts with the first row of the partition, and similarly UNBOUNDED
393 FOLLOWING means that the frame ends with the last row of the partition
394 (regardless of RANGE or ROWS mode). In ROWS mode, CURRENT ROW means
395 that the frame starts or ends with the current row; but in RANGE mode
396 it means that the frame starts or ends with the current row's first or
397 last peer in the ORDER BY ordering. The valuePRECEDING and
398 valueFOLLOWING cases are currently only allowed in ROWS mode. They
399 indicate that the frame starts or ends with the row that many rows
400 before or after the current row. value must be an integer expression
401 not containing any variables, aggregate functions, or window functions.
402 The value must not be null or negative; but it can be zero, which
403 selects the current row itself.
404
405 Beware that the ROWS options can produce unpredictable results if the
406 ORDER BY ordering does not order the rows uniquely. The RANGE options
407 are designed to ensure that rows that are peers in the ORDER BY
408 ordering are treated alike; any two peer rows will be both in or both
409 not in the frame.
410
411 The purpose of a WINDOW clause is to specify the behavior of window
412 functions appearing in the query's SELECT List or ORDER BY Clause.
413 These functions can reference the WINDOW clause entries by name in
414 their OVER clauses. A WINDOW clause entry does not have to be
415 referenced anywhere, however; if it is not used in the query it is
416 simply ignored. It is possible to use window functions without any
417 WINDOW clause at all, since a window function call can specify its
418 window definition directly in its OVER clause. However, the WINDOW
419 clause saves typing when the same window definition is needed for more
420 than one window function.
421
422 Window functions are described in detail in Section 3.5, “Window
423 Functions”, in the documentation, Section 4.2.8, “Window Function
424 Calls”, in the documentation, and Section 7.2.4, “Window Function
425 Processing”, in the documentation.
426
427 SELECT List
428 The SELECT list (between the key words SELECT and FROM) specifies
429 expressions that form the output rows of the SELECT statement. The
430 expressions can (and usually do) refer to columns computed in the FROM
431 clause.
432
433 Just as in a table, every output column of a SELECT has a name. In a
434 simple SELECT this name is just used to label the column for display,
435 but when the SELECT is a sub-query of a larger query, the name is seen
436 by the larger query as the column name of the virtual table produced by
437 the sub-query. To specify the name to use for an output column, write
438 ASoutput_name after the column's expression. (You can omit AS, but only
439 if the desired output name does not match any PostgreSQL keyword (see
440 Appendix C, SQL Key Words). For protection against possible future
441 keyword additions, it is recommended that you always either write AS or
442 double-quote the output name.) If you do not specify a column name, a
443 name is chosen automatically by PostgreSQL. If the column's expression
444 is a simple column reference then the chosen name is the same as that
445 column's name. In more complex cases a function or type name may be
446 used, or the system may fall back on a generated name such as ?column?.
447
448 An output column's name can be used to refer to the column's value in
449 ORDER BY and GROUP BY clauses, but not in the WHERE or HAVING clauses;
450 there you must write out the expression instead.
451
452 Instead of an expression, * can be written in the output list as a
453 shorthand for all the columns of the selected rows. Also, you can write
454 table_name.* as a shorthand for the columns coming from just that
455 table. In these cases it is not possible to specify new names with AS;
456 the output column names will be the same as the table columns' names.
457
458 DISTINCT Clause
459 If SELECT DISTINCT is specified, all duplicate rows are removed from
460 the result set (one row is kept from each group of duplicates). SELECT
461 ALL specifies the opposite: all rows are kept; that is the default.
462
463 SELECT DISTINCT ON ( expression [, ...] ) keeps only the first row of
464 each set of rows where the given expressions evaluate to equal. The
465 DISTINCT ON expressions are interpreted using the same rules as for
466 ORDER BY (see above). Note that the “first row” of each set is
467 unpredictable unless ORDER BY is used to ensure that the desired row
468 appears first. For example:
469
470 SELECT DISTINCT ON (location) location, time, report
471 FROM weather_reports
472 ORDER BY location, time DESC;
473
474 retrieves the most recent weather report for each location. But if we
475 had not used ORDER BY to force descending order of time values for each
476 location, we'd have gotten a report from an unpredictable time for each
477 location.
478
479 The DISTINCT ON expression(s) must match the leftmost ORDER BY
480 expression(s). The ORDER BY clause will normally contain additional
481 expression(s) that determine the desired precedence of rows within each
482 DISTINCT ON group.
483
484 UNION Clause
485 The UNION clause has this general form:
486
487 select_statement UNION [ ALL | DISTINCT ] select_statement
488
489 select_statement is any SELECT statement without an ORDER BY, LIMIT,
490 FOR UPDATE, or FOR SHARE clause. (ORDER BY and LIMIT can be attached to
491 a subexpression if it is enclosed in parentheses. Without parentheses,
492 these clauses will be taken to apply to the result of the UNION, not to
493 its right-hand input expression.)
494
495 The UNION operator computes the set union of the rows returned by the
496 involved SELECT statements. A row is in the set union of two result
497 sets if it appears in at least one of the result sets. The two SELECT
498 statements that represent the direct operands of the UNION must produce
499 the same number of columns, and corresponding columns must be of
500 compatible data types.
501
502 The result of UNION does not contain any duplicate rows unless the ALL
503 option is specified. ALL prevents elimination of duplicates.
504 (Therefore, UNION ALL is usually significantly quicker than UNION; use
505 ALL when you can.) DISTINCT can be written to explicitly specify the
506 default behavior of eliminating duplicate rows.
507
508 Multiple UNION operators in the same SELECT statement are evaluated
509 left to right, unless otherwise indicated by parentheses.
510
511 Currently, FOR UPDATE and FOR SHARE cannot be specified either for a
512 UNION result or for any input of a UNION.
513
514 INTERSECT Clause
515 The INTERSECT clause has this general form:
516
517 select_statement INTERSECT [ ALL | DISTINCT ] select_statement
518
519 select_statement is any SELECT statement without an ORDER BY, LIMIT,
520 FOR UPDATE, or FOR SHARE clause.
521
522 The INTERSECT operator computes the set intersection of the rows
523 returned by the involved SELECT statements. A row is in the
524 intersection of two result sets if it appears in both result sets.
525
526 The result of INTERSECT does not contain any duplicate rows unless the
527 ALL option is specified. With ALL, a row that has m duplicates in the
528 left table and n duplicates in the right table will appear min(m,n)
529 times in the result set. DISTINCT can be written to explicitly specify
530 the default behavior of eliminating duplicate rows.
531
532 Multiple INTERSECT operators in the same SELECT statement are evaluated
533 left to right, unless parentheses dictate otherwise. INTERSECT binds
534 more tightly than UNION. That is, A UNION B INTERSECT C will be read as
535 A UNION (B INTERSECT C).
536
537 Currently, FOR UPDATE and FOR SHARE cannot be specified either for an
538 INTERSECT result or for any input of an INTERSECT.
539
540 EXCEPT Clause
541 The EXCEPT clause has this general form:
542
543 select_statement EXCEPT [ ALL | DISTINCT ] select_statement
544
545 select_statement is any SELECT statement without an ORDER BY, LIMIT,
546 FOR UPDATE, or FOR SHARE clause.
547
548 The EXCEPT operator computes the set of rows that are in the result of
549 the left SELECT statement but not in the result of the right one.
550
551 The result of EXCEPT does not contain any duplicate rows unless the ALL
552 option is specified. With ALL, a row that has m duplicates in the left
553 table and n duplicates in the right table will appear max(m-n,0) times
554 in the result set. DISTINCT can be written to explicitly specify the
555 default behavior of eliminating duplicate rows.
556
557 Multiple EXCEPT operators in the same SELECT statement are evaluated
558 left to right, unless parentheses dictate otherwise. EXCEPT binds at
559 the same level as UNION.
560
561 Currently, FOR UPDATE and FOR SHARE cannot be specified either for an
562 EXCEPT result or for any input of an EXCEPT.
563
564 ORDER BY Clause
565 The optional ORDER BY clause has this general form:
566
567 ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ] [, ...]
568
569 The ORDER BY clause causes the result rows to be sorted according to
570 the specified expression(s). If two rows are equal according to the
571 leftmost expression, they are compared according to the next expression
572 and so on. If they are equal according to all specified expressions,
573 they are returned in an implementation-dependent order.
574
575 Each expression can be the name or ordinal number of an output column
576 (SELECT list item), or it can be an arbitrary expression formed from
577 input-column values.
578
579 The ordinal number refers to the ordinal (left-to-right) position of
580 the output column. This feature makes it possible to define an ordering
581 on the basis of a column that does not have a unique name. This is
582 never absolutely necessary because it is always possible to assign a
583 name to an output column using the AS clause.
584
585 It is also possible to use arbitrary expressions in the ORDER BY
586 clause, including columns that do not appear in the SELECT output list.
587 Thus the following statement is valid:
588
589 SELECT name FROM distributors ORDER BY code;
590
591 A limitation of this feature is that an ORDER BY clause applying to the
592 result of a UNION, INTERSECT, or EXCEPT clause can only specify an
593 output column name or number, not an expression.
594
595 If an ORDER BY expression is a simple name that matches both an output
596 column name and an input column name, ORDER BY will interpret it as the
597 output column name. This is the opposite of the choice that GROUP BY
598 will make in the same situation. This inconsistency is made to be
599 compatible with the SQL standard.
600
601 Optionally one can add the key word ASC (ascending) or DESC
602 (descending) after any expression in the ORDER BY clause. If not
603 specified, ASC is assumed by default. Alternatively, a specific
604 ordering operator name can be specified in the USING clause. An
605 ordering operator must be a less-than or greater-than member of some
606 B-tree operator family. ASC is usually equivalent to USING < and DESC
607 is usually equivalent to USING >. (But the creator of a user-defined
608 data type can define exactly what the default sort ordering is, and it
609 might correspond to operators with other names.)
610
611 If NULLS LAST is specified, null values sort after all non-null values;
612 if NULLS FIRST is specified, null values sort before all non-null
613 values. If neither is specified, the default behavior is NULLS LAST
614 when ASC is specified or implied, and NULLS FIRST when DESC is
615 specified (thus, the default is to act as though nulls are larger than
616 non-nulls). When USING is specified, the default nulls ordering depends
617 on whether the operator is a less-than or greater-than operator.
618
619 Note that ordering options apply only to the expression they follow;
620 for example ORDER BY x, y DESC does not mean the same thing as ORDER BY
621 x DESC, y DESC.
622
623 Character-string data is sorted according to the collation that applies
624 to the column being sorted. That can be overridden at need by including
625 a COLLATE clause in the expression, for example ORDER BY mycolumn
626 COLLATE "en_US". For more information see Section 4.2.10, “Collation
627 Expressions”, in the documentation and Section 22.2, “Collation
628 Support”, in the documentation.
629
630 LIMIT Clause
631 The LIMIT clause consists of two independent sub-clauses:
632
633 LIMIT { count | ALL }
634 OFFSET start
635
636 count specifies the maximum number of rows to return, while start
637 specifies the number of rows to skip before starting to return rows.
638 When both are specified, start rows are skipped before starting to
639 count the count rows to be returned.
640
641 If the count expression evaluates to NULL, it is treated as LIMIT ALL,
642 i.e., no limit. If start evaluates to NULL, it is treated the same as
643 OFFSET 0.
644
645 SQL:2008 introduced a different syntax to achieve the same result,
646 which PostgreSQL also supports. It is:
647
648 OFFSET start { ROW | ROWS }
649 FETCH { FIRST | NEXT } [ count ] { ROW | ROWS } ONLY
650
651 In this syntax, to write anything except a simple integer constant for
652 start or count, you must write parentheses around it. If count is
653 omitted in a FETCH clause, it defaults to 1. ROW and ROWS as well as
654 FIRST and NEXT are noise words that don't influence the effects of
655 these clauses. According to the standard, the OFFSET clause must come
656 before the FETCH clause if both are present; but PostgreSQL is laxer
657 and allows either order.
658
659 When using LIMIT, it is a good idea to use an ORDER BY clause that
660 constrains the result rows into a unique order. Otherwise you will get
661 an unpredictable subset of the query's rows — you might be asking for
662 the tenth through twentieth rows, but tenth through twentieth in what
663 ordering? You don't know what ordering unless you specify ORDER BY.
664
665 The query planner takes LIMIT into account when generating a query
666 plan, so you are very likely to get different plans (yielding different
667 row orders) depending on what you use for LIMIT and OFFSET. Thus, using
668 different LIMIT/OFFSET values to select different subsets of a query
669 result will give inconsistent results unless you enforce a predictable
670 result ordering with ORDER BY. This is not a bug; it is an inherent
671 consequence of the fact that SQL does not promise to deliver the
672 results of a query in any particular order unless ORDER BY is used to
673 constrain the order.
674
675 It is even possible for repeated executions of the same LIMIT query to
676 return different subsets of the rows of a table, if there is not an
677 ORDER BY to enforce selection of a deterministic subset. Again, this is
678 not a bug; determinism of the results is simply not guaranteed in such
679 a case.
680
681 FOR UPDATE/FOR SHARE Clause
682 The FOR UPDATE clause has this form:
683
684 FOR UPDATE [ OF table_name [, ...] ] [ NOWAIT ]
685
686 The closely related FOR SHARE clause has this form:
687
688 FOR SHARE [ OF table_name [, ...] ] [ NOWAIT ]
689
690 FOR UPDATE causes the rows retrieved by the SELECT statement to be
691 locked as though for update. This prevents them from being modified or
692 deleted by other transactions until the current transaction ends. That
693 is, other transactions that attempt UPDATE, DELETE, or SELECT FOR
694 UPDATE of these rows will be blocked until the current transaction
695 ends. Also, if an UPDATE, DELETE, or SELECT FOR UPDATE from another
696 transaction has already locked a selected row or rows, SELECT FOR
697 UPDATE will wait for the other transaction to complete, and will then
698 lock and return the updated row (or no row, if the row was deleted).
699 Within a REPEATABLE READ or SERIALIZABLE transaction, however, an error
700 will be thrown if a row to be locked has changed since the transaction
701 started. For further discussion see Chapter 13, Concurrency Control, in
702 the documentation.
703
704 FOR SHARE behaves similarly, except that it acquires a shared rather
705 than exclusive lock on each retrieved row. A shared lock blocks other
706 transactions from performing UPDATE, DELETE, or SELECT FOR UPDATE on
707 these rows, but it does not prevent them from performing SELECT FOR
708 SHARE.
709
710 To prevent the operation from waiting for other transactions to commit,
711 use the NOWAIT option. With NOWAIT, the statement reports an error,
712 rather than waiting, if a selected row cannot be locked immediately.
713 Note that NOWAIT applies only to the row-level lock(s) — the required
714 ROW SHARE table-level lock is still taken in the ordinary way (see
715 Chapter 13, Concurrency Control, in the documentation). You can use
716 LOCK(7) with the NOWAIT option first, if you need to acquire the
717 table-level lock without waiting.
718
719 If specific tables are named in FOR UPDATE or FOR SHARE, then only rows
720 coming from those tables are locked; any other tables used in the
721 SELECT are simply read as usual. A FOR UPDATE or FOR SHARE clause
722 without a table list affects all tables used in the statement. If FOR
723 UPDATE or FOR SHARE is applied to a view or sub-query, it affects all
724 tables used in the view or sub-query. However, FOR UPDATE/FOR SHARE do
725 not apply to WITH queries referenced by the primary query. If you want
726 row locking to occur within a WITH query, specify FOR UPDATE or FOR
727 SHARE within the WITH query.
728
729 Multiple FOR UPDATE and FOR SHARE clauses can be written if it is
730 necessary to specify different locking behavior for different tables.
731 If the same table is mentioned (or implicitly affected) by both FOR
732 UPDATE and FOR SHARE clauses, then it is processed as FOR UPDATE.
733 Similarly, a table is processed as NOWAIT if that is specified in any
734 of the clauses affecting it.
735
736 FOR UPDATE and FOR SHARE cannot be used in contexts where returned rows
737 cannot be clearly identified with individual table rows; for example
738 they cannot be used with aggregation.
739
740 When FOR UPDATE or FOR SHARE appears at the top level of a SELECT
741 query, the rows that are locked are exactly those that are returned by
742 the query; in the case of a join query, the rows locked are those that
743 contribute to returned join rows. In addition, rows that satisfied the
744 query conditions as of the query snapshot will be locked, although they
745 will not be returned if they were updated after the snapshot and no
746 longer satisfy the query conditions. If a LIMIT is used, locking stops
747 once enough rows have been returned to satisfy the limit (but note that
748 rows skipped over by OFFSET will get locked). Similarly, if FOR UPDATE
749 or FOR SHARE is used in a cursor's query, only rows actually fetched or
750 stepped past by the cursor will be locked.
751
752 When FOR UPDATE or FOR SHARE appears in a sub-SELECT, the rows locked
753 are those returned to the outer query by the sub-query. This might
754 involve fewer rows than inspection of the sub-query alone would
755 suggest, since conditions from the outer query might be used to
756 optimize execution of the sub-query. For example,
757
758 SELECT * FROM (SELECT * FROM mytable FOR UPDATE) ss WHERE col1 = 5;
759
760 will lock only rows having col1 = 5, even though that condition is not
761 textually within the sub-query.
762
763 Caution
764 Avoid locking a row and then modifying it within a later savepoint
765 or PL/pgSQL exception block. A subsequent rollback would cause the
766 lock to be lost. For example:
767
768 BEGIN;
769 SELECT * FROM mytable WHERE key = 1 FOR UPDATE;
770 SAVEPOINT s;
771 UPDATE mytable SET ... WHERE key = 1;
772 ROLLBACK TO s;
773
774 After the ROLLBACK, the row is effectively unlocked, rather than
775 returned to its pre-savepoint state of being locked but not
776 modified. This hazard occurs if a row locked in the current
777 transaction is updated or deleted, or if a shared lock is upgraded
778 to exclusive: in all these cases, the former lock state is
779 forgotten. If the transaction is then rolled back to a state
780 between the original locking command and the subsequent change, the
781 row will appear not to be locked at all. This is an implementation
782 deficiency which will be addressed in a future release of
783 PostgreSQL.
784
785 Caution
786 It is possible for a SELECT command running at the READ COMMITTED
787 transaction isolation level and using ORDER BY and FOR UPDATE/SHARE
788 to return rows out of order. This is because ORDER BY is applied
789 first. The command sorts the result, but might then block trying to
790 obtain a lock on one or more of the rows. Once the SELECT unblocks,
791 some of the ordering column values might have been modified,
792 leading to those rows appearing to be out of order (though they are
793 in order in terms of the original column values). This can be
794 worked around at need by placing the FOR UPDATE/SHARE clause in a
795 sub-query, for example
796
797 SELECT * FROM (SELECT * FROM mytable FOR UPDATE) ss ORDER BY column1;
798
799 Note that this will result in locking all rows of mytable, whereas
800 FOR UPDATE at the top level would lock only the actually returned
801 rows. This can make for a significant performance difference,
802 particularly if the ORDER BY is combined with LIMIT or other
803 restrictions. So this technique is recommended only if concurrent
804 updates of the ordering columns are expected and a strictly sorted
805 result is required.
806
807 At the REPEATABLE READ or SERIALIZABLE transaction isolation level
808 this would cause a serialization failure (with a SQLSTATE of
809 '40001'), so there is no possibility of receiving rows out of order
810 under these isolation levels.
811
812 TABLE Command
813 The command
814
815 TABLE name
816
817 is completely equivalent to
818
819 SELECT * FROM name
820
821 It can be used as a top-level command or as a space-saving syntax
822 variant in parts of complex queries.
823
825 To join the table films with the table distributors:
826
827 SELECT f.title, f.did, d.name, f.date_prod, f.kind
828 FROM distributors d, films f
829 WHERE f.did = d.did
830
831 title | did | name | date_prod | kind
832 -------------------+-----+--------------+------------+----------
833 The Third Man | 101 | British Lion | 1949-12-23 | Drama
834 The African Queen | 101 | British Lion | 1951-08-11 | Romantic
835 ...
836
837 To sum the column len of all films and group the results by kind:
838
839 SELECT kind, sum(len) AS total FROM films GROUP BY kind;
840
841 kind | total
842 ----------+-------
843 Action | 07:34
844 Comedy | 02:58
845 Drama | 14:28
846 Musical | 06:42
847 Romantic | 04:38
848
849 To sum the column len of all films, group the results by kind and show
850 those group totals that are less than 5 hours:
851
852 SELECT kind, sum(len) AS total
853 FROM films
854 GROUP BY kind
855 HAVING sum(len) < interval '5 hours';
856
857 kind | total
858 ----------+-------
859 Comedy | 02:58
860 Romantic | 04:38
861
862 The following two examples are identical ways of sorting the individual
863 results according to the contents of the second column (name):
864
865 SELECT * FROM distributors ORDER BY name;
866 SELECT * FROM distributors ORDER BY 2;
867
868 did | name
869 -----+------------------
870 109 | 20th Century Fox
871 110 | Bavaria Atelier
872 101 | British Lion
873 107 | Columbia
874 102 | Jean Luc Godard
875 113 | Luso films
876 104 | Mosfilm
877 103 | Paramount
878 106 | Toho
879 105 | United Artists
880 111 | Walt Disney
881 112 | Warner Bros.
882 108 | Westward
883
884 The next example shows how to obtain the union of the tables
885 distributors and actors, restricting the results to those that begin
886 with the letter W in each table. Only distinct rows are wanted, so the
887 key word ALL is omitted.
888
889 distributors: actors:
890 did | name id | name
891 -----+-------------- ----+----------------
892 108 | Westward 1 | Woody Allen
893 111 | Walt Disney 2 | Warren Beatty
894 112 | Warner Bros. 3 | Walter Matthau
895 ... ...
896
897 SELECT distributors.name
898 FROM distributors
899 WHERE distributors.name LIKE 'W%'
900 UNION
901 SELECT actors.name
902 FROM actors
903 WHERE actors.name LIKE 'W%';
904
905 name
906 ----------------
907 Walt Disney
908 Walter Matthau
909 Warner Bros.
910 Warren Beatty
911 Westward
912 Woody Allen
913
914 This example shows how to use a function in the FROM clause, both with
915 and without a column definition list:
916
917 CREATE FUNCTION distributors(int) RETURNS SETOF distributors AS $$
918 SELECT * FROM distributors WHERE did = $1;
919 $$ LANGUAGE SQL;
920
921 SELECT * FROM distributors(111);
922 did | name
923 -----+-------------
924 111 | Walt Disney
925
926 CREATE FUNCTION distributors_2(int) RETURNS SETOF record AS $$
927 SELECT * FROM distributors WHERE did = $1;
928 $$ LANGUAGE SQL;
929
930 SELECT * FROM distributors_2(111) AS (f1 int, f2 text);
931 f1 | f2
932 -----+-------------
933 111 | Walt Disney
934
935 This example shows how to use a simple WITH clause:
936
937 WITH t AS (
938 SELECT random() as x FROM generate_series(1, 3)
939 )
940 SELECT * FROM t
941 UNION ALL
942 SELECT * FROM t
943
944 x
945 --------------------
946 0.534150459803641
947 0.520092216785997
948 0.0735620250925422
949 0.534150459803641
950 0.520092216785997
951 0.0735620250925422
952
953 Notice that the WITH query was evaluated only once, so that we got two
954 sets of the same three random values.
955
956 This example uses WITH RECURSIVE to find all subordinates (direct or
957 indirect) of the employee Mary, and their level of indirectness, from a
958 table that shows only direct subordinates:
959
960 WITH RECURSIVE employee_recursive(distance, employee_name, manager_name) AS (
961 SELECT 1, employee_name, manager_name
962 FROM employee
963 WHERE manager_name = 'Mary'
964 UNION ALL
965 SELECT er.distance + 1, e.employee_name, e.manager_name
966 FROM employee_recursive er, employee e
967 WHERE er.employee_name = e.manager_name
968 )
969 SELECT distance, employee_name FROM employee_recursive;
970
971 Notice the typical form of recursive queries: an initial condition,
972 followed by UNION, followed by the recursive part of the query. Be sure
973 that the recursive part of the query will eventually return no tuples,
974 or else the query will loop indefinitely. (See Section 7.8, “WITH
975 Queries (Common Table Expressions)”, in the documentation for more
976 examples.)
977
979 Of course, the SELECT statement is compatible with the SQL standard.
980 But there are some extensions and some missing features.
981
982 Omitted FROM Clauses
983 PostgreSQL allows one to omit the FROM clause. It has a straightforward
984 use to compute the results of simple expressions:
985
986 SELECT 2+2;
987
988 ?column?
989 ----------
990 4
991
992 Some other SQL databases cannot do this except by introducing a dummy
993 one-row table from which to do the SELECT.
994
995 Note that if a FROM clause is not specified, the query cannot reference
996 any database tables. For example, the following query is invalid:
997
998 SELECT distributors.* WHERE distributors.name = 'Westward';
999
1000 PostgreSQL releases prior to 8.1 would accept queries of this form, and
1001 add an implicit entry to the query's FROM clause for each table
1002 referenced by the query. This is no longer allowed.
1003
1004 Omitting the AS Key Word
1005 In the SQL standard, the optional key word AS can be omitted before an
1006 output column name whenever the new column name is a valid column name
1007 (that is, not the same as any reserved keyword). PostgreSQL is
1008 slightly more restrictive: AS is required if the new column name
1009 matches any keyword at all, reserved or not. Recommended practice is to
1010 use AS or double-quote output column names, to prevent any possible
1011 conflict against future keyword additions.
1012
1013 In FROM items, both the standard and PostgreSQL allow AS to be omitted
1014 before an alias that is an unreserved keyword. But this is impractical
1015 for output column names, because of syntactic ambiguities.
1016
1017 ONLY and Inheritance
1018 The SQL standard requires parentheses around the table name when
1019 writing ONLY, for example SELECT * FROM ONLY (tab1), ONLY (tab2) WHERE
1020 .... PostgreSQL considers these parentheses to be optional.
1021
1022 PostgreSQL allows a trailing * to be written to explicitly specify the
1023 non-ONLY behavior of including child tables. The standard does not
1024 allow this.
1025
1026 (These points apply equally to all SQL commands supporting the ONLY
1027 option.)
1028
1029 Namespace Available to GROUP BY and ORDER BY
1030 In the SQL-92 standard, an ORDER BY clause can only use output column
1031 names or numbers, while a GROUP BY clause can only use expressions
1032 based on input column names. PostgreSQL extends each of these clauses
1033 to allow the other choice as well (but it uses the standard's
1034 interpretation if there is ambiguity). PostgreSQL also allows both
1035 clauses to specify arbitrary expressions. Note that names appearing in
1036 an expression will always be taken as input-column names, not as
1037 output-column names.
1038
1039 SQL:1999 and later use a slightly different definition which is not
1040 entirely upward compatible with SQL-92. In most cases, however,
1041 PostgreSQL will interpret an ORDER BY or GROUP BY expression the same
1042 way SQL:1999 does.
1043
1044 Functional Dependencies
1045 PostgreSQL recognizes functional dependency (allowing columns to be
1046 omitted from GROUP BY) only when a table's primary key is included in
1047 the GROUP BY list. The SQL standard specifies additional conditions
1048 that should be recognized.
1049
1050 WINDOW Clause Restrictions
1051 The SQL standard provides additional options for the window
1052 frame_clause. PostgreSQL currently supports only the options listed
1053 above.
1054
1055 LIMIT and OFFSET
1056 The clauses LIMIT and OFFSET are PostgreSQL-specific syntax, also used
1057 by MySQL. The SQL:2008 standard has introduced the clauses OFFSET ...
1058 FETCH {FIRST|NEXT} ... for the same functionality, as shown above in
1059 LIMIT Clause. This syntax is also used by IBM DB2. (Applications
1060 written for Oracle frequently use a workaround involving the
1061 automatically generated rownum column, which is not available in
1062 PostgreSQL, to implement the effects of these clauses.)
1063
1064 FOR UPDATE and FOR SHARE
1065 Although FOR UPDATE appears in the SQL standard, the standard allows it
1066 only as an option of DECLARE CURSOR. PostgreSQL allows it in any
1067 SELECT query as well as in sub-SELECTs, but this is an extension. The
1068 FOR SHARE variant, and the NOWAIT option, do not appear in the
1069 standard.
1070
1071 Data-Modifying Statements in WITH
1072 PostgreSQL allows INSERT, UPDATE, and DELETE to be used as WITH
1073 queries. This is not found in the SQL standard.
1074
1075 Nonstandard Clauses
1076 The clause DISTINCT ON is not defined in the SQL standard.
1077
1078
1079
1080PostgreSQL 9.2.24 2017-11-06 SELECT(7)