SQL Syntax
syntax
SQL
This chapter describes the syntax of SQL. It forms the foundation
for understanding the following chapters which will go into detail
about how the SQL commands are applied to define and modify data.
We also advise users who are already familiar with SQL to read this
chapter carefully because there are several rules and concepts that
are implemented inconsistently among SQL databases or that are
specific to PostgreSQL.
Lexical Structure
token
SQL input consists of a sequence of
commands. A command is composed of a
sequence of tokens, terminated by a
semicolon (;
). The end of the input stream also
terminates a command. Which tokens are valid depends on the syntax
of the particular command.
A token can be a key word, an
identifier, a quoted
identifier, a literal (or
constant), or a special character symbol. Tokens are normally
separated by whitespace (space, tab, newline), but need not be if
there is no ambiguity (which is generally only the case if a
special character is adjacent to some other token type).
Additionally, comments can occur in SQL
input. They are not tokens, they are effectively equivalent to
whitespace.
For example, the following is (syntactically) valid SQL input:
SELECT * FROM MY_TABLE;
UPDATE MY_TABLE SET A = 5;
INSERT INTO MY_TABLE VALUES (3, 'hi there');
This is a sequence of three commands, one per line (although this
is not required; more than one command can be on a line, and
commands can usefully be split across lines).
The SQL syntax is not very consistent regarding what tokens
identify commands and which are operands or parameters. The first
few tokens are generally the command name, so in the above example
we would usually speak of a SELECT
, an
UPDATE
, and an INSERT
command. But
for instance the UPDATE command always requires
a SET token to appear in a certain position, and
this particular variation of INSERT also
requires a VALUES in order to be complete. The
precise syntax rules for each command are described in .
Identifiers and Key Words
identifier
syntax of
name
syntax of
key word
syntax of
Tokens such as SELECT, UPDATE, or
VALUES in the example above are examples of
key words, that is, words that have a fixed
meaning in the SQL language. The tokens MY_TABLE
and A are examples of
identifiers. They identify names of
tables, columns, or other database objects, depending on the
command they are used in. Therefore they are sometimes simply
called names
. Key words and identifiers have the
same lexical structure, meaning that one cannot know whether a
token is an identifier or a key word without knowing the language.
A complete list of key words can be found in .
SQL identifiers and key words must begin with a letter
(a-z, but also letters with
diacritical marks and non-Latin letters) or an underscore
(_). Subsequent characters in an identifier or
key word can be letters, underscores, digits
(0-9), or dollar signs
($>). Note that dollar signs are not allowed in identifiers
according to the letter of the SQL standard, so their use may render
applications less portable.
The SQL standard will not define a key word that contains
digits or starts or ends with an underscore, so identifiers of this
form are safe against possible conflict with future extensions of the
standard.
identifierlength
The system uses no more than NAMEDATALEN-1
characters of an identifier; longer names can be written in
commands, but they will be truncated. By default,
NAMEDATALEN is 64 so the maximum identifier
length is 63. If this limit is problematic, it can be raised by
changing the NAMEDATALEN constant in
src/include/postgres_ext.h.
case sensitivity
of SQL commands
Identifier and key word names are case insensitive. Therefore
UPDATE MY_TABLE SET A = 5;
can equivalently be written as
uPDaTE my_TabLE SeT a = 5;
A convention often used is to write key words in upper
case and names in lower case, e.g.,
UPDATE my_table SET a = 5;
quotation marks
and identifiers
There is a second kind of identifier: the delimited
identifier or quoted
identifier. It is formed by enclosing an arbitrary
sequence of characters in double-quotes
("). A delimited
identifier is always an identifier, never a key word. So
"select" could be used to refer to a column or
table named select
, whereas an unquoted
select would be taken as a key word and
would therefore provoke a parse error when used where a table or
column name is expected. The example can be written with quoted
identifiers like this:
UPDATE "my_table" SET "a" = 5;
Quoted identifiers can contain any character other than a double
quote itself. (To include a double quote, write two double quotes.)
This allows constructing table or column names that would
otherwise not be possible, such as ones containing spaces or
ampersands. The length limitation still applies.
Quoting an identifier also makes it case-sensitive, whereas
unquoted names are always folded to lower case. For example, the
identifiers FOO, foo, and
"foo" are considered the same by
PostgreSQL, but
"Foo" and "FOO" are
different from these three and each other. (The folding of
unquoted names to lower case in PostgreSQL> is
incompatible with the SQL standard, which says that unquoted names
should be folded to upper case. Thus, foo
should be equivalent to "FOO" not
"foo" according to the standard. If you want
to write portable applications you are advised to always quote a
particular name or never quote it.)
Constants
constant
There are three kinds of implicitly-typed
constants in PostgreSQL:
strings, bit strings, and numbers.
Constants can also be specified with explicit types, which can
enable more accurate representation and more efficient handling by
the system. These alternatives are discussed in the following
subsections.
String Constants
character string
constant
quotation marks
escaping
A string constant in SQL is an arbitrary sequence of characters
bounded by single quotes ('), for example
'This is a string'. The standard-compliant way of
writing a single-quote character within a string constant is to
write two adjacent single quotes, e.g.
'Dianne''s horse'.
PostgreSQL also allows single quotes
to be escaped with a backslash (\'). However,
future versions of PostgreSQL will not
allow this, so applications using backslashes should convert to the
standard-compliant method outlined above.
Another PostgreSQL extension is that
C-style backslash escapes are available: \b is a
backspace, \f is a form feed,
\n is a newline, \r is a
carriage return, \t is a tab. Also supported is
\digits, where
digits represents an octal byte value, and
\xhexdigits, where
hexdigits represents a hexadecimal byte value.
(It is your responsibility that the byte sequences you create are
valid characters in the server character set encoding.) Any other
character following a backslash is taken literally. Thus, to
include a backslash in a string constant, write two backslashes.
While ordinary strings now support C-style backslash escapes,
future versions will generate warnings for such usage and
eventually treat backslashes as literal characters to be
standard-conforming. The proper way to specify escape processing is
to use the escape string syntax to indicate that escape
processing is desired. Escape string syntax is specified by writing
the letter E (upper or lower case) just before
the string, e.g. E'\041'>. This method will work in all
future versions of PostgreSQL.
The character with the code zero cannot be in a string constant.
Two string constants that are only separated by whitespace
with at least one newline are concatenated
and effectively treated as if the string had been written in one
constant. For example:
SELECT 'foo'
'bar';
is equivalent to
SELECT 'foobar';
but
SELECT 'foo' 'bar';
is not valid syntax. (This slightly bizarre behavior is specified
by SQL; PostgreSQL is
following the standard.)
Dollar-Quoted String Constants
dollar quoting
While the standard syntax for specifying string constants is usually
convenient, it can be difficult to understand when the desired string
contains many single quotes or backslashes, since each of those must
be doubled. To allow more readable queries in such situations,
PostgreSQL provides another way, called
dollar quoting
, to write string constants.
A dollar-quoted string constant
consists of a dollar sign ($), an optional
tag
of zero or more characters, another dollar
sign, an arbitrary sequence of characters that makes up the
string content, a dollar sign, the same tag that began this
dollar quote, and a dollar sign. For example, here are two
different ways to specify the string Dianne's horse>
using dollar quoting:
$$Dianne's horse$$
$SomeTag$Dianne's horse$SomeTag$
Notice that inside the dollar-quoted string, single quotes can be
used without needing to be escaped. Indeed, no characters inside
a dollar-quoted string are ever escaped: the string content is always
written literally. Backslashes are not special, and neither are
dollar signs, unless they are part of a sequence matching the opening
tag.
It is possible to nest dollar-quoted string constants by choosing
different tags at each nesting level. This is most commonly used in
writing function definitions. For example:
$function$
BEGIN
RETURN ($1 ~ $q$[\t\r\n\v\\]$q$);
END;
$function$
Here, the sequence $q$[\t\r\n\v\\]$q$> represents a
dollar-quoted literal string [\t\r\n\v\\]>, which will
be recognized when the function body is executed by
PostgreSQL>. But since the sequence does not match
the outer dollar quoting delimiter $function$>, it is
just some more characters within the constant so far as the outer
string is concerned.
The tag, if any, of a dollar-quoted string follows the same rules
as an unquoted identifier, except that it cannot contain a dollar sign.
Tags are case sensitive, so $tag$String content$tag$
is correct, but $TAG$String content$tag$ is not.
A dollar-quoted string that follows a keyword or identifier must
be separated from it by whitespace; otherwise the dollar quoting
delimiter would be taken as part of the preceding identifier.
Dollar quoting is not part of the SQL standard, but it is often a more
convenient way to write complicated string literals than the
standard-compliant single quote syntax. It is particularly useful when
representing string constants inside other constants, as is often needed
in procedural function definitions. With single-quote syntax, each
backslash in the above example would have to be written as four
backslashes, which would be reduced to two backslashes in parsing the
original string constant, and then to one when the inner string constant
is re-parsed during function execution.
Bit-String Constants
bit string
constant
Bit-string constants look like regular string constants with a
B (upper or lower case) immediately before the
opening quote (no intervening whitespace), e.g.,
B'1001'. The only characters allowed within
bit-string constants are 0 and
1.
Alternatively, bit-string constants can be specified in hexadecimal
notation, using a leading X (upper or lower case),
e.g., X'1FF'. This notation is equivalent to
a bit-string constant with four binary digits for each hexadecimal digit.
Both forms of bit-string constant can be continued
across lines in the same way as regular string constants.
Dollar quoting cannot be used in a bit-string constant.
Numeric Constants
number
constant
Numeric constants are accepted in these general forms:
digits
digits.digitse+-digits
digits.digitse+-digits
digitse+-digits
where digits is one or more decimal
digits (0 through 9). At least one digit must be before or after the
decimal point, if one is used. At least one digit must follow the
exponent marker (e), if one is present.
There may not be any spaces or other characters embedded in the
constant. Note that any leading plus or minus sign is not actually
considered part of the constant; it is an operator applied to the
constant.
These are some examples of valid numeric constants:
42
3.5
4.
.001
5e2
1.925e-3
integer
bigint
numeric
A numeric constant that contains neither a decimal point nor an
exponent is initially presumed to be type integer> if its
value fits in type integer> (32 bits); otherwise it is
presumed to be type bigint> if its
value fits in type bigint> (64 bits); otherwise it is
taken to be type numeric>. Constants that contain decimal
points and/or exponents are always initially presumed to be type
numeric>.
The initially assigned data type of a numeric constant is just a
starting point for the type resolution algorithms. In most cases
the constant will be automatically coerced to the most
appropriate type depending on context. When necessary, you can
force a numeric value to be interpreted as a specific data type
by casting it.type cast
For example, you can force a numeric value to be treated as type
real> (float4>) by writing
REAL '1.23' -- string style
1.23::REAL -- PostgreSQL (historical) style
These are actually just special cases of the general casting
notations discussed next.
Constants of Other Types
data type
constant
A constant of an arbitrary type can be
entered using any one of the following notations:
type 'string'
'string'::type
CAST ( 'string' AS type )
The string constant's text is passed to the input conversion
routine for the type called type. The
result is a constant of the indicated type. The explicit type
cast may be omitted if there is no ambiguity as to the type the
constant must be (for example, when it is assigned directly to a
table column), in which case it is automatically coerced.
The string constant can be written using either regular SQL
notation or dollar-quoting.
It is also possible to specify a type coercion using a function-like
syntax:
typename ( 'string' )
but not all type names may be used in this way; see for details.
The ::, CAST(), and
function-call syntaxes can also be used to specify run-time type
conversions of arbitrary expressions, as discussed in . But the form
type 'string'
can only be used to specify the type of a literal constant.
Another restriction on
type 'string'
is that it does not work for array types; use ::
or CAST() to specify the type of an array constant.
The CAST()> syntax conforms to SQL. The
type 'string'
syntax is a generalization of the standard: SQL specifies this syntax only
for a few data types, but PostgreSQL allows it
for all types. The syntax with
:: is historical PostgreSQL
usage, as is the function-call syntax.
Operators
operator
syntax
An operator name is a sequence of up to NAMEDATALEN-1
(63 by default) characters from the following list:
+ - * / < > = ~ ! @ # % ^ & | ` ?
There are a few restrictions on operator names, however:
-- and /* cannot appear
anywhere in an operator name, since they will be taken as the
start of a comment.
A multiple-character operator name cannot end in +> or ->,
unless the name also contains at least one of these characters:
~ ! @ # % ^ & | ` ?
For example, @- is an allowed operator name,
but *- is not. This restriction allows
PostgreSQL to parse SQL-compliant
queries without requiring spaces between tokens.
When working with non-SQL-standard operator names, you will usually
need to separate adjacent operators with spaces to avoid ambiguity.
For example, if you have defined a left unary operator named @,
you cannot write X*@Y; you must write
X* @Y to ensure that
PostgreSQL reads it as two operator names
not one.
Special Characters
Some characters that are not alphanumeric have a special meaning
that is different from being an operator. Details on the usage can
be found at the location where the respective syntax element is
described. This section only exists to advise the existence and
summarize the purposes of these characters.
A dollar sign ($) followed by digits is used
to represent a positional parameter in the body of a function
definition or a prepared statement. In other contexts the
dollar sign may be part of an identifier or a dollar-quoted string
constant.
Parentheses (()) have their usual meaning to
group expressions and enforce precedence. In some cases
parentheses are required as part of the fixed syntax of a
particular SQL command.
Brackets ([]) are used to select the elements
of an array. See for more information
on arrays.
Commas (,) are used in some syntactical
constructs to separate the elements of a list.
The semicolon (;) terminates an SQL command.
It cannot appear anywhere within a command, except within a
string constant or quoted identifier.
The colon (:) is used to select
slices
from arrays. (See .) In certain SQL dialects (such as Embedded
SQL), the colon is used to prefix variable names.
The asterisk (*) is used in some contexts to denote
all the fields of a table row or composite value. It also
has a special meaning when used as the argument of the
COUNT aggregate function.
The period (.) is used in numeric
constants, and to separate schema, table, and column names.
Lexical Precedence
operator
precedence
shows the precedence and
associativity of the operators in PostgreSQL>.
Most operators have the same precedence and are left-associative.
The precedence and associativity of the operators is hard-wired
into the parser. This may lead to non-intuitive behavior; for
example the Boolean operators <> and
>> have a different precedence than the Boolean
operators <=> and >=>. Also, you will
sometimes need to add parentheses when using combinations of
binary and unary operators. For instance
SELECT 5 ! - 6;
will be parsed as
SELECT 5 ! (- 6);
because the parser has no idea — until it is too late
— that ! is defined as a postfix operator,
not an infix one. To get the desired behavior in this case, you
must write
SELECT (5 !) - 6;
This is the price one pays for extensibility.
Operator Precedence (decreasing)
Operator/Element
Associativity
Description
.
left
table/column name separator
::
left
PostgreSQL-style typecast
[ ]
left
array element selection
-
right
unary minus
^
left
exponentiation
* / %
left
multiplication, division, modulo
+ -
left
addition, subtraction
IS
IS TRUE>, IS FALSE>, IS UNKNOWN>, IS NULL>
ISNULL
test for null
NOTNULL
test for not null
(any other)
left
all other native and user-defined operators
IN
set membership
BETWEEN
range containment
OVERLAPS
time interval overlap
LIKE ILIKE SIMILAR
string pattern matching
< >
less than, greater than
=
right
equality, assignment
NOT
right
logical negation
AND
left
logical conjunction
OR
left
logical disjunction
Note that the operator precedence rules also apply to user-defined
operators that have the same names as the built-in operators
mentioned above. For example, if you define a
+
operator for some custom data type it will have
the same precedence as the built-in +
operator, no
matter what yours does.
When a schema-qualified operator name is used in the
OPERATOR> syntax, as for example in
SELECT 3 OPERATOR(pg_catalog.+) 4;
the OPERATOR> construct is taken to have the default precedence
shown in for any other> operator. This is true no matter
which specific operator name appears inside OPERATOR()>.
Value Expressions
expression
syntax
value expression
scalar
expression
Value expressions are used in a variety of contexts, such
as in the target list of the SELECT command, as
new column values in INSERT or
UPDATE, or in search conditions in a number of
commands. The result of a value expression is sometimes called a
scalar, to distinguish it from the result of
a table expression (which is a table). Value expressions are
therefore also called scalar expressions (or
even simply expressions). The expression
syntax allows the calculation of values from primitive parts using
arithmetic, logical, set, and other operations.
A value expression is one of the following:
A constant or literal value.
A column reference.
A positional parameter reference, in the body of a function definition
or prepared statement.
A subscripted expression.
A field selection expression.
An operator invocation.
A function call.
An aggregate expression.
A type cast.
A scalar subquery.
An array constructor.
A row constructor.
Another value expression in parentheses, useful to group
subexpressions and override
precedence.parenthesis>>
In addition to this list, there are a number of constructs that can
be classified as an expression but do not follow any general syntax
rules. These generally have the semantics of a function or
operator and are explained in the appropriate location in . An example is the IS NULL
clause.
We have already discussed constants in . The following sections discuss
the remaining options.
Column References
column reference
A column can be referenced in the form
correlation.columnname
correlation is the name of a
table (possibly qualified with a schema name), or an alias for a table
defined by means of a FROM clause, or one of
the key words NEW or OLD.
(NEW and OLD can only appear in rewrite rules,
while other correlation names can be used in any SQL statement.)
The correlation name and separating dot may be omitted if the column name
is unique across all the tables being used in the current query. (See also .)
Positional Parameters
parameter
syntax
$
A positional parameter reference is used to indicate a value
that is supplied externally to an SQL statement. Parameters are
used in SQL function definitions and in prepared queries. Some
client libraries also support specifying data values separately
from the SQL command string, in which case parameters are used to
refer to the out-of-line data values.
The form of a parameter reference is:
$number
For example, consider the definition of a function,
dept, as
CREATE FUNCTION dept(text) RETURNS dept
AS $$ SELECT * FROM dept WHERE name = $1 $$
LANGUAGE SQL;
Here the $1 references the value of the first
function argument whenever the function is invoked.
Subscripts
subscript
If an expression yields a value of an array type, then a specific
element of the array value can be extracted by writing
expression[subscript]
or multiple adjacent elements (an array slice>) can be extracted
by writing
expression[lower_subscript:upper_subscript]
(Here, the brackets [ ] are meant to appear literally.)
Each subscript is itself an expression,
which must yield an integer value.
In general the array expression must be
parenthesized, but the parentheses may be omitted when the expression
to be subscripted is just a column reference or positional parameter.
Also, multiple subscripts can be concatenated when the original array
is multidimensional.
For example,
mytable.arraycolumn[4]
mytable.two_d_column[17][34]
$1[10:42]
(arrayfunction(a,b))[42]
The parentheses in the last example are required.
See for more about arrays.
Field Selection
field selection
If an expression yields a value of a composite type (row type), then a
specific field of the row can be extracted by writing
expression.fieldname
In general the row expression must be
parenthesized, but the parentheses may be omitted when the expression
to be selected from is just a table reference or positional parameter.
For example,
mytable.mycolumn
$1.somecolumn
(rowfunction(a,b)).col3
(Thus, a qualified column reference is actually just a special case
of the field selection syntax.)
Operator Invocations
operator
invocation
There are three possible syntaxes for an operator invocation:
expression operator expression (binary infix operator)
operator expression (unary prefix operator)
expression operator (unary postfix operator)
where the operator token follows the syntax
rules of , or is one of the
key words AND, OR, and
NOT, or is a qualified operator name in the form
OPERATOR(>schema>.>operatorname>)>
Which particular operators exist and whether
they are unary or binary depends on what operators have been
defined by the system or the user.
describes the built-in operators.
Function Calls
function
invocation
The syntax for a function call is the name of a function
(possibly qualified with a schema name), followed by its argument list
enclosed in parentheses:
function (expression , expression ... )
For example, the following computes the square root of 2:
sqrt(2)
The list of built-in functions is in .
Other functions may be added by the user.
Aggregate Expressions
aggregate function
invocation
An aggregate expression represents the
application of an aggregate function across the rows selected by a
query. An aggregate function reduces multiple inputs to a single
output value, such as the sum or average of the inputs. The
syntax of an aggregate expression is one of the following:
aggregate_name (expression)
aggregate_name (ALL expression)
aggregate_name (DISTINCT expression)
aggregate_name ( * )
where aggregate_name is a previously
defined aggregate (possibly qualified with a schema name), and
expression is
any value expression that does not itself contain an aggregate
expression.
The first form of aggregate expression invokes the aggregate
across all input rows for which the given expression yields a
non-null value. (Actually, it is up to the aggregate function
whether to ignore null values or not — but all the standard ones do.)
The second form is the same as the first, since
ALL is the default. The third form invokes the
aggregate for all distinct non-null values of the expression found
in the input rows. The last form invokes the aggregate once for
each input row regardless of null or non-null values; since no
particular input value is specified, it is generally only useful
for the count() aggregate function.
For example, count(*) yields the total number
of input rows; count(f1) yields the number of
input rows in which f1 is non-null;
count(distinct f1) yields the number of
distinct non-null values of f1.
The predefined aggregate functions are described in . Other aggregate functions may be added
by the user.
An aggregate expression may only appear in the result list or
HAVING> clause of a SELECT> command.
It is forbidden in other clauses, such as WHERE>,
because those clauses are logically evaluated before the results
of aggregates are formed.
When an aggregate expression appears in a subquery (see
and
), the aggregate is normally
evaluated over the rows of the subquery. But an exception occurs
if the aggregate's argument contains only outer-level variables:
the aggregate then belongs to the nearest such outer level, and is
evaluated over the rows of that query. The aggregate expression
as a whole is then an outer reference for the subquery it appears in,
and acts as a constant over any one evaluation of that subquery.
The restriction about
appearing only in the result list or HAVING> clause
applies with respect to the query level that the aggregate belongs to.
Type Casts
data type
type cast
type cast
A type cast specifies a conversion from one data type to another.
PostgreSQL accepts two equivalent syntaxes
for type casts:
CAST ( expression AS type )
expression::type
The CAST> syntax conforms to SQL; the syntax with
:: is historical PostgreSQL
usage.
When a cast is applied to a value expression of a known type, it
represents a run-time type conversion. The cast will succeed only
if a suitable type conversion operation has been defined. Notice that this
is subtly different from the use of casts with constants, as shown in
. A cast applied to an
unadorned string literal represents the initial assignment of a type
to a literal constant value, and so it will succeed for any type
(if the contents of the string literal are acceptable input syntax for the
data type).
An explicit type cast may usually be omitted if there is no ambiguity as
to the type that a value expression must produce (for example, when it is
assigned to a table column); the system will automatically apply a
type cast in such cases. However, automatic casting is only done for
casts that are marked OK to apply implicitly>
in the system catalogs. Other casts must be invoked with
explicit casting syntax. This restriction is intended to prevent
surprising conversions from being applied silently.
It is also possible to specify a type cast using a function-like
syntax:
typename ( expression )
However, this only works for types whose names are also valid as
function names. For example, double precision
can't be used this way, but the equivalent float8
can. Also, the names interval>, time>, and
timestamp> can only be used in this fashion if they are
double-quoted, because of syntactic conflicts. Therefore, the use of
the function-like cast syntax leads to inconsistencies and should
probably be avoided in new applications.
(The function-like syntax is in fact just a function call. When
one of the two standard cast syntaxes is used to do a run-time
conversion, it will internally invoke a registered function to
perform the conversion. By convention, these conversion functions
have the same name as their output type, and thus the function-like
syntax> is nothing more than a direct invocation of the underlying
conversion function. Obviously, this is not something that a portable
application should rely on.)
Scalar Subqueries
subquery
A scalar subquery is an ordinary
SELECT query in parentheses that returns exactly one
row with one column. (See for information about writing queries.)
The SELECT query is executed
and the single returned value is used in the surrounding value expression.
It is an error to use a query that
returns more than one row or more than one column as a scalar subquery.
(But if, during a particular execution, the subquery returns no rows,
there is no error; the scalar result is taken to be null.)
The subquery can refer to variables from the surrounding query,
which will act as constants during any one evaluation of the subquery.
See also for other expressions involving subqueries.
For example, the following finds the largest city population in each
state:
SELECT name, (SELECT max(pop) FROM cities WHERE cities.state = states.name)
FROM states;
Array Constructors
array
constructor
ARRAY
An array constructor is an expression that builds an
array value from values for its member elements. A simple array
constructor
consists of the key word ARRAY, a left square bracket
[>, one or more expressions (separated by commas) for the
array element values, and finally a right square bracket ]>.
For example,
SELECT ARRAY[1,2,3+4];
array
---------
{1,2,7}
(1 row)
The array element type is the common type of the member expressions,
determined using the same rules as for UNION> or
CASE> constructs (see ).
Multidimensional array values can be built by nesting array
constructors.
In the inner constructors, the key word ARRAY may
be omitted. For example, these produce the same result:
SELECT ARRAY[ARRAY[1,2], ARRAY[3,4]];
array
---------------
{{1,2},{3,4}}
(1 row)
SELECT ARRAY[[1,2],[3,4]];
array
---------------
{{1,2},{3,4}}
(1 row)
Since multidimensional arrays must be rectangular, inner constructors
at the same level must produce sub-arrays of identical dimensions.
Multidimensional array constructor elements can be anything yielding
an array of the proper kind, not only a sub-ARRAY> construct.
For example:
CREATE TABLE arr(f1 int[], f2 int[]);
INSERT INTO arr VALUES (ARRAY[[1,2],[3,4]], ARRAY[[5,6],[7,8]]);
SELECT ARRAY[f1, f2, '{{9,10},{11,12}}'::int[]] FROM arr;
array
------------------------------------------------
{{{1,2},{3,4}},{{5,6},{7,8}},{{9,10},{11,12}}}
(1 row)
It is also possible to construct an array from the results of a
subquery. In this form, the array constructor is written with the
key word ARRAY followed by a parenthesized (not
bracketed) subquery. For example:
SELECT ARRAY(SELECT oid FROM pg_proc WHERE proname LIKE 'bytea%');
?column?
-------------------------------------------------------------
{2011,1954,1948,1952,1951,1244,1950,2005,1949,1953,2006,31}
(1 row)
The subquery must return a single column. The resulting
one-dimensional array will have an element for each row in the
subquery result, with an element type matching that of the
subquery's output column.
The subscripts of an array value built with ARRAY
always begin with one. For more information about arrays, see
.
Row Constructors
composite type
constructor
row type
constructor
ROW
A row constructor is an expression that builds a row value (also
called a composite value) from values
for its member fields. A row constructor consists of the key word
ROW, a left parenthesis, zero or more
expressions (separated by commas) for the row field values, and finally
a right parenthesis. For example,
SELECT ROW(1,2.5,'this is a test');
The key word ROW> is optional when there is more than one
expression in the list.
A row constructor can include the syntax
rowvalue.*,
which will be expanded to a list of the elements of the row value,
just as occurs when the .*> syntax is used at the top level
of a SELECT> list. For example, if table t> has
columns f1> and f2>, these are the same:
SELECT ROW(t.*, 42) FROM t;
SELECT ROW(t.f1, t.f2, 42) FROM t;
Before PostgreSQL 8.2, the
.* syntax was not expanded, so that writing
ROW(t.*, 42)> created a two-field row whose first field
was another row value. The new behavior is usually more useful.
If you need the old behavior of nested row values, write the inner
row value without .*, for instance
ROW(t, 42)>.
By default, the value created by a ROW> expression is of
an anonymous record type. If necessary, it can be cast to a named
composite type — either the row type of a table, or a composite type
created with CREATE TYPE AS>. An explicit cast may be needed
to avoid ambiguity. For example:
CREATE TABLE mytable(f1 int, f2 float, f3 text);
CREATE FUNCTION getf1(mytable) RETURNS int AS 'SELECT $1.f1' LANGUAGE SQL;
-- No cast needed since only one getf1() exists
SELECT getf1(ROW(1,2.5,'this is a test'));
getf1
-------
1
(1 row)
CREATE TYPE myrowtype AS (f1 int, f2 text, f3 numeric);
CREATE FUNCTION getf1(myrowtype) RETURNS int AS 'SELECT $1.f1' LANGUAGE SQL;
-- Now we need a cast to indicate which function to call:
SELECT getf1(ROW(1,2.5,'this is a test'));
ERROR: function getf1(record) is not unique
SELECT getf1(ROW(1,2.5,'this is a test')::mytable);
getf1
-------
1
(1 row)
SELECT getf1(CAST(ROW(11,'this is a test',2.5) AS myrowtype));
getf1
-------
11
(1 row)
Row constructors can be used to build composite values to be stored
in a composite-type table column, or to be passed to a function that
accepts a composite parameter. Also,
it is possible to compare two row values or test a row with
IS NULL> or IS NOT NULL>, for example
SELECT ROW(1,2.5,'this is a test') = ROW(1, 3, 'not the same');
SELECT ROW(table.*) IS NULL FROM table; -- detect all-null rows
For more detail see .
Row constructors can also be used in connection with subqueries,
as discussed in .
Expression Evaluation Rules
expression
order of evaluation
The order of evaluation of subexpressions is not defined. In
particular, the inputs of an operator or function are not necessarily
evaluated left-to-right or in any other fixed order.
Furthermore, if the result of an expression can be determined by
evaluating only some parts of it, then other subexpressions
might not be evaluated at all. For instance, if one wrote
SELECT true OR somefunc();
then somefunc() would (probably) not be called
at all. The same would be the case if one wrote
SELECT somefunc() OR true;
Note that this is not the same as the left-to-right
short-circuiting
of Boolean operators that is found
in some programming languages.
As a consequence, it is unwise to use functions with side effects
as part of complex expressions. It is particularly dangerous to
rely on side effects or evaluation order in WHERE> and HAVING> clauses,
since those clauses are extensively reprocessed as part of
developing an execution plan. Boolean
expressions (AND>/OR>/NOT> combinations) in those clauses may be reorganized
in any manner allowed by the laws of Boolean algebra.
When it is essential to force evaluation order, a CASE>
construct (see ) may be
used. For example, this is an untrustworthy way of trying to
avoid division by zero in a WHERE> clause:
SELECT ... WHERE x <> 0 AND y/x > 1.5;
But this is safe:
SELECT ... WHERE CASE WHEN x <> 0 THEN y/x > 1.5 ELSE false END;
A CASE> construct used in this fashion will defeat optimization
attempts, so it should only be done when necessary. (In this particular
example, it would doubtless be best to sidestep the problem by writing
y > 1.5*x> instead.)