-<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.95 2006/06/12 16:45:30 momjian Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.96 2006/06/15 18:02:22 momjian Exp $ -->
<chapter id="plpgsql">
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
variable, or list of scalar variables. This is done by:
<synopsis>
-SELECT INTO <replaceable>target</replaceable> <replaceable>select_expressions</replaceable> FROM ...;
+SELECT INTO <optional>STRICT</optional> <replaceable>target</replaceable> <replaceable>select_expressions</replaceable> FROM ...;
</synopsis>
where <replaceable>target</replaceable> can be a record variable, a row
</para>
<para>
- If the query returns zero rows, null values are assigned to the
- target(s). If the query returns multiple rows, the first
- row is assigned to the target(s) and the rest are discarded.
- (Note that <quote>the first row</> is not well-defined unless you've
- used <literal>ORDER BY</>.)
- </para>
-
- <para>
- You can check the special <literal>FOUND</literal> variable (see
- <xref linkend="plpgsql-statements-diagnostics">) after a
- <command>SELECT INTO</command> statement to determine whether the
- assignment was successful, that is, at least one row was was returned by
- the query. For example:
+ If <literal>STRICT</literal> is not specified then
+ <replaceable>target</replaceable> will be set to the first row
+ returned by the query, or if the query returned no rows,
+ null values are assigned. (Note that <quote>the first row</> is not
+ well-defined unless you've used <literal>ORDER BY</>.)
+ You can check the special <literal>FOUND</literal> variable to
+ determine if any rows were found:
<programlisting>
-SELECT INTO myrec * FROM emp WHERE empname = myname;
+SELECT INTO STRICT myrec * FROM emp WHERE empname = myname;
IF NOT FOUND THEN
RAISE EXCEPTION 'employee % not found', myname;
END IF;
</programlisting>
- </para>
<para>
- To test for whether a record/row result is null, you can use the
- <literal>IS NULL</literal> conditional. There is, however, no
- way to tell whether any additional rows might have been
- discarded. Here is an example that handles the case where no
- rows have been returned:
-<programlisting>
-DECLARE
- users_rec RECORD;
-BEGIN
- SELECT INTO users_rec * FROM users WHERE user_id=3;
+ If the <literal>STRICT</literal> option is specified, a query must
+ return exactly one row or a run-time error will be thrown, either
+ <literal>NO_DATA_FOUND</> (no rows) or <literal>TOO_MANY_ROWS</>
+ (more than one row). You can must use exception blocks to determine
+ the number of rows generated by the query:
- IF users_rec.homepage IS NULL THEN
- -- user entered no homepage, return "http://"
- RETURN 'http://';
- END IF;
+<programlisting>
+BEGIN;
+ SELECT INTO STRICT myrec * FROM emp WHERE empname = myname;
+ EXCEPTION
+ WHEN NO_DATA_FOUND THEN
+ RAISE EXCEPTION 'employee % not found', myname;
+ WHEN TOO_MANY_ROWS THEN
+ RAISE EXCEPTION 'employee % not unique', myname;
END;
</programlisting>
+ Only <command>SELECT INTO STRICT</command> allows you to check if more
+ than one row was retrieved. <command>SELECT INTO STRICT</command>
+ matches Oracle's PL/SQL <command>SELECT INTO</command> behavior.
</para>
+
</sect2>
<sect2 id="plpgsql-statements-perform">
<itemizedlist>
<listitem>
<para>
- A <command>SELECT INTO</command> statement sets
- <literal>FOUND</literal> true if it returns a row, false if no
+ A <command>SELECT INTO</command> statement sets
+ <literal>FOUND</literal> true if a row is assigned, false if no
row is returned.
</para>
</listitem>
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.91 2006/06/12 16:45:30 momjian Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.92 2006/06/15 18:02:22 momjian Exp $
*
*-------------------------------------------------------------------------
*/
%token K_ELSE
%token K_ELSIF
%token K_END
+%token K_STRICT
%token K_EXCEPTION
%token K_EXECUTE
%token K_EXIT
PLpgSQL_rec *rec = NULL;
int tok;
bool have_into = false;
+ bool have_strict = false;
plpgsql_dstring_init(&ds);
plpgsql_dstring_append(&ds, "SELECT ");
errmsg("INTO specified more than once")));
}
tok = yylex();
+ if (tok == K_STRICT)
+ {
+ have_strict = true;
+ tok = yylex();
+ }
switch (tok)
{
case T_ROW:
select->rec = rec;
select->row = row;
select->query = expr;
+ select->strict = have_strict;
return (PLpgSQL_stmt *)select;
}
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.170 2006/06/12 16:45:30 momjian Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.171 2006/06/15 18:02:22 momjian Exp $
*
*-------------------------------------------------------------------------
*/
/*
* Run the query
+ * Retrieving two rows can be slower than a single row, e.g.
+ * a sequential scan where the scan has to be completed to
+ * check for a second row. For this reason, we only do the
+ * second-line check for STRICT.
*/
- exec_run_select(estate, stmt->query, 1, NULL);
+ exec_run_select(estate, stmt->query, stmt->strict ? 2 : 1, NULL);
tuptab = estate->eval_tuptable;
n = estate->eval_processed;
/*
- * If the query didn't return any rows, set the target to NULL and return.
+ * If SELECT ... INTO specified STRICT, and the query didn't
+ * find exactly one row, throw an error. If STRICT was not specified,
+ * then allow the query to find any number of rows.
*/
if (n == 0)
{
- exec_move_row(estate, rec, row, NULL, tuptab->tupdesc);
- exec_eval_cleanup(estate);
- return PLPGSQL_RC_OK;
+ if (!stmt->strict)
+ {
+ /* null the target */
+ exec_move_row(estate, rec, row, NULL, tuptab->tupdesc);
+ exec_eval_cleanup(estate);
+ return PLPGSQL_RC_OK;
+ }
+ else
+ ereport(ERROR,
+ (errcode(ERRCODE_NO_DATA),
+ errmsg("query returned no rows")));
}
+ else if (n > 1 && stmt->strict)
+ ereport(ERROR,
+ (errcode(ERRCODE_CARDINALITY_VIOLATION),
+ errmsg("query more than one row")));
/*
- * Put the result into the target and set found to true
+ * Put the first result into the target and set found to true
*/
exec_move_row(estate, rec, row, tuptab->vals[0], tuptab->tupdesc);
exec_set_found(estate, true);
*
* Copyright (c) 2003-2006, PostgreSQL Global Development Group
*
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/plerrcodes.h,v 1.7 2006/03/05 15:59:10 momjian Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/plerrcodes.h,v 1.8 2006/06/15 18:02:22 momjian Exp $
*
*-------------------------------------------------------------------------
*/
{
"index_corrupted", ERRCODE_INDEX_CORRUPTED
},
+
+{
+ "no_data_found", ERRCODE_NO_DATA
+},
+
+{
+ "too_many_rows", ERRCODE_CARDINALITY_VIOLATION
+},
+
+
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.75 2006/06/12 16:45:30 momjian Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.76 2006/06/15 18:02:22 momjian Exp $
*
*-------------------------------------------------------------------------
*/
{ /* SELECT ... INTO statement */
int cmd_type;
int lineno;
+ bool strict;
PLpgSQL_rec *rec;
PLpgSQL_row *row;
PLpgSQL_expr *query;
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.50 2006/06/12 16:45:30 momjian Exp $
+ * $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.51 2006/06/15 18:02:22 momjian Exp $
*
*-------------------------------------------------------------------------
*/
elseif { return K_ELSIF; }
elsif { return K_ELSIF; }
end { return K_END; }
+strict { return K_STRICT; }
exception { return K_EXCEPTION; }
execute { return K_EXECUTE; }
exit { return K_EXIT; }