]> granicus.if.org Git - postgresql/commitdiff
Add STRICT to PL/pgSQL SELECT INTO, so exceptions are thrown if more or
authorBruce Momjian <bruce@momjian.us>
Thu, 15 Jun 2006 18:02:22 +0000 (18:02 +0000)
committerBruce Momjian <bruce@momjian.us>
Thu, 15 Jun 2006 18:02:22 +0000 (18:02 +0000)
less than one row is returned by the SELECT, for Oracle PL/SQL
compatibility.

Improve SELECT INTO documentation.

Matt Miller

doc/src/sgml/plpgsql.sgml
src/pl/plpgsql/src/gram.y
src/pl/plpgsql/src/pl_exec.c
src/pl/plpgsql/src/plerrcodes.h
src/pl/plpgsql/src/plpgsql.h
src/pl/plpgsql/src/scan.l

index 60c7593362beb388cf1e7543607c6a5ae217b691..1f09b9e99c71154e886b30403638a8529a888a84 100644 (file)
@@ -1,4 +1,4 @@
-<!-- $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>
@@ -1081,7 +1081,7 @@ tax := subtotal * 0.06;
      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
@@ -1122,47 +1122,43 @@ SELECT INTO <replaceable>target</replaceable> <replaceable>select_expressions</r
     </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">
@@ -1424,8 +1420,8 @@ GET DIAGNOSTICS integer_var = ROW_COUNT;
          <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>
index 5343dfb1978af529315c9b9c601266719898010d..21a0bd6541e0e3c7c88201b192cb247944ec999e 100644 (file)
@@ -9,7 +9,7 @@
  *
  *
  * 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 $
  *
  *-------------------------------------------------------------------------
  */
@@ -157,6 +157,7 @@ static      void                     check_labels(const char *start_label,
 %token K_ELSE
 %token K_ELSIF
 %token K_END
+%token K_STRICT
 %token K_EXCEPTION
 %token K_EXECUTE
 %token K_EXIT
@@ -2001,6 +2002,7 @@ make_select_stmt(void)
        PLpgSQL_rec                     *rec = NULL;
        int                                     tok;
        bool                            have_into = false;
+       bool                            have_strict = false;
 
        plpgsql_dstring_init(&ds);
        plpgsql_dstring_append(&ds, "SELECT ");
@@ -2028,6 +2030,11 @@ make_select_stmt(void)
                                                 errmsg("INTO specified more than once")));
                        }
                        tok = yylex();
+                       if (tok == K_STRICT)
+                       {
+                               have_strict = true;
+                               tok = yylex();
+                       }
                        switch (tok)
                        {
                                case T_ROW:
@@ -2108,6 +2115,7 @@ make_select_stmt(void)
                select->rec              = rec;
                select->row              = row;
                select->query    = expr;
+               select->strict   = have_strict;
 
                return (PLpgSQL_stmt *)select;
        }
index 3ac48bbcecb55e24871fffc2bf228ef30cf65a43..893ad1dfdc8effcc86d2959622799aa4cb2d091d 100644 (file)
@@ -8,7 +8,7 @@
  *
  *
  * 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 $
  *
  *-------------------------------------------------------------------------
  */
@@ -1701,23 +1701,41 @@ exec_stmt_select(PLpgSQL_execstate *estate, PLpgSQL_stmt_select *stmt)
 
        /*
         * 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);
index be9f764a9aedadd408a4ce5cbdb80f362e788543..fedd4d0c7e7fb312a5cc731e41cf2456379863fb 100644 (file)
@@ -9,7 +9,7 @@
  *
  * 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
+},
+
+
index 16ffe7e93dfe0a4445f2f457ad4d18e2e812b93a..9f2e7b0a057860996cdef183ee072a4f886edb8a 100644 (file)
@@ -8,7 +8,7 @@
  *
  *
  * 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 $
  *
  *-------------------------------------------------------------------------
  */
@@ -432,6 +432,7 @@ typedef struct
 {                                                              /* SELECT ... INTO statement            */
        int                     cmd_type;
        int                     lineno;
+       bool            strict;
        PLpgSQL_rec *rec;
        PLpgSQL_row *row;
        PLpgSQL_expr *query;
index daafe96b87499f02783cf2ec5eb94a831f6e3631..1dca30a5666db303356e8d1692764d3877b497ee 100644 (file)
@@ -9,7 +9,7 @@
  *
  *
  * 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 $
  *
  *-------------------------------------------------------------------------
  */
@@ -129,6 +129,7 @@ else                        { return K_ELSE;                        }
 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;                        }