Skip to main content
Version: 2.x

Value Expressions

Value expressions are the core components that allow you to calculate, transform, and reference data within a query. When defining queries, understanding these expressions is key to writing flexible and effective SQL.

This document explains types of expressions such as column references, positional parameters, array and row constructors, function calls, and type casts. Each type plays a specific role in how data is processed and represented in a query result.

Column references

A column reference has the form:

<correlation>.<columnname>

Here, <correlation> is the name of a table (possibly qualified with a schema name) or an alias for a table defined with a FROM clause or one of the keywords NEW or OLD. NEW and OLD can appear only in rewrite rules, but you can use other correlation names in any SQL statement. If the column name is unique across all tables in the query, you can omit the <correlation> part of the column reference.

Positional parameters

Positional parameters are arguments to SQL statements or functions that you reference by their positions in a series of arguments. For example, $1 refers to the first argument, $2 to the second argument, and so on. The values of positional parameters are set from arguments external to the SQL statement or supplied when SQL functions are invoked. Some client libraries support specifying data values separately from the SQL command, in which case parameters refer to the out-of-line data values. A parameter reference has the form:

$number

For example:

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

If an expression yields a value of an array type, you can extract a specific element of the array value as follows:

<expression>[<subscript>]

You can extract multiple adjacent elements, called an array slice, as follows (including the brackets):

<expression>[<lower_subscript>:<upper_subscript>]

Each subscript is an expression and yields an integer value.

Array expressions usually must be in parentheses, but you can omit the parentheses when the expression to be subscripted is a column reference or positional parameter. You can concatenate multiple subscripts when the original array is multidimensional. For example (including the parentheses):

mytable.arraycolumn[4]
mytable.two_d_column[17][34]
$1[10:42]
(arrayfunction(a,b))[42]

Field selection

If an expression yields a value of a composite type (row type), you can extract a specific field of the row as follows:

<expression>.<fieldname>

The row expression usually must be in parentheses, but you can omit these parentheses when the expression to be selected from is a table reference or positional parameter. For example:

mytable.mycolumn
$1.somecolumn
(rowfunction(a,b)).col3

A qualified column reference is a special case of field selection syntax.

Operator invocations

Operator invocations have the following possible syntaxes:

<expression operator expression>(binary infix operator)
<operator expression>(unary prefix operator)
<expression operator>(unary postfix operator)

Where operator is an operator token, one of the key words AND, OR, or NOT, or qualified operator name in the form:

OPERATOR(<schema>.<operatorname>)

Available operators and whether they are unary or binary depends on the operators that the system or user defines.

Function calls

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 function call computes the square root of 2:

sqrt(2)

Type casts

A type cast specifies a conversion from one data type to another. A cast applied to a value expression of a known type is a run-time type conversion. The cast succeeds only if a suitable type conversion is defined. This differs from the use of casts with constants. A cast applied to a string literal represents the initial assignment of a type to a literal constant value, so it succeeds for any type if the contents of the string literal are acceptable input syntax for the data type.

Apache Cloudberry supports three types of casts applied to a value expression:

  • Explicit cast - Apache Cloudberry applies a cast when you explicitly specify a cast between two data types. Apache Cloudberry accepts two equivalent syntaxes for explicit type casts:

    CAST ( expression AS type )
    expression::type

    The CAST syntax conforms to SQL; the syntax using :: is historical PostgreSQL usage.

  • Assignment cast - Apache Cloudberry implicitly invokes a cast in assignment contexts, when assigning a value to a column of the target data type. For example, a CREATE CAST command with the AS ASSIGNMENT clause creates a cast that is applied implicitly in the assignment context. This example assignment cast assumes that tbl1.f1 is a column of type text. The INSERT command is allowed because the value is implicitly cast from the integer to text type.

    INSERT INTO tbl1 (f1) VALUES (42);
  • Implicit cast - Apache Cloudberry implicitly invokes a cast in assignment or expression contexts. For example, a CREATE CAST command with the AS IMPLICIT clause creates an implicit cast, a cast that is applied implicitly in both the assignment and expression context. This example implicit cast assumes that tbl1.c1 is a column of type int. For the calculation in the predicate, the value of c1 is implicitly cast from int to a decimal type.

    SELECT * FROM tbl1 WHERE tbl1.c2 = (4.3 + tbl1.c1) ;

You can usually omit an explicit type cast if there is no ambiguity about the type a value expression must produce (for example, when it is assigned to a table column); the system automatically applies a type cast. Apache Cloudberry implicitly applies casts only to casts defined with a cast context of assignment or explicit in the system catalogs. Other casts must be invoked with explicit casting syntax to prevent unexpected conversions from being applied without the user's knowledge.

You can display cast information with the psql meta-command dC. Cast information is stored in the catalog table pg_cast, and type information is stored in the catalog table pg_type.

Array constructors

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 a right square bracket ]. For example,

SELECT ARRAY[1,2,3+4];
array
---------
{1,2,7}

The array element type is the common type of its member expressions, determined using the same rules as for UNION or CASE constructs.

You can build multidimensional array values by nesting array constructors. In the inner constructors, you can omit the keyword ARRAY. For example, the following two SELECT statements produce the same result:

SELECT ARRAY[ARRAY[1,2], ARRAY[3,4]];
SELECT ARRAY[[1,2],[3,4]];
array
---------------
{{1,2},{3,4}}

because multidimensional arrays must be rectangular, inner constructors at the same level must produce sub-arrays of identical dimensions.

Multidimensional array constructor elements are not limited to a sub-ARRAY construct; they are anything that produces an array of the proper kind. 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}}}

You can construct an array from the results of a subquery. Write the array constructor with the keyword ARRAY followed by a subquery in parentheses. 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}

The subquery must return a single column. The resulting one-dimensional array has 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 1.

Row constructors

A row constructor is an expression that builds a row value (also called a composite value) from values for its member fields. For example,

SELECT ROW(1,2.5,'this is a test');

Row constructors have the syntax rowvalue.*, which expands to a list of the elements of the row value, as when you use the syntax .* at the top level of a SELECT list. For example, if table t has columns f1 and f2, the following queries are the same:

SELECT ROW(t.*, 42) FROM t;
SELECT ROW(t.f1, t.f2, 42) FROM t;

By default, the value created by a ROW expression has 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. To avoid ambiguity, you can explicitly cast the value if necessary. For example:

CREATE TABLE mytable(f1 int, f2 float, f3 text);
CREATE FUNCTION getf1(mytable) RETURNS int AS 'SELECT $1.f1'
LANGUAGE SQL;

In the following query, you do not need to cast the value because there is only one getf1() function and therefore no ambiguity:

SELECT getf1(ROW(1,2.5,'this is a test'));
getf1
-------
1
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
SELECT getf1(CAST(ROW(11,'this is a test',2.5) AS
myrowtype));
getf1
-------
11

You can use row constructors 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.