6.1.13. INTO

Used for

Passing SELECT output into variables

Available in

PSQL

In PSQL code (triggers, stored procedures and executable blocks), the results of a SELECT statement can be loaded row-by-row into local variables. It is often the only way to do anything with the returned values at all. The number, order and types of the variables must match the columns in the output row.

A “plain” SELECT statement can only be used in PSQL if it returns at most one row, i.e., if it is a singleton select. For multi-row selects, PSQL provides the FOR SELECT loop construct, discussed later in the PSQL chapter. PSQL also supports the DECLARE CURSOR statement, which binds a named cursor to a SELECT statement. The cursor can then be used to walk the result set.

Syntax

In PSQL the INTO clause is placed at the very end of the SELECT statement.

  1. SELECT [...] <column-list>
  2. FROM ...
  3. [...]
  4. [INTO <variable-list>]
  5. <variable-list> ::= [:]psqlvar [, [:]psqlvar ...]

The colon prefix before local variable names in PSQL is optional in the INTO clause.

Examples

Selecting some aggregated values and passing them into previously declared variables min_amt, avg_amt and max_amt:

  1. select min(amount), avg(cast(amount as float)), max(amount)
  2. from orders
  3. where artno = 372218
  4. into min_amt, avg_amt, max_amt;

The CAST serves to make the average a real number; otherwise, since amount is presumably an integer field, SQL rules would truncate it to the nearest lower integer.

A PSQL trigger that retrieves two values as a BLOB field (using the LIST() function) and assigns it INTO a third field:

  1. select list(name, ', ')
  2. from persons p
  3. where p.id in (new.father, new.mother)
  4. into new.parentnames;