2 4.2. Value Expressions #
4 4.2.1. Column References
5 4.2.2. Positional Parameters
8 4.2.5. Operator Invocations
10 4.2.7. Aggregate Expressions
11 4.2.8. Window Function Calls
13 4.2.10. Collation Expressions
14 4.2.11. Scalar Subqueries
15 4.2.12. Array Constructors
16 4.2.13. Row Constructors
17 4.2.14. Expression Evaluation Rules
19 Value expressions are used in a variety of contexts, such as in the
20 target list of the SELECT command, as new column values in INSERT or
21 UPDATE, or in search conditions in a number of commands. The result of
22 a value expression is sometimes called a scalar, to distinguish it from
23 the result of a table expression (which is a table). Value expressions
24 are therefore also called scalar expressions (or even simply
25 expressions). The expression syntax allows the calculation of values
26 from primitive parts using arithmetic, logical, set, and other
29 A value expression is one of the following:
30 * A constant or literal value
32 * A positional parameter reference, in the body of a function
33 definition or prepared statement
34 * A subscripted expression
35 * A field selection expression
36 * An operator invocation
38 * An aggregate expression
39 * A window function call
41 * A collation expression
43 * An array constructor
45 * Another value expression in parentheses (used to group
46 subexpressions and override precedence)
48 In addition to this list, there are a number of constructs that can be
49 classified as an expression but do not follow any general syntax rules.
50 These generally have the semantics of a function or operator and are
51 explained in the appropriate location in Chapter 9. An example is the
54 We have already discussed constants in Section 4.1.2. The following
55 sections discuss the remaining options.
57 4.2.1. Column References #
59 A column can be referenced in the form:
60 correlation.columnname
62 correlation is the name of a table (possibly qualified with a schema
63 name), or an alias for a table defined by means of a FROM clause. The
64 correlation name and separating dot can be omitted if the column name
65 is unique across all the tables being used in the current query. (See
68 4.2.2. Positional Parameters #
70 A positional parameter reference is used to indicate a value that is
71 supplied externally to an SQL statement. Parameters are used in SQL
72 function definitions and in prepared queries. Some client libraries
73 also support specifying data values separately from the SQL command
74 string, in which case parameters are used to refer to the out-of-line
75 data values. The form of a parameter reference is:
78 For example, consider the definition of a function, dept, as:
79 CREATE FUNCTION dept(text) RETURNS dept
80 AS $$ SELECT * FROM dept WHERE name = $1 $$
83 Here the $1 references the value of the first function argument
84 whenever the function is invoked.
88 If an expression yields a value of an array type, then a specific
89 element of the array value can be extracted by writing
92 or multiple adjacent elements (an “array slice”) can be extracted by
94 expression[lower_subscript:upper_subscript]
96 (Here, the brackets [ ] are meant to appear literally.) Each subscript
97 is itself an expression, which will be rounded to the nearest integer
100 In general the array expression must be parenthesized, but the
101 parentheses can be omitted when the expression to be subscripted is
102 just a column reference or positional parameter. Also, multiple
103 subscripts can be concatenated when the original array is
104 multidimensional. For example:
105 mytable.arraycolumn[4]
106 mytable.two_d_column[17][34]
108 (arrayfunction(a,b))[42]
110 The parentheses in the last example are required. See Section 8.15 for
113 4.2.4. Field Selection #
115 If an expression yields a value of a composite type (row type), then a
116 specific field of the row can be extracted by writing
119 In general the row expression must be parenthesized, but the
120 parentheses can be omitted when the expression to be selected from is
121 just a table reference or positional parameter. For example:
124 (rowfunction(a,b)).col3
126 (Thus, a qualified column reference is actually just a special case of
127 the field selection syntax.) An important special case is extracting a
128 field from a table column that is of a composite type:
129 (compositecol).somefield
130 (mytable.compositecol).somefield
132 The parentheses are required here to show that compositecol is a column
133 name not a table name, or that mytable is a table name not a schema
134 name in the second case.
136 You can ask for all fields of a composite value by writing .*:
139 This notation behaves differently depending on context; see
140 Section 8.16.5 for details.
142 4.2.5. Operator Invocations #
144 There are two possible syntaxes for an operator invocation:
145 expression operator expression (binary infix operator)
146 operator expression (unary prefix operator)
148 where the operator token follows the syntax rules of Section 4.1.3, or
149 is one of the key words AND, OR, and NOT, or is a qualified operator
151 OPERATOR(schema.operatorname)
153 Which particular operators exist and whether they are unary or binary
154 depends on what operators have been defined by the system or the user.
155 Chapter 9 describes the built-in operators.
157 4.2.6. Function Calls #
159 The syntax for a function call is the name of a function (possibly
160 qualified with a schema name), followed by its argument list enclosed
162 function_name ([expression [, expression ... ]] )
164 For example, the following computes the square root of 2:
167 The list of built-in functions is in Chapter 9. Other functions can be
170 When issuing queries in a database where some users mistrust other
171 users, observe security precautions from Section 10.3 when writing
174 The arguments can optionally have names attached. See Section 4.3 for
179 A function that takes a single argument of composite type can
180 optionally be called using field-selection syntax, and conversely field
181 selection can be written in functional style. That is, the notations
182 col(table) and table.col are interchangeable. This behavior is not
183 SQL-standard but is provided in PostgreSQL because it allows use of
184 functions to emulate “computed fields”. For more information see
187 4.2.7. Aggregate Expressions #
189 An aggregate expression represents the application of an aggregate
190 function across the rows selected by a query. An aggregate function
191 reduces multiple inputs to a single output value, such as the sum or
192 average of the inputs. The syntax of an aggregate expression is one of
194 aggregate_name (expression [ , ... ] [ order_by_clause ] ) [ FILTER ( WHERE filt
196 aggregate_name (ALL expression [ , ... ] [ order_by_clause ] ) [ FILTER ( WHERE
198 aggregate_name (DISTINCT expression [ , ... ] [ order_by_clause ] ) [ FILTER ( W
199 HERE filter_clause ) ]
200 aggregate_name ( * ) [ FILTER ( WHERE filter_clause ) ]
201 aggregate_name ( [ expression [ , ... ] ] ) WITHIN GROUP ( order_by_clause ) [ F
202 ILTER ( WHERE filter_clause ) ]
204 where aggregate_name is a previously defined aggregate (possibly
205 qualified with a schema name) and expression is any value expression
206 that does not itself contain an aggregate expression or a window
207 function call. The optional order_by_clause and filter_clause are
210 The first form of aggregate expression invokes the aggregate once for
211 each input row. The second form is the same as the first, since ALL is
212 the default. The third form invokes the aggregate once for each
213 distinct value of the expression (or distinct set of values, for
214 multiple expressions) found in the input rows. The fourth form invokes
215 the aggregate once for each input row; since no particular input value
216 is specified, it is generally only useful for the count(*) aggregate
217 function. The last form is used with ordered-set aggregate functions,
218 which are described below.
220 Most aggregate functions ignore null inputs, so that rows in which one
221 or more of the expression(s) yield null are discarded. This can be
222 assumed to be true, unless otherwise specified, for all built-in
225 For example, count(*) yields the total number of input rows; count(f1)
226 yields the number of input rows in which f1 is non-null, since count
227 ignores nulls; and count(distinct f1) yields the number of distinct
228 non-null values of f1.
230 Ordinarily, the input rows are fed to the aggregate function in an
231 unspecified order. In many cases this does not matter; for example, min
232 produces the same result no matter what order it receives the inputs
233 in. However, some aggregate functions (such as array_agg and
234 string_agg) produce results that depend on the ordering of the input
235 rows. When using such an aggregate, the optional order_by_clause can be
236 used to specify the desired ordering. The order_by_clause has the same
237 syntax as for a query-level ORDER BY clause, as described in
238 Section 7.5, except that its expressions are always just expressions
239 and cannot be output-column names or numbers. For example:
240 WITH vals (v) AS ( VALUES (1),(3),(4),(3),(2) )
241 SELECT array_agg(v ORDER BY v DESC) FROM vals;
246 Since jsonb only keeps the last matching key, ordering of its keys can
248 WITH vals (k, v) AS ( VALUES ('key0','1'), ('key1','3'), ('key1','2') )
249 SELECT jsonb_object_agg(k, v ORDER BY v) FROM vals;
251 ----------------------------
252 {"key0": "1", "key1": "3"}
254 When dealing with multiple-argument aggregate functions, note that the
255 ORDER BY clause goes after all the aggregate arguments. For example,
257 SELECT string_agg(a, ',' ORDER BY a) FROM table;
260 SELECT string_agg(a ORDER BY a, ',') FROM table; -- incorrect
262 The latter is syntactically valid, but it represents a call of a
263 single-argument aggregate function with two ORDER BY keys (the second
264 one being rather useless since it's a constant).
266 If DISTINCT is specified with an order_by_clause, ORDER BY expressions
267 can only reference columns in the DISTINCT list. For example:
268 WITH vals (v) AS ( VALUES (1),(3),(4),(3),(2) )
269 SELECT array_agg(DISTINCT v ORDER BY v DESC) FROM vals;
274 Placing ORDER BY within the aggregate's regular argument list, as
275 described so far, is used when ordering the input rows for
276 general-purpose and statistical aggregates, for which ordering is
277 optional. There is a subclass of aggregate functions called ordered-set
278 aggregates for which an order_by_clause is required, usually because
279 the aggregate's computation is only sensible in terms of a specific
280 ordering of its input rows. Typical examples of ordered-set aggregates
281 include rank and percentile calculations. For an ordered-set aggregate,
282 the order_by_clause is written inside WITHIN GROUP (...), as shown in
283 the final syntax alternative above. The expressions in the
284 order_by_clause are evaluated once per input row just like regular
285 aggregate arguments, sorted as per the order_by_clause's requirements,
286 and fed to the aggregate function as input arguments. (This is unlike
287 the case for a non-WITHIN GROUP order_by_clause, which is not treated
288 as argument(s) to the aggregate function.) The argument expressions
289 preceding WITHIN GROUP, if any, are called direct arguments to
290 distinguish them from the aggregated arguments listed in the
291 order_by_clause. Unlike regular aggregate arguments, direct arguments
292 are evaluated only once per aggregate call, not once per input row.
293 This means that they can contain variables only if those variables are
294 grouped by GROUP BY; this restriction is the same as if the direct
295 arguments were not inside an aggregate expression at all. Direct
296 arguments are typically used for things like percentile fractions,
297 which only make sense as a single value per aggregation calculation.
298 The direct argument list can be empty; in this case, write just () not
299 (*). (PostgreSQL will actually accept either spelling, but only the
300 first way conforms to the SQL standard.)
302 An example of an ordered-set aggregate call is:
303 SELECT percentile_cont(0.5) WITHIN GROUP (ORDER BY income) FROM households;
308 which obtains the 50th percentile, or median, value of the income
309 column from table households. Here, 0.5 is a direct argument; it would
310 make no sense for the percentile fraction to be a value varying across
313 If FILTER is specified, then only the input rows for which the
314 filter_clause evaluates to true are fed to the aggregate function;
315 other rows are discarded. For example:
317 count(*) AS unfiltered,
318 count(*) FILTER (WHERE i < 5) AS filtered
319 FROM generate_series(1,10) AS s(i);
320 unfiltered | filtered
321 ------------+----------
325 The predefined aggregate functions are described in Section 9.21. Other
326 aggregate functions can be added by the user.
328 An aggregate expression can only appear in the result list or HAVING
329 clause of a SELECT command. It is forbidden in other clauses, such as
330 WHERE, because those clauses are logically evaluated before the results
331 of aggregates are formed.
333 When an aggregate expression appears in a subquery (see Section 4.2.11
334 and Section 9.24), the aggregate is normally evaluated over the rows of
335 the subquery. But an exception occurs if the aggregate's arguments (and
336 filter_clause if any) contain only outer-level variables: the aggregate
337 then belongs to the nearest such outer level, and is evaluated over the
338 rows of that query. The aggregate expression as a whole is then an
339 outer reference for the subquery it appears in, and acts as a constant
340 over any one evaluation of that subquery. The restriction about
341 appearing only in the result list or HAVING clause applies with respect
342 to the query level that the aggregate belongs to.
344 4.2.8. Window Function Calls #
346 A window function call represents the application of an aggregate-like
347 function over some portion of the rows selected by a query. Unlike
348 non-window aggregate calls, this is not tied to grouping of the
349 selected rows into a single output row — each row remains separate in
350 the query output. However the window function has access to all the
351 rows that would be part of the current row's group according to the
352 grouping specification (PARTITION BY list) of the window function call.
353 The syntax of a window function call is one of the following:
354 function_name ([expression [, expression ... ]]) [ FILTER ( WHERE filter_clause
356 function_name ([expression [, expression ... ]]) [ FILTER ( WHERE filter_clause
357 ) ] OVER ( window_definition )
358 function_name ( * ) [ FILTER ( WHERE filter_clause ) ] OVER window_name
359 function_name ( * ) [ FILTER ( WHERE filter_clause ) ] OVER ( window_definition
362 where window_definition has the syntax
363 [ existing_window_name ]
364 [ PARTITION BY expression [, ...] ]
365 [ ORDER BY expression [ ASC | DESC | USING operator ] [ NULLS { FIRST | LAST } ]
369 The optional frame_clause can be one of
370 { RANGE | ROWS | GROUPS } frame_start [ frame_exclusion ]
371 { RANGE | ROWS | GROUPS } BETWEEN frame_start AND frame_end [ frame_exclusion ]
373 where frame_start and frame_end can be one of
380 and frame_exclusion can be one of
386 Here, expression represents any value expression that does not itself
387 contain window function calls.
389 window_name is a reference to a named window specification defined in
390 the query's WINDOW clause. Alternatively, a full window_definition can
391 be given within parentheses, using the same syntax as for defining a
392 named window in the WINDOW clause; see the SELECT reference page for
393 details. It's worth pointing out that OVER wname is not exactly
394 equivalent to OVER (wname ...); the latter implies copying and
395 modifying the window definition, and will be rejected if the referenced
396 window specification includes a frame clause.
398 The PARTITION BY clause groups the rows of the query into partitions,
399 which are processed separately by the window function. PARTITION BY
400 works similarly to a query-level GROUP BY clause, except that its
401 expressions are always just expressions and cannot be output-column
402 names or numbers. Without PARTITION BY, all rows produced by the query
403 are treated as a single partition. The ORDER BY clause determines the
404 order in which the rows of a partition are processed by the window
405 function. It works similarly to a query-level ORDER BY clause, but
406 likewise cannot use output-column names or numbers. Without ORDER BY,
407 rows are processed in an unspecified order.
409 The frame_clause specifies the set of rows constituting the window
410 frame, which is a subset of the current partition, for those window
411 functions that act on the frame instead of the whole partition. The set
412 of rows in the frame can vary depending on which row is the current
413 row. The frame can be specified in RANGE, ROWS or GROUPS mode; in each
414 case, it runs from the frame_start to the frame_end. If frame_end is
415 omitted, the end defaults to CURRENT ROW.
417 A frame_start of UNBOUNDED PRECEDING means that the frame starts with
418 the first row of the partition, and similarly a frame_end of UNBOUNDED
419 FOLLOWING means that the frame ends with the last row of the partition.
421 In RANGE or GROUPS mode, a frame_start of CURRENT ROW means the frame
422 starts with the current row's first peer row (a row that the window's
423 ORDER BY clause sorts as equivalent to the current row), while a
424 frame_end of CURRENT ROW means the frame ends with the current row's
425 last peer row. In ROWS mode, CURRENT ROW simply means the current row.
427 In the offset PRECEDING and offset FOLLOWING frame options, the offset
428 must be an expression not containing any variables, aggregate
429 functions, or window functions. The meaning of the offset depends on
431 * In ROWS mode, the offset must yield a non-null, non-negative
432 integer, and the option means that the frame starts or ends the
433 specified number of rows before or after the current row.
434 * In GROUPS mode, the offset again must yield a non-null,
435 non-negative integer, and the option means that the frame starts or
436 ends the specified number of peer groups before or after the
437 current row's peer group, where a peer group is a set of rows that
438 are equivalent in the ORDER BY ordering. (There must be an ORDER BY
439 clause in the window definition to use GROUPS mode.)
440 * In RANGE mode, these options require that the ORDER BY clause
441 specify exactly one column. The offset specifies the maximum
442 difference between the value of that column in the current row and
443 its value in preceding or following rows of the frame. The data
444 type of the offset expression varies depending on the data type of
445 the ordering column. For numeric ordering columns it is typically
446 of the same type as the ordering column, but for datetime ordering
447 columns it is an interval. For example, if the ordering column is
448 of type date or timestamp, one could write RANGE BETWEEN '1 day'
449 PRECEDING AND '10 days' FOLLOWING. The offset is still required to
450 be non-null and non-negative, though the meaning of “non-negative”
451 depends on its data type.
453 In any case, the distance to the end of the frame is limited by the
454 distance to the end of the partition, so that for rows near the
455 partition ends the frame might contain fewer rows than elsewhere.
457 Notice that in both ROWS and GROUPS mode, 0 PRECEDING and 0 FOLLOWING
458 are equivalent to CURRENT ROW. This normally holds in RANGE mode as
459 well, for an appropriate data-type-specific meaning of “zero”.
461 The frame_exclusion option allows rows around the current row to be
462 excluded from the frame, even if they would be included according to
463 the frame start and frame end options. EXCLUDE CURRENT ROW excludes the
464 current row from the frame. EXCLUDE GROUP excludes the current row and
465 its ordering peers from the frame. EXCLUDE TIES excludes any peers of
466 the current row from the frame, but not the current row itself. EXCLUDE
467 NO OTHERS simply specifies explicitly the default behavior of not
468 excluding the current row or its peers.
470 The default framing option is RANGE UNBOUNDED PRECEDING, which is the
471 same as RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW. With ORDER
472 BY, this sets the frame to be all rows from the partition start up
473 through the current row's last ORDER BY peer. Without ORDER BY, this
474 means all rows of the partition are included in the window frame, since
475 all rows become peers of the current row.
477 Restrictions are that frame_start cannot be UNBOUNDED FOLLOWING,
478 frame_end cannot be UNBOUNDED PRECEDING, and the frame_end choice
479 cannot appear earlier in the above list of frame_start and frame_end
480 options than the frame_start choice does — for example RANGE BETWEEN
481 CURRENT ROW AND offset PRECEDING is not allowed. But, for example, ROWS
482 BETWEEN 7 PRECEDING AND 8 PRECEDING is allowed, even though it would
483 never select any rows.
485 If FILTER is specified, then only the input rows for which the
486 filter_clause evaluates to true are fed to the window function; other
487 rows are discarded. Only window functions that are aggregates accept a
490 The built-in window functions are described in Table 9.67. Other window
491 functions can be added by the user. Also, any built-in or user-defined
492 general-purpose or statistical aggregate can be used as a window
493 function. (Ordered-set and hypothetical-set aggregates cannot presently
494 be used as window functions.)
496 The syntaxes using * are used for calling parameter-less aggregate
497 functions as window functions, for example count(*) OVER (PARTITION BY
498 x ORDER BY y). The asterisk (*) is customarily not used for
499 window-specific functions. Window-specific functions do not allow
500 DISTINCT or ORDER BY to be used within the function argument list.
502 Window function calls are permitted only in the SELECT list and the
503 ORDER BY clause of the query.
505 More information about window functions can be found in Section 3.5,
506 Section 9.22, and Section 7.2.5.
510 A type cast specifies a conversion from one data type to another.
511 PostgreSQL accepts two equivalent syntaxes for type casts:
512 CAST ( expression AS type )
515 The CAST syntax conforms to SQL; the syntax with :: is historical
518 When a cast is applied to a value expression of a known type, it
519 represents a run-time type conversion. The cast will succeed only if a
520 suitable type conversion operation has been defined. Notice that this
521 is subtly different from the use of casts with constants, as shown in
522 Section 4.1.2.7. A cast applied to an unadorned string literal
523 represents the initial assignment of a type to a literal constant
524 value, and so it will succeed for any type (if the contents of the
525 string literal are acceptable input syntax for the data type).
527 An explicit type cast can usually be omitted if there is no ambiguity
528 as to the type that a value expression must produce (for example, when
529 it is assigned to a table column); the system will automatically apply
530 a type cast in such cases. However, automatic casting is only done for
531 casts that are marked “OK to apply implicitly” in the system catalogs.
532 Other casts must be invoked with explicit casting syntax. This
533 restriction is intended to prevent surprising conversions from being
536 It is also possible to specify a type cast using a function-like
538 typename ( expression )
540 However, this only works for types whose names are also valid as
541 function names. For example, double precision cannot be used this way,
542 but the equivalent float8 can. Also, the names interval, time, and
543 timestamp can only be used in this fashion if they are double-quoted,
544 because of syntactic conflicts. Therefore, the use of the function-like
545 cast syntax leads to inconsistencies and should probably be avoided.
549 The function-like syntax is in fact just a function call. When one of
550 the two standard cast syntaxes is used to do a run-time conversion, it
551 will internally invoke a registered function to perform the conversion.
552 By convention, these conversion functions have the same name as their
553 output type, and thus the “function-like syntax” is nothing more than a
554 direct invocation of the underlying conversion function. Obviously,
555 this is not something that a portable application should rely on. For
556 further details see CREATE CAST.
558 4.2.10. Collation Expressions #
560 The COLLATE clause overrides the collation of an expression. It is
561 appended to the expression it applies to:
562 expr COLLATE collation
564 where collation is a possibly schema-qualified identifier. The COLLATE
565 clause binds tighter than operators; parentheses can be used when
568 If no collation is explicitly specified, the database system either
569 derives a collation from the columns involved in the expression, or it
570 defaults to the default collation of the database if no column is
571 involved in the expression.
573 The two common uses of the COLLATE clause are overriding the sort order
574 in an ORDER BY clause, for example:
575 SELECT a, b, c FROM tbl WHERE ... ORDER BY a COLLATE "C";
577 and overriding the collation of a function or operator call that has
578 locale-sensitive results, for example:
579 SELECT * FROM tbl WHERE a > 'foo' COLLATE "C";
581 Note that in the latter case the COLLATE clause is attached to an input
582 argument of the operator we wish to affect. It doesn't matter which
583 argument of the operator or function call the COLLATE clause is
584 attached to, because the collation that is applied by the operator or
585 function is derived by considering all arguments, and an explicit
586 COLLATE clause will override the collations of all other arguments.
587 (Attaching non-matching COLLATE clauses to more than one argument,
588 however, is an error. For more details see Section 23.2.) Thus, this
589 gives the same result as the previous example:
590 SELECT * FROM tbl WHERE a COLLATE "C" > 'foo';
592 But this is an error:
593 SELECT * FROM tbl WHERE (a > 'foo') COLLATE "C";
595 because it attempts to apply a collation to the result of the >
596 operator, which is of the non-collatable data type boolean.
598 4.2.11. Scalar Subqueries #
600 A scalar subquery is an ordinary SELECT query in parentheses that
601 returns exactly one row with one column. (See Chapter 7 for information
602 about writing queries.) The SELECT query is executed and the single
603 returned value is used in the surrounding value expression. It is an
604 error to use a query that returns more than one row or more than one
605 column as a scalar subquery. (But if, during a particular execution,
606 the subquery returns no rows, there is no error; the scalar result is
607 taken to be null.) The subquery can refer to variables from the
608 surrounding query, which will act as constants during any one
609 evaluation of the subquery. See also Section 9.24 for other expressions
610 involving subqueries.
612 For example, the following finds the largest city population in each
614 SELECT name, (SELECT max(pop) FROM cities WHERE cities.state = states.name)
617 4.2.12. Array Constructors #
619 An array constructor is an expression that builds an array value using
620 values for its member elements. A simple array constructor consists of
621 the key word ARRAY, a left square bracket [, a list of expressions
622 (separated by commas) for the array element values, and finally a right
623 square bracket ]. For example:
624 SELECT ARRAY[1,2,3+4];
630 By default, the array element type is the common type of the member
631 expressions, determined using the same rules as for UNION or CASE
632 constructs (see Section 10.5). You can override this by explicitly
633 casting the array constructor to the desired type, for example:
634 SELECT ARRAY[1,2,22.7]::integer[];
640 This has the same effect as casting each expression to the array
641 element type individually. For more on casting, see Section 4.2.9.
643 Multidimensional array values can be built by nesting array
644 constructors. In the inner constructors, the key word ARRAY can be
645 omitted. For example, these produce the same result:
646 SELECT ARRAY[ARRAY[1,2], ARRAY[3,4]];
652 SELECT ARRAY[[1,2],[3,4]];
658 Since multidimensional arrays must be rectangular, inner constructors
659 at the same level must produce sub-arrays of identical dimensions. Any
660 cast applied to the outer ARRAY constructor propagates automatically to
661 all the inner constructors.
663 Multidimensional array constructor elements can be anything yielding an
664 array of the proper kind, not only a sub-ARRAY construct. For example:
665 CREATE TABLE arr(f1 int[], f2 int[]);
667 INSERT INTO arr VALUES (ARRAY[[1,2],[3,4]], ARRAY[[5,6],[7,8]]);
669 SELECT ARRAY[f1, f2, '{{9,10},{11,12}}'::int[]] FROM arr;
671 ------------------------------------------------
672 {{{1,2},{3,4}},{{5,6},{7,8}},{{9,10},{11,12}}}
675 You can construct an empty array, but since it's impossible to have an
676 array with no type, you must explicitly cast your empty array to the
677 desired type. For example:
678 SELECT ARRAY[]::integer[];
684 It is also possible to construct an array from the results of a
685 subquery. In this form, the array constructor is written with the key
686 word ARRAY followed by a parenthesized (not bracketed) subquery. For
688 SELECT ARRAY(SELECT oid FROM pg_proc WHERE proname LIKE 'bytea%');
690 ------------------------------------------------------------------
691 {2011,1954,1948,1952,1951,1244,1950,2005,1949,1953,2006,31,2412}
694 SELECT ARRAY(SELECT ARRAY[i, i*2] FROM generate_series(1,5) AS a(i));
696 ----------------------------------
697 {{1,2},{2,4},{3,6},{4,8},{5,10}}
700 The subquery must return a single column. If the subquery's output
701 column is of a non-array type, the resulting one-dimensional array will
702 have an element for each row in the subquery result, with an element
703 type matching that of the subquery's output column. If the subquery's
704 output column is of an array type, the result will be an array of the
705 same type but one higher dimension; in this case all the subquery rows
706 must yield arrays of identical dimensionality, else the result would
709 The subscripts of an array value built with ARRAY always begin with
710 one. For more information about arrays, see Section 8.15.
712 4.2.13. Row Constructors #
714 A row constructor is an expression that builds a row value (also called
715 a composite value) using values for its member fields. A row
716 constructor consists of the key word ROW, a left parenthesis, zero or
717 more expressions (separated by commas) for the row field values, and
718 finally a right parenthesis. For example:
719 SELECT ROW(1,2.5,'this is a test');
721 The key word ROW is optional when there is more than one expression in
724 A row constructor can include the syntax rowvalue.*, which will be
725 expanded to a list of the elements of the row value, just as occurs
726 when the .* syntax is used at the top level of a SELECT list (see
727 Section 8.16.5). For example, if table t has columns f1 and f2, these
729 SELECT ROW(t.*, 42) FROM t;
730 SELECT ROW(t.f1, t.f2, 42) FROM t;
734 Before PostgreSQL 8.2, the .* syntax was not expanded in row
735 constructors, so that writing ROW(t.*, 42) created a two-field row
736 whose first field was another row value. The new behavior is usually
737 more useful. If you need the old behavior of nested row values, write
738 the inner row value without .*, for instance ROW(t, 42).
740 By default, the value created by a ROW expression is of an anonymous
741 record type. If necessary, it can be cast to a named composite type —
742 either the row type of a table, or a composite type created with CREATE
743 TYPE AS. An explicit cast might be needed to avoid ambiguity. For
745 CREATE TABLE mytable(f1 int, f2 float, f3 text);
747 CREATE FUNCTION getf1(mytable) RETURNS int AS 'SELECT $1.f1' LANGUAGE SQL;
749 -- No cast needed since only one getf1() exists
750 SELECT getf1(ROW(1,2.5,'this is a test'));
756 CREATE TYPE myrowtype AS (f1 int, f2 text, f3 numeric);
758 CREATE FUNCTION getf1(myrowtype) RETURNS int AS 'SELECT $1.f1' LANGUAGE SQL;
760 -- Now we need a cast to indicate which function to call:
761 SELECT getf1(ROW(1,2.5,'this is a test'));
762 ERROR: function getf1(record) is not unique
764 SELECT getf1(ROW(1,2.5,'this is a test')::mytable);
770 SELECT getf1(CAST(ROW(11,'this is a test',2.5) AS myrowtype));
776 Row constructors can be used to build composite values to be stored in
777 a composite-type table column, or to be passed to a function that
778 accepts a composite parameter. Also, it is possible to test rows using
779 the standard comparison operators as described in Section 9.2, to
780 compare one row against another as described in Section 9.25, and to
781 use them in connection with subqueries, as discussed in Section 9.24.
783 4.2.14. Expression Evaluation Rules #
785 The order of evaluation of subexpressions is not defined. In
786 particular, the inputs of an operator or function are not necessarily
787 evaluated left-to-right or in any other fixed order.
789 Furthermore, if the result of an expression can be determined by
790 evaluating only some parts of it, then other subexpressions might not
791 be evaluated at all. For instance, if one wrote:
792 SELECT true OR somefunc();
794 then somefunc() would (probably) not be called at all. The same would
795 be the case if one wrote:
796 SELECT somefunc() OR true;
798 Note that this is not the same as the left-to-right “short-circuiting”
799 of Boolean operators that is found in some programming languages.
801 As a consequence, it is unwise to use functions with side effects as
802 part of complex expressions. It is particularly dangerous to rely on
803 side effects or evaluation order in WHERE and HAVING clauses, since
804 those clauses are extensively reprocessed as part of developing an
805 execution plan. Boolean expressions (AND/OR/NOT combinations) in those
806 clauses can be reorganized in any manner allowed by the laws of Boolean
809 When it is essential to force evaluation order, a CASE construct (see
810 Section 9.18) can be used. For example, this is an untrustworthy way of
811 trying to avoid division by zero in a WHERE clause:
812 SELECT ... WHERE x > 0 AND y/x > 1.5;
815 SELECT ... WHERE CASE WHEN x > 0 THEN y/x > 1.5 ELSE false END;
817 A CASE construct used in this fashion will defeat optimization
818 attempts, so it should only be done when necessary. (In this particular
819 example, it would be better to sidestep the problem by writing y >
822 CASE is not a cure-all for such issues, however. One limitation of the
823 technique illustrated above is that it does not prevent early
824 evaluation of constant subexpressions. As described in Section 36.7,
825 functions and operators marked IMMUTABLE can be evaluated when the
826 query is planned rather than when it is executed. Thus for example
827 SELECT CASE WHEN x > 0 THEN x ELSE 1/0 END FROM tab;
829 is likely to result in a division-by-zero failure due to the planner
830 trying to simplify the constant subexpression, even if every row in the
831 table has x > 0 so that the ELSE arm would never be entered at run
834 While that particular example might seem silly, related cases that
835 don't obviously involve constants can occur in queries executed within
836 functions, since the values of function arguments and local variables
837 can be inserted into queries as constants for planning purposes. Within
838 PL/pgSQL functions, for example, using an IF-THEN-ELSE statement to
839 protect a risky computation is much safer than just nesting it in a
842 Another limitation of the same kind is that a CASE cannot prevent
843 evaluation of an aggregate expression contained within it, because
844 aggregate expressions are computed before other expressions in a SELECT
845 list or HAVING clause are considered. For example, the following query
846 can cause a division-by-zero error despite seemingly having protected
848 SELECT CASE WHEN min(employees) > 0
849 THEN avg(expenses / employees)
853 The min() and avg() aggregates are computed concurrently over all the
854 input rows, so if any row has employees equal to zero, the
855 division-by-zero error will occur before there is any opportunity to
856 test the result of min(). Instead, use a WHERE or FILTER clause to
857 prevent problematic input rows from reaching an aggregate function in