mirror of
https://github.com/postgres/postgres.git
synced 2025-07-26 01:22:12 +03:00
Support SQL/PSM-compatible CASE statement in plpgsql.
Pavel Stehule
This commit is contained in:
@ -1,4 +1,4 @@
|
|||||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/errcodes.sgml,v 1.23 2008/01/15 01:36:53 tgl Exp $ -->
|
<!-- $PostgreSQL: pgsql/doc/src/sgml/errcodes.sgml,v 1.24 2008/05/15 22:39:48 tgl Exp $ -->
|
||||||
|
|
||||||
<appendix id="errcodes-appendix">
|
<appendix id="errcodes-appendix">
|
||||||
<title><productname>PostgreSQL</productname> Error Codes</title>
|
<title><productname>PostgreSQL</productname> Error Codes</title>
|
||||||
@ -62,14 +62,14 @@
|
|||||||
|
|
||||||
<tgroup cols="3">
|
<tgroup cols="3">
|
||||||
<colspec colnum="1" colname="errorcode">
|
<colspec colnum="1" colname="errorcode">
|
||||||
<colspec colnum="3" colname="constant">
|
<colspec colnum="3" colname="condname">
|
||||||
<spanspec namest="errorcode" nameend="constant" spanname="span13">
|
<spanspec namest="errorcode" nameend="condname" spanname="span13">
|
||||||
|
|
||||||
<thead>
|
<thead>
|
||||||
<row>
|
<row>
|
||||||
<entry>Error Code</entry>
|
<entry>Error Code</entry>
|
||||||
<entry>Meaning</entry>
|
<entry>Meaning</entry>
|
||||||
<entry>Constant</entry>
|
<entry>Condition Name</entry>
|
||||||
</row>
|
</row>
|
||||||
</thead>
|
</thead>
|
||||||
|
|
||||||
@ -292,6 +292,17 @@
|
|||||||
</row>
|
</row>
|
||||||
|
|
||||||
|
|
||||||
|
<row>
|
||||||
|
<entry spanname="span13"><emphasis role="bold">Class 20 — Case Not Found</></entry>
|
||||||
|
</row>
|
||||||
|
|
||||||
|
<row>
|
||||||
|
<entry><literal>20000</literal></entry>
|
||||||
|
<entry>CASE NOT FOUND</entry>
|
||||||
|
<entry>case_not_found</entry>
|
||||||
|
</row>
|
||||||
|
|
||||||
|
|
||||||
<row>
|
<row>
|
||||||
<entry spanname="span13"><emphasis role="bold">Class 21 — Cardinality Violation</></entry>
|
<entry spanname="span13"><emphasis role="bold">Class 21 — Cardinality Violation</></entry>
|
||||||
</row>
|
</row>
|
||||||
|
@ -1,4 +1,4 @@
|
|||||||
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.129 2008/05/13 22:10:29 tgl Exp $ -->
|
<!-- $PostgreSQL: pgsql/doc/src/sgml/plpgsql.sgml,v 1.130 2008/05/15 22:39:49 tgl Exp $ -->
|
||||||
|
|
||||||
<chapter id="plpgsql">
|
<chapter id="plpgsql">
|
||||||
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
|
<title><application>PL/pgSQL</application> - <acronym>SQL</acronym> Procedural Language</title>
|
||||||
@ -1581,9 +1581,9 @@ SELECT * FROM getallfoo();
|
|||||||
<title>Conditionals</title>
|
<title>Conditionals</title>
|
||||||
|
|
||||||
<para>
|
<para>
|
||||||
<literal>IF</> statements let you execute commands based on
|
<command>IF</> and <command>CASE</> statements let you execute
|
||||||
certain conditions. <application>PL/pgSQL</> has five forms of
|
alternative commands based on certain conditions.
|
||||||
<literal>IF</>:
|
<application>PL/pgSQL</> has five forms of <command>IF</>:
|
||||||
<itemizedlist>
|
<itemizedlist>
|
||||||
<listitem>
|
<listitem>
|
||||||
<para><literal>IF ... THEN</></>
|
<para><literal>IF ... THEN</></>
|
||||||
@ -1601,6 +1601,22 @@ SELECT * FROM getallfoo();
|
|||||||
<para><literal>IF ... THEN ... ELSEIF ... THEN ... ELSE</></>
|
<para><literal>IF ... THEN ... ELSEIF ... THEN ... ELSE</></>
|
||||||
</listitem>
|
</listitem>
|
||||||
</itemizedlist>
|
</itemizedlist>
|
||||||
|
|
||||||
|
and four forms of <command>CASE</>:
|
||||||
|
<itemizedlist>
|
||||||
|
<listitem>
|
||||||
|
<para><literal>CASE ... WHEN ... THEN ... END CASE</></>
|
||||||
|
</listitem>
|
||||||
|
<listitem>
|
||||||
|
<para><literal>CASE ... WHEN ... THEN ... ELSE ... END CASE</></>
|
||||||
|
</listitem>
|
||||||
|
<listitem>
|
||||||
|
<para><literal>CASE WHEN ... THEN ... END CASE</></>
|
||||||
|
</listitem>
|
||||||
|
<listitem>
|
||||||
|
<para><literal>CASE WHEN ... THEN ... ELSE ... END CASE</></>
|
||||||
|
</listitem>
|
||||||
|
</itemizedlist>
|
||||||
</para>
|
</para>
|
||||||
|
|
||||||
<sect3>
|
<sect3>
|
||||||
@ -1751,6 +1767,93 @@ END IF;
|
|||||||
<literal>ELSEIF</> is an alias for <literal>ELSIF</>.
|
<literal>ELSEIF</> is an alias for <literal>ELSIF</>.
|
||||||
</para>
|
</para>
|
||||||
</sect3>
|
</sect3>
|
||||||
|
|
||||||
|
<sect3>
|
||||||
|
<title>Simple <literal>CASE</></title>
|
||||||
|
|
||||||
|
<synopsis>
|
||||||
|
CASE <replaceable>search-expression</replaceable>
|
||||||
|
WHEN <replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> <optional> ... </optional></optional> THEN
|
||||||
|
<replaceable>statements</replaceable>
|
||||||
|
<optional> WHEN <replaceable>expression</replaceable> <optional>, <replaceable>expression</replaceable> <optional> ... </optional></optional> THEN
|
||||||
|
<replaceable>statements</replaceable>
|
||||||
|
... </optional>
|
||||||
|
<optional> ELSE
|
||||||
|
<replaceable>statements</replaceable> </optional>
|
||||||
|
END CASE;
|
||||||
|
</synopsis>
|
||||||
|
|
||||||
|
<para>
|
||||||
|
The simple form of <command>CASE</> provides conditional execution
|
||||||
|
based on equality of operands. The <replaceable>search-expression</>
|
||||||
|
is evaluated (once) and successively compared to each
|
||||||
|
<replaceable>expression</> in the <literal>WHEN</> clauses.
|
||||||
|
If a match is found, then the corresponding
|
||||||
|
<replaceable>statements</replaceable> are executed, and then control
|
||||||
|
passes to the next statement after <literal>END CASE</>. (Subsequent
|
||||||
|
<literal>WHEN</> expressions are not evaluated.) If no match is
|
||||||
|
found, the <literal>ELSE</> <replaceable>statements</replaceable> are
|
||||||
|
executed; but if <literal>ELSE</> is not present, then a
|
||||||
|
<literal>CASE_NOT_FOUND</literal> exception is raised.
|
||||||
|
</para>
|
||||||
|
|
||||||
|
<para>
|
||||||
|
Here is a simple example:
|
||||||
|
|
||||||
|
<programlisting>
|
||||||
|
CASE x
|
||||||
|
WHEN 1, 2 THEN
|
||||||
|
msg := 'one or two';
|
||||||
|
ELSE
|
||||||
|
msg := 'other value than one or two';
|
||||||
|
END CASE;
|
||||||
|
</programlisting>
|
||||||
|
</para>
|
||||||
|
</sect3>
|
||||||
|
|
||||||
|
<sect3>
|
||||||
|
<title>Searched <literal>CASE</></title>
|
||||||
|
|
||||||
|
<synopsis>
|
||||||
|
CASE
|
||||||
|
WHEN <replaceable>boolean-expression</replaceable> THEN
|
||||||
|
<replaceable>statements</replaceable>
|
||||||
|
<optional> WHEN <replaceable>boolean-expression</replaceable> THEN
|
||||||
|
<replaceable>statements</replaceable>
|
||||||
|
... </optional>
|
||||||
|
<optional> ELSE
|
||||||
|
<replaceable>statements</replaceable> </optional>
|
||||||
|
END CASE;
|
||||||
|
</synopsis>
|
||||||
|
|
||||||
|
<para>
|
||||||
|
The searched form of <command>CASE</> provides conditional execution
|
||||||
|
based on truth of boolean expressions. Each <literal>WHEN</> clause's
|
||||||
|
<replaceable>boolean-expression</replaceable> is evaluated in turn,
|
||||||
|
until one is found that yields <literal>true</>. Then the
|
||||||
|
corresponding <replaceable>statements</replaceable> are executed, and
|
||||||
|
then control passes to the next statement after <literal>END CASE</>.
|
||||||
|
(Subsequent <literal>WHEN</> expressions are not evaluated.)
|
||||||
|
If no true result is found, the <literal>ELSE</>
|
||||||
|
<replaceable>statements</replaceable> are executed;
|
||||||
|
but if <literal>ELSE</> is not present, then a
|
||||||
|
<literal>CASE_NOT_FOUND</literal> exception is raised.
|
||||||
|
</para>
|
||||||
|
|
||||||
|
<para>
|
||||||
|
Here is an example:
|
||||||
|
|
||||||
|
<programlisting>
|
||||||
|
CASE
|
||||||
|
WHEN x BETWEEN 0 AND 10 THEN
|
||||||
|
msg := 'value is between zero and ten';
|
||||||
|
WHEN x BETWEEN 11 AND 20 THEN
|
||||||
|
msg := 'value is between eleven and twenty';
|
||||||
|
END CASE;
|
||||||
|
</programlisting>
|
||||||
|
</para>
|
||||||
|
|
||||||
|
</sect3>
|
||||||
</sect2>
|
</sect2>
|
||||||
|
|
||||||
<sect2 id="plpgsql-control-structures-loops">
|
<sect2 id="plpgsql-control-structures-loops">
|
||||||
|
@ -11,7 +11,7 @@
|
|||||||
*
|
*
|
||||||
* Copyright (c) 2003-2008, PostgreSQL Global Development Group
|
* Copyright (c) 2003-2008, PostgreSQL Global Development Group
|
||||||
*
|
*
|
||||||
* $PostgreSQL: pgsql/src/include/utils/errcodes.h,v 1.24 2008/01/01 19:45:59 momjian Exp $
|
* $PostgreSQL: pgsql/src/include/utils/errcodes.h,v 1.25 2008/05/15 22:39:49 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -101,6 +101,9 @@
|
|||||||
/* Class 0P - Invalid Role Specification */
|
/* Class 0P - Invalid Role Specification */
|
||||||
#define ERRCODE_INVALID_ROLE_SPECIFICATION MAKE_SQLSTATE('0','P', '0','0','0')
|
#define ERRCODE_INVALID_ROLE_SPECIFICATION MAKE_SQLSTATE('0','P', '0','0','0')
|
||||||
|
|
||||||
|
/* Class 20 - Case Not Found */
|
||||||
|
#define ERRCODE_CASE_NOT_FOUND MAKE_SQLSTATE('2','0', '0','0','0')
|
||||||
|
|
||||||
/* Class 21 - Cardinality Violation */
|
/* Class 21 - Cardinality Violation */
|
||||||
/* (this means something returned the wrong number of rows) */
|
/* (this means something returned the wrong number of rows) */
|
||||||
#define ERRCODE_CARDINALITY_VIOLATION MAKE_SQLSTATE('2','1', '0','0','0')
|
#define ERRCODE_CARDINALITY_VIOLATION MAKE_SQLSTATE('2','1', '0','0','0')
|
||||||
|
@ -9,7 +9,7 @@
|
|||||||
*
|
*
|
||||||
*
|
*
|
||||||
* IDENTIFICATION
|
* IDENTIFICATION
|
||||||
* $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.112 2008/05/13 22:10:29 tgl Exp $
|
* $PostgreSQL: pgsql/src/pl/plpgsql/src/gram.y,v 1.113 2008/05/15 22:39:49 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -37,6 +37,8 @@ static PLpgSQL_stmt_fetch *read_fetch_direction(void);
|
|||||||
static PLpgSQL_stmt *make_return_stmt(int lineno);
|
static PLpgSQL_stmt *make_return_stmt(int lineno);
|
||||||
static PLpgSQL_stmt *make_return_next_stmt(int lineno);
|
static PLpgSQL_stmt *make_return_next_stmt(int lineno);
|
||||||
static PLpgSQL_stmt *make_return_query_stmt(int lineno);
|
static PLpgSQL_stmt *make_return_query_stmt(int lineno);
|
||||||
|
static PLpgSQL_stmt *make_case(int lineno, PLpgSQL_expr *t_expr,
|
||||||
|
List *case_when_list, List *else_stmts);
|
||||||
static void check_assignable(PLpgSQL_datum *datum);
|
static void check_assignable(PLpgSQL_datum *datum);
|
||||||
static void read_into_target(PLpgSQL_rec **rec, PLpgSQL_row **row,
|
static void read_into_target(PLpgSQL_rec **rec, PLpgSQL_row **row,
|
||||||
bool *strict);
|
bool *strict);
|
||||||
@ -102,6 +104,7 @@ static List *read_raise_options(void);
|
|||||||
PLpgSQL_nsitem *nsitem;
|
PLpgSQL_nsitem *nsitem;
|
||||||
PLpgSQL_diag_item *diagitem;
|
PLpgSQL_diag_item *diagitem;
|
||||||
PLpgSQL_stmt_fetch *fetch;
|
PLpgSQL_stmt_fetch *fetch;
|
||||||
|
PLpgSQL_case_when *casewhen;
|
||||||
}
|
}
|
||||||
|
|
||||||
%type <declhdr> decl_sect
|
%type <declhdr> decl_sect
|
||||||
@ -116,7 +119,7 @@ static List *read_raise_options(void);
|
|||||||
%type <str> decl_stmts decl_stmt
|
%type <str> decl_stmts decl_stmt
|
||||||
|
|
||||||
%type <expr> expr_until_semi expr_until_rightbracket
|
%type <expr> expr_until_semi expr_until_rightbracket
|
||||||
%type <expr> expr_until_then expr_until_loop
|
%type <expr> expr_until_then expr_until_loop opt_expr_until_when
|
||||||
%type <expr> opt_exitcond
|
%type <expr> opt_exitcond
|
||||||
|
|
||||||
%type <ival> assign_var
|
%type <ival> assign_var
|
||||||
@ -135,12 +138,16 @@ static List *read_raise_options(void);
|
|||||||
%type <stmt> stmt_return stmt_raise stmt_execsql stmt_execsql_insert
|
%type <stmt> stmt_return stmt_raise stmt_execsql stmt_execsql_insert
|
||||||
%type <stmt> stmt_dynexecute stmt_for stmt_perform stmt_getdiag
|
%type <stmt> stmt_dynexecute stmt_for stmt_perform stmt_getdiag
|
||||||
%type <stmt> stmt_open stmt_fetch stmt_move stmt_close stmt_null
|
%type <stmt> stmt_open stmt_fetch stmt_move stmt_close stmt_null
|
||||||
|
%type <stmt> stmt_case
|
||||||
|
|
||||||
%type <list> proc_exceptions
|
%type <list> proc_exceptions
|
||||||
%type <exception_block> exception_sect
|
%type <exception_block> exception_sect
|
||||||
%type <exception> proc_exception
|
%type <exception> proc_exception
|
||||||
%type <condition> proc_conditions proc_condition
|
%type <condition> proc_conditions proc_condition
|
||||||
|
|
||||||
|
%type <casewhen> case_when
|
||||||
|
%type <list> case_when_list opt_case_else
|
||||||
|
|
||||||
%type <list> getdiag_list
|
%type <list> getdiag_list
|
||||||
%type <diagitem> getdiag_list_item
|
%type <diagitem> getdiag_list_item
|
||||||
%type <ival> getdiag_kind getdiag_target
|
%type <ival> getdiag_kind getdiag_target
|
||||||
@ -157,6 +164,7 @@ static List *read_raise_options(void);
|
|||||||
%token K_ASSIGN
|
%token K_ASSIGN
|
||||||
%token K_BEGIN
|
%token K_BEGIN
|
||||||
%token K_BY
|
%token K_BY
|
||||||
|
%token K_CASE
|
||||||
%token K_CLOSE
|
%token K_CLOSE
|
||||||
%token K_CONSTANT
|
%token K_CONSTANT
|
||||||
%token K_CONTINUE
|
%token K_CONTINUE
|
||||||
@ -581,9 +589,7 @@ decl_defkey : K_ASSIGN
|
|||||||
;
|
;
|
||||||
|
|
||||||
proc_sect :
|
proc_sect :
|
||||||
{
|
{ $$ = NIL; }
|
||||||
$$ = NIL;
|
|
||||||
}
|
|
||||||
| proc_stmts
|
| proc_stmts
|
||||||
{ $$ = $1; }
|
{ $$ = $1; }
|
||||||
;
|
;
|
||||||
@ -598,7 +604,7 @@ proc_stmts : proc_stmts proc_stmt
|
|||||||
| proc_stmt
|
| proc_stmt
|
||||||
{
|
{
|
||||||
if ($1 == NULL)
|
if ($1 == NULL)
|
||||||
$$ = NULL;
|
$$ = NIL;
|
||||||
else
|
else
|
||||||
$$ = list_make1($1);
|
$$ = list_make1($1);
|
||||||
}
|
}
|
||||||
@ -610,6 +616,8 @@ proc_stmt : pl_block ';'
|
|||||||
{ $$ = $1; }
|
{ $$ = $1; }
|
||||||
| stmt_if
|
| stmt_if
|
||||||
{ $$ = $1; }
|
{ $$ = $1; }
|
||||||
|
| stmt_case
|
||||||
|
{ $$ = $1; }
|
||||||
| stmt_loop
|
| stmt_loop
|
||||||
{ $$ = $1; }
|
{ $$ = $1; }
|
||||||
| stmt_while
|
| stmt_while
|
||||||
@ -808,6 +816,67 @@ stmt_else :
|
|||||||
}
|
}
|
||||||
;
|
;
|
||||||
|
|
||||||
|
stmt_case : K_CASE lno opt_expr_until_when case_when_list opt_case_else K_END K_CASE ';'
|
||||||
|
{
|
||||||
|
$$ = make_case($2, $3, $4, $5);
|
||||||
|
}
|
||||||
|
;
|
||||||
|
|
||||||
|
opt_expr_until_when :
|
||||||
|
{
|
||||||
|
PLpgSQL_expr *expr = NULL;
|
||||||
|
int tok = yylex();
|
||||||
|
|
||||||
|
if (tok != K_WHEN)
|
||||||
|
{
|
||||||
|
plpgsql_push_back_token(tok);
|
||||||
|
expr = plpgsql_read_expression(K_WHEN, "WHEN");
|
||||||
|
}
|
||||||
|
plpgsql_push_back_token(K_WHEN);
|
||||||
|
$$ = expr;
|
||||||
|
}
|
||||||
|
;
|
||||||
|
|
||||||
|
case_when_list : case_when_list case_when
|
||||||
|
{
|
||||||
|
$$ = lappend($1, $2);
|
||||||
|
}
|
||||||
|
| case_when
|
||||||
|
{
|
||||||
|
$$ = list_make1($1);
|
||||||
|
}
|
||||||
|
;
|
||||||
|
|
||||||
|
case_when : K_WHEN lno expr_until_then proc_sect
|
||||||
|
{
|
||||||
|
PLpgSQL_case_when *new = palloc(sizeof(PLpgSQL_case_when));
|
||||||
|
|
||||||
|
new->lineno = $2;
|
||||||
|
new->expr = $3;
|
||||||
|
new->stmts = $4;
|
||||||
|
$$ = new;
|
||||||
|
}
|
||||||
|
;
|
||||||
|
|
||||||
|
opt_case_else :
|
||||||
|
{
|
||||||
|
$$ = NIL;
|
||||||
|
}
|
||||||
|
| K_ELSE proc_sect
|
||||||
|
{
|
||||||
|
/*
|
||||||
|
* proc_sect could return an empty list, but we
|
||||||
|
* must distinguish that from not having ELSE at all.
|
||||||
|
* Simplest fix is to return a list with one NULL
|
||||||
|
* pointer, which make_case() must take care of.
|
||||||
|
*/
|
||||||
|
if ($2 != NIL)
|
||||||
|
$$ = $2;
|
||||||
|
else
|
||||||
|
$$ = list_make1(NULL);
|
||||||
|
}
|
||||||
|
;
|
||||||
|
|
||||||
stmt_loop : opt_block_label K_LOOP lno loop_body
|
stmt_loop : opt_block_label K_LOOP lno loop_body
|
||||||
{
|
{
|
||||||
PLpgSQL_stmt_loop *new;
|
PLpgSQL_stmt_loop *new;
|
||||||
@ -2804,6 +2873,103 @@ read_raise_options(void)
|
|||||||
return result;
|
return result;
|
||||||
}
|
}
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Fix up CASE statement
|
||||||
|
*/
|
||||||
|
static PLpgSQL_stmt *
|
||||||
|
make_case(int lineno, PLpgSQL_expr *t_expr,
|
||||||
|
List *case_when_list, List *else_stmts)
|
||||||
|
{
|
||||||
|
PLpgSQL_stmt_case *new;
|
||||||
|
|
||||||
|
new = palloc(sizeof(PLpgSQL_stmt_case));
|
||||||
|
new->cmd_type = PLPGSQL_STMT_CASE;
|
||||||
|
new->lineno = lineno;
|
||||||
|
new->t_expr = t_expr;
|
||||||
|
new->t_varno = 0;
|
||||||
|
new->case_when_list = case_when_list;
|
||||||
|
new->have_else = (else_stmts != NIL);
|
||||||
|
/* Get rid of list-with-NULL hack */
|
||||||
|
if (list_length(else_stmts) == 1 && linitial(else_stmts) == NULL)
|
||||||
|
new->else_stmts = NIL;
|
||||||
|
else
|
||||||
|
new->else_stmts = else_stmts;
|
||||||
|
|
||||||
|
/*
|
||||||
|
* When test expression is present, we create a var for it and then
|
||||||
|
* convert all the WHEN expressions to "VAR IN (original_expression)".
|
||||||
|
* This is a bit klugy, but okay since we haven't yet done more than
|
||||||
|
* read the expressions as text. (Note that previous parsing won't
|
||||||
|
* have complained if the WHEN ... THEN expression contained multiple
|
||||||
|
* comma-separated values.)
|
||||||
|
*/
|
||||||
|
if (t_expr)
|
||||||
|
{
|
||||||
|
ListCell *l;
|
||||||
|
PLpgSQL_var *t_var;
|
||||||
|
int t_varno;
|
||||||
|
|
||||||
|
/*
|
||||||
|
* We don't yet know the result datatype of t_expr. Build the
|
||||||
|
* variable as if it were INT4; we'll fix this at runtime if needed.
|
||||||
|
*/
|
||||||
|
t_var = (PLpgSQL_var *)
|
||||||
|
plpgsql_build_variable("*case*", lineno,
|
||||||
|
plpgsql_build_datatype(INT4OID, -1),
|
||||||
|
false);
|
||||||
|
t_varno = t_var->varno;
|
||||||
|
new->t_varno = t_varno;
|
||||||
|
|
||||||
|
foreach(l, case_when_list)
|
||||||
|
{
|
||||||
|
PLpgSQL_case_when *cwt = (PLpgSQL_case_when *) lfirst(l);
|
||||||
|
PLpgSQL_expr *expr = cwt->expr;
|
||||||
|
int nparams = expr->nparams;
|
||||||
|
PLpgSQL_expr *new_expr;
|
||||||
|
PLpgSQL_dstring ds;
|
||||||
|
char buff[32];
|
||||||
|
|
||||||
|
/* Must add the CASE variable as an extra param to expression */
|
||||||
|
if (nparams >= MAX_EXPR_PARAMS)
|
||||||
|
{
|
||||||
|
plpgsql_error_lineno = cwt->lineno;
|
||||||
|
ereport(ERROR,
|
||||||
|
(errcode(ERRCODE_PROGRAM_LIMIT_EXCEEDED),
|
||||||
|
errmsg("too many variables specified in SQL statement")));
|
||||||
|
}
|
||||||
|
|
||||||
|
new_expr = palloc(sizeof(PLpgSQL_expr) + sizeof(int) * (nparams + 1) - sizeof(int));
|
||||||
|
memcpy(new_expr, expr,
|
||||||
|
sizeof(PLpgSQL_expr) + sizeof(int) * nparams - sizeof(int));
|
||||||
|
new_expr->nparams = nparams + 1;
|
||||||
|
new_expr->params[nparams] = t_varno;
|
||||||
|
|
||||||
|
/* And do the string hacking */
|
||||||
|
plpgsql_dstring_init(&ds);
|
||||||
|
|
||||||
|
plpgsql_dstring_append(&ds, "SELECT $");
|
||||||
|
snprintf(buff, sizeof(buff), "%d", nparams + 1);
|
||||||
|
plpgsql_dstring_append(&ds, buff);
|
||||||
|
plpgsql_dstring_append(&ds, " IN (");
|
||||||
|
|
||||||
|
/* copy expression query without SELECT keyword */
|
||||||
|
Assert(strncmp(expr->query, "SELECT ", 7) == 0);
|
||||||
|
plpgsql_dstring_append(&ds, expr->query + 7);
|
||||||
|
plpgsql_dstring_append_char(&ds, ')');
|
||||||
|
|
||||||
|
new_expr->query = pstrdup(plpgsql_dstring_get(&ds));
|
||||||
|
|
||||||
|
plpgsql_dstring_free(&ds);
|
||||||
|
pfree(expr->query);
|
||||||
|
pfree(expr);
|
||||||
|
|
||||||
|
cwt->expr = new_expr;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
return (PLpgSQL_stmt *) new;
|
||||||
|
}
|
||||||
|
|
||||||
|
|
||||||
/* Needed to avoid conflict between different prefix settings: */
|
/* Needed to avoid conflict between different prefix settings: */
|
||||||
#undef yylex
|
#undef yylex
|
||||||
|
@ -8,7 +8,7 @@
|
|||||||
*
|
*
|
||||||
*
|
*
|
||||||
* IDENTIFICATION
|
* IDENTIFICATION
|
||||||
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.214 2008/05/13 22:10:30 tgl Exp $
|
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_exec.c,v 1.215 2008/05/15 22:39:49 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -94,6 +94,8 @@ static int exec_stmt_getdiag(PLpgSQL_execstate *estate,
|
|||||||
PLpgSQL_stmt_getdiag *stmt);
|
PLpgSQL_stmt_getdiag *stmt);
|
||||||
static int exec_stmt_if(PLpgSQL_execstate *estate,
|
static int exec_stmt_if(PLpgSQL_execstate *estate,
|
||||||
PLpgSQL_stmt_if *stmt);
|
PLpgSQL_stmt_if *stmt);
|
||||||
|
static int exec_stmt_case(PLpgSQL_execstate *estate,
|
||||||
|
PLpgSQL_stmt_case *stmt);
|
||||||
static int exec_stmt_loop(PLpgSQL_execstate *estate,
|
static int exec_stmt_loop(PLpgSQL_execstate *estate,
|
||||||
PLpgSQL_stmt_loop *stmt);
|
PLpgSQL_stmt_loop *stmt);
|
||||||
static int exec_stmt_while(PLpgSQL_execstate *estate,
|
static int exec_stmt_while(PLpgSQL_execstate *estate,
|
||||||
@ -1229,7 +1231,7 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt)
|
|||||||
|
|
||||||
CHECK_FOR_INTERRUPTS();
|
CHECK_FOR_INTERRUPTS();
|
||||||
|
|
||||||
switch (stmt->cmd_type)
|
switch ((enum PLpgSQL_stmt_types) stmt->cmd_type)
|
||||||
{
|
{
|
||||||
case PLPGSQL_STMT_BLOCK:
|
case PLPGSQL_STMT_BLOCK:
|
||||||
rc = exec_stmt_block(estate, (PLpgSQL_stmt_block *) stmt);
|
rc = exec_stmt_block(estate, (PLpgSQL_stmt_block *) stmt);
|
||||||
@ -1251,6 +1253,10 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt)
|
|||||||
rc = exec_stmt_if(estate, (PLpgSQL_stmt_if *) stmt);
|
rc = exec_stmt_if(estate, (PLpgSQL_stmt_if *) stmt);
|
||||||
break;
|
break;
|
||||||
|
|
||||||
|
case PLPGSQL_STMT_CASE:
|
||||||
|
rc = exec_stmt_case(estate, (PLpgSQL_stmt_case *) stmt);
|
||||||
|
break;
|
||||||
|
|
||||||
case PLPGSQL_STMT_LOOP:
|
case PLPGSQL_STMT_LOOP:
|
||||||
rc = exec_stmt_loop(estate, (PLpgSQL_stmt_loop *) stmt);
|
rc = exec_stmt_loop(estate, (PLpgSQL_stmt_loop *) stmt);
|
||||||
break;
|
break;
|
||||||
@ -1442,6 +1448,91 @@ exec_stmt_if(PLpgSQL_execstate *estate, PLpgSQL_stmt_if *stmt)
|
|||||||
}
|
}
|
||||||
|
|
||||||
|
|
||||||
|
/*-----------
|
||||||
|
* exec_stmt_case
|
||||||
|
*-----------
|
||||||
|
*/
|
||||||
|
static int
|
||||||
|
exec_stmt_case(PLpgSQL_execstate *estate, PLpgSQL_stmt_case *stmt)
|
||||||
|
{
|
||||||
|
PLpgSQL_var *t_var = NULL;
|
||||||
|
bool isnull;
|
||||||
|
ListCell *l;
|
||||||
|
|
||||||
|
if (stmt->t_expr != NULL)
|
||||||
|
{
|
||||||
|
/* simple case */
|
||||||
|
Datum t_val;
|
||||||
|
Oid t_oid;
|
||||||
|
|
||||||
|
t_val = exec_eval_expr(estate, stmt->t_expr, &isnull, &t_oid);
|
||||||
|
|
||||||
|
t_var = (PLpgSQL_var *) estate->datums[stmt->t_varno];
|
||||||
|
|
||||||
|
/*
|
||||||
|
* When expected datatype is different from real, change it.
|
||||||
|
* Note that what we're modifying here is an execution copy
|
||||||
|
* of the datum, so this doesn't affect the originally stored
|
||||||
|
* function parse tree.
|
||||||
|
*/
|
||||||
|
if (t_var->datatype->typoid != t_oid)
|
||||||
|
t_var->datatype = plpgsql_build_datatype(t_oid, -1);
|
||||||
|
|
||||||
|
/* now we can assign to the variable */
|
||||||
|
exec_assign_value(estate,
|
||||||
|
(PLpgSQL_datum *) t_var,
|
||||||
|
t_val,
|
||||||
|
t_oid,
|
||||||
|
&isnull);
|
||||||
|
|
||||||
|
exec_eval_cleanup(estate);
|
||||||
|
}
|
||||||
|
|
||||||
|
/* Now search for a successful WHEN clause */
|
||||||
|
foreach(l, stmt->case_when_list)
|
||||||
|
{
|
||||||
|
PLpgSQL_case_when *cwt = (PLpgSQL_case_when *) lfirst(l);
|
||||||
|
bool value;
|
||||||
|
|
||||||
|
value = exec_eval_boolean(estate, cwt->expr, &isnull);
|
||||||
|
exec_eval_cleanup(estate);
|
||||||
|
if (!isnull && value)
|
||||||
|
{
|
||||||
|
/* Found it */
|
||||||
|
|
||||||
|
/* We can now discard any value we had for the temp variable */
|
||||||
|
if (t_var != NULL)
|
||||||
|
{
|
||||||
|
free_var(t_var);
|
||||||
|
t_var->value = (Datum) 0;
|
||||||
|
t_var->isnull = true;
|
||||||
|
}
|
||||||
|
|
||||||
|
/* Evaluate the statement(s), and we're done */
|
||||||
|
return exec_stmts(estate, cwt->stmts);
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
/* We can now discard any value we had for the temp variable */
|
||||||
|
if (t_var != NULL)
|
||||||
|
{
|
||||||
|
free_var(t_var);
|
||||||
|
t_var->value = (Datum) 0;
|
||||||
|
t_var->isnull = true;
|
||||||
|
}
|
||||||
|
|
||||||
|
/* SQL2003 mandates this error if there was no ELSE clause */
|
||||||
|
if (!stmt->have_else)
|
||||||
|
ereport(ERROR,
|
||||||
|
(errcode(ERRCODE_CASE_NOT_FOUND),
|
||||||
|
errmsg("case not found"),
|
||||||
|
errhint("CASE statement is missing ELSE part.")));
|
||||||
|
|
||||||
|
/* Evaluate the ELSE statements, and we're done */
|
||||||
|
return exec_stmts(estate, stmt->else_stmts);
|
||||||
|
}
|
||||||
|
|
||||||
|
|
||||||
/* ----------
|
/* ----------
|
||||||
* exec_stmt_loop Loop over statements until
|
* exec_stmt_loop Loop over statements until
|
||||||
* an exit occurs.
|
* an exit occurs.
|
||||||
|
@ -8,7 +8,7 @@
|
|||||||
*
|
*
|
||||||
*
|
*
|
||||||
* IDENTIFICATION
|
* IDENTIFICATION
|
||||||
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.71 2008/05/13 22:10:30 tgl Exp $
|
* $PostgreSQL: pgsql/src/pl/plpgsql/src/pl_funcs.c,v 1.72 2008/05/15 22:39:49 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -466,7 +466,7 @@ plpgsql_convert_ident(const char *s, char **output, int numidents)
|
|||||||
const char *
|
const char *
|
||||||
plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
|
plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
|
||||||
{
|
{
|
||||||
switch (stmt->cmd_type)
|
switch ((enum PLpgSQL_stmt_types) stmt->cmd_type)
|
||||||
{
|
{
|
||||||
case PLPGSQL_STMT_BLOCK:
|
case PLPGSQL_STMT_BLOCK:
|
||||||
return _("statement block");
|
return _("statement block");
|
||||||
@ -474,6 +474,8 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
|
|||||||
return _("assignment");
|
return _("assignment");
|
||||||
case PLPGSQL_STMT_IF:
|
case PLPGSQL_STMT_IF:
|
||||||
return "IF";
|
return "IF";
|
||||||
|
case PLPGSQL_STMT_CASE:
|
||||||
|
return "CASE";
|
||||||
case PLPGSQL_STMT_LOOP:
|
case PLPGSQL_STMT_LOOP:
|
||||||
return "LOOP";
|
return "LOOP";
|
||||||
case PLPGSQL_STMT_WHILE:
|
case PLPGSQL_STMT_WHILE:
|
||||||
@ -526,6 +528,7 @@ static void dump_stmt(PLpgSQL_stmt *stmt);
|
|||||||
static void dump_block(PLpgSQL_stmt_block *block);
|
static void dump_block(PLpgSQL_stmt_block *block);
|
||||||
static void dump_assign(PLpgSQL_stmt_assign *stmt);
|
static void dump_assign(PLpgSQL_stmt_assign *stmt);
|
||||||
static void dump_if(PLpgSQL_stmt_if *stmt);
|
static void dump_if(PLpgSQL_stmt_if *stmt);
|
||||||
|
static void dump_case(PLpgSQL_stmt_case *stmt);
|
||||||
static void dump_loop(PLpgSQL_stmt_loop *stmt);
|
static void dump_loop(PLpgSQL_stmt_loop *stmt);
|
||||||
static void dump_while(PLpgSQL_stmt_while *stmt);
|
static void dump_while(PLpgSQL_stmt_while *stmt);
|
||||||
static void dump_fori(PLpgSQL_stmt_fori *stmt);
|
static void dump_fori(PLpgSQL_stmt_fori *stmt);
|
||||||
@ -561,7 +564,7 @@ static void
|
|||||||
dump_stmt(PLpgSQL_stmt *stmt)
|
dump_stmt(PLpgSQL_stmt *stmt)
|
||||||
{
|
{
|
||||||
printf("%3d:", stmt->lineno);
|
printf("%3d:", stmt->lineno);
|
||||||
switch (stmt->cmd_type)
|
switch ((enum PLpgSQL_stmt_types) stmt->cmd_type)
|
||||||
{
|
{
|
||||||
case PLPGSQL_STMT_BLOCK:
|
case PLPGSQL_STMT_BLOCK:
|
||||||
dump_block((PLpgSQL_stmt_block *) stmt);
|
dump_block((PLpgSQL_stmt_block *) stmt);
|
||||||
@ -572,6 +575,9 @@ dump_stmt(PLpgSQL_stmt *stmt)
|
|||||||
case PLPGSQL_STMT_IF:
|
case PLPGSQL_STMT_IF:
|
||||||
dump_if((PLpgSQL_stmt_if *) stmt);
|
dump_if((PLpgSQL_stmt_if *) stmt);
|
||||||
break;
|
break;
|
||||||
|
case PLPGSQL_STMT_CASE:
|
||||||
|
dump_case((PLpgSQL_stmt_case *) stmt);
|
||||||
|
break;
|
||||||
case PLPGSQL_STMT_LOOP:
|
case PLPGSQL_STMT_LOOP:
|
||||||
dump_loop((PLpgSQL_stmt_loop *) stmt);
|
dump_loop((PLpgSQL_stmt_loop *) stmt);
|
||||||
break;
|
break;
|
||||||
@ -714,6 +720,44 @@ dump_if(PLpgSQL_stmt_if *stmt)
|
|||||||
printf(" ENDIF\n");
|
printf(" ENDIF\n");
|
||||||
}
|
}
|
||||||
|
|
||||||
|
static void
|
||||||
|
dump_case(PLpgSQL_stmt_case *stmt)
|
||||||
|
{
|
||||||
|
ListCell *l;
|
||||||
|
|
||||||
|
dump_ind();
|
||||||
|
printf("CASE %d ", stmt->t_varno);
|
||||||
|
if (stmt->t_expr)
|
||||||
|
dump_expr(stmt->t_expr);
|
||||||
|
printf("\n");
|
||||||
|
dump_indent += 6;
|
||||||
|
foreach(l, stmt->case_when_list)
|
||||||
|
{
|
||||||
|
PLpgSQL_case_when *cwt = (PLpgSQL_case_when *) lfirst(l);
|
||||||
|
|
||||||
|
dump_ind();
|
||||||
|
printf("WHEN ");
|
||||||
|
dump_expr(cwt->expr);
|
||||||
|
printf("\n");
|
||||||
|
dump_ind();
|
||||||
|
printf("THEN\n");
|
||||||
|
dump_indent += 2;
|
||||||
|
dump_stmts(cwt->stmts);
|
||||||
|
dump_indent -= 2;
|
||||||
|
}
|
||||||
|
if (stmt->have_else)
|
||||||
|
{
|
||||||
|
dump_ind();
|
||||||
|
printf("ELSE\n");
|
||||||
|
dump_indent += 2;
|
||||||
|
dump_stmts(stmt->else_stmts);
|
||||||
|
dump_indent -= 2;
|
||||||
|
}
|
||||||
|
dump_indent -= 6;
|
||||||
|
dump_ind();
|
||||||
|
printf(" ENDCASE\n");
|
||||||
|
}
|
||||||
|
|
||||||
static void
|
static void
|
||||||
dump_loop(PLpgSQL_stmt_loop *stmt)
|
dump_loop(PLpgSQL_stmt_loop *stmt)
|
||||||
{
|
{
|
||||||
@ -1025,7 +1069,7 @@ dump_raise(PLpgSQL_stmt_raise *stmt)
|
|||||||
foreach(lc, stmt->options)
|
foreach(lc, stmt->options)
|
||||||
{
|
{
|
||||||
PLpgSQL_raise_option *opt = (PLpgSQL_raise_option *) lfirst(lc);
|
PLpgSQL_raise_option *opt = (PLpgSQL_raise_option *) lfirst(lc);
|
||||||
|
|
||||||
dump_ind();
|
dump_ind();
|
||||||
switch (opt->opt_type)
|
switch (opt->opt_type)
|
||||||
{
|
{
|
||||||
@ -1034,7 +1078,7 @@ dump_raise(PLpgSQL_stmt_raise *stmt)
|
|||||||
break;
|
break;
|
||||||
case PLPGSQL_RAISEOPTION_MESSAGE:
|
case PLPGSQL_RAISEOPTION_MESSAGE:
|
||||||
printf(" MESSAGE = ");
|
printf(" MESSAGE = ");
|
||||||
break;
|
break;
|
||||||
case PLPGSQL_RAISEOPTION_DETAIL:
|
case PLPGSQL_RAISEOPTION_DETAIL:
|
||||||
printf(" DETAIL = ");
|
printf(" DETAIL = ");
|
||||||
break;
|
break;
|
||||||
@ -1044,7 +1088,7 @@ dump_raise(PLpgSQL_stmt_raise *stmt)
|
|||||||
}
|
}
|
||||||
dump_expr(opt->expr);
|
dump_expr(opt->expr);
|
||||||
printf("\n");
|
printf("\n");
|
||||||
}
|
}
|
||||||
dump_indent -= 2;
|
dump_indent -= 2;
|
||||||
}
|
}
|
||||||
dump_indent -= 2;
|
dump_indent -= 2;
|
||||||
|
@ -9,7 +9,7 @@
|
|||||||
*
|
*
|
||||||
* Copyright (c) 2003-2008, PostgreSQL Global Development Group
|
* Copyright (c) 2003-2008, PostgreSQL Global Development Group
|
||||||
*
|
*
|
||||||
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plerrcodes.h,v 1.13 2008/01/15 01:36:53 tgl Exp $
|
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plerrcodes.h,v 1.14 2008/05/15 22:39:49 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -79,6 +79,10 @@
|
|||||||
"invalid_role_specification", ERRCODE_INVALID_ROLE_SPECIFICATION
|
"invalid_role_specification", ERRCODE_INVALID_ROLE_SPECIFICATION
|
||||||
},
|
},
|
||||||
|
|
||||||
|
{
|
||||||
|
"case_not_found", ERRCODE_CASE_NOT_FOUND
|
||||||
|
},
|
||||||
|
|
||||||
{
|
{
|
||||||
"cardinality_violation", ERRCODE_CARDINALITY_VIOLATION
|
"cardinality_violation", ERRCODE_CARDINALITY_VIOLATION
|
||||||
},
|
},
|
||||||
|
@ -8,7 +8,7 @@
|
|||||||
*
|
*
|
||||||
*
|
*
|
||||||
* IDENTIFICATION
|
* IDENTIFICATION
|
||||||
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.99 2008/05/13 22:10:30 tgl Exp $
|
* $PostgreSQL: pgsql/src/pl/plpgsql/src/plpgsql.h,v 1.100 2008/05/15 22:39:49 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -71,11 +71,12 @@ enum
|
|||||||
* Execution tree node types
|
* Execution tree node types
|
||||||
* ----------
|
* ----------
|
||||||
*/
|
*/
|
||||||
enum
|
enum PLpgSQL_stmt_types
|
||||||
{
|
{
|
||||||
PLPGSQL_STMT_BLOCK,
|
PLPGSQL_STMT_BLOCK,
|
||||||
PLPGSQL_STMT_ASSIGN,
|
PLPGSQL_STMT_ASSIGN,
|
||||||
PLPGSQL_STMT_IF,
|
PLPGSQL_STMT_IF,
|
||||||
|
PLPGSQL_STMT_CASE,
|
||||||
PLPGSQL_STMT_LOOP,
|
PLPGSQL_STMT_LOOP,
|
||||||
PLPGSQL_STMT_WHILE,
|
PLPGSQL_STMT_WHILE,
|
||||||
PLPGSQL_STMT_FORI,
|
PLPGSQL_STMT_FORI,
|
||||||
@ -390,6 +391,25 @@ typedef struct
|
|||||||
} PLpgSQL_stmt_if;
|
} PLpgSQL_stmt_if;
|
||||||
|
|
||||||
|
|
||||||
|
typedef struct /* CASE statement */
|
||||||
|
{
|
||||||
|
int cmd_type;
|
||||||
|
int lineno;
|
||||||
|
PLpgSQL_expr *t_expr; /* test expression, or NULL if none */
|
||||||
|
int t_varno; /* var to store test expression value into */
|
||||||
|
List *case_when_list; /* List of PLpgSQL_case_when structs */
|
||||||
|
bool have_else; /* flag needed because list could be empty */
|
||||||
|
List *else_stmts; /* List of statements */
|
||||||
|
} PLpgSQL_stmt_case;
|
||||||
|
|
||||||
|
typedef struct /* one arm of CASE statement */
|
||||||
|
{
|
||||||
|
int lineno;
|
||||||
|
PLpgSQL_expr *expr; /* boolean expression for this case */
|
||||||
|
List *stmts; /* List of statements */
|
||||||
|
} PLpgSQL_case_when;
|
||||||
|
|
||||||
|
|
||||||
typedef struct
|
typedef struct
|
||||||
{ /* Unconditional LOOP statement */
|
{ /* Unconditional LOOP statement */
|
||||||
int cmd_type;
|
int cmd_type;
|
||||||
|
@ -9,7 +9,7 @@
|
|||||||
*
|
*
|
||||||
*
|
*
|
||||||
* IDENTIFICATION
|
* IDENTIFICATION
|
||||||
* $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.63 2008/05/13 22:10:30 tgl Exp $
|
* $PostgreSQL: pgsql/src/pl/plpgsql/src/scan.l,v 1.64 2008/05/15 22:39:49 tgl Exp $
|
||||||
*
|
*
|
||||||
*-------------------------------------------------------------------------
|
*-------------------------------------------------------------------------
|
||||||
*/
|
*/
|
||||||
@ -116,6 +116,7 @@ dolqinside [^$]+
|
|||||||
alias { return K_ALIAS; }
|
alias { return K_ALIAS; }
|
||||||
begin { return K_BEGIN; }
|
begin { return K_BEGIN; }
|
||||||
by { return K_BY; }
|
by { return K_BY; }
|
||||||
|
case { return K_CASE; }
|
||||||
close { return K_CLOSE; }
|
close { return K_CLOSE; }
|
||||||
constant { return K_CONSTANT; }
|
constant { return K_CONSTANT; }
|
||||||
continue { return K_CONTINUE; }
|
continue { return K_CONTINUE; }
|
||||||
|
@ -2,24 +2,24 @@
|
|||||||
-- PLPGSQL
|
-- PLPGSQL
|
||||||
--
|
--
|
||||||
-- Scenario:
|
-- Scenario:
|
||||||
--
|
--
|
||||||
-- A building with a modern TP cable installation where any
|
-- A building with a modern TP cable installation where any
|
||||||
-- of the wall connectors can be used to plug in phones,
|
-- of the wall connectors can be used to plug in phones,
|
||||||
-- ethernet interfaces or local office hubs. The backside
|
-- ethernet interfaces or local office hubs. The backside
|
||||||
-- of the wall connectors is wired to one of several patch-
|
-- of the wall connectors is wired to one of several patch-
|
||||||
-- fields in the building.
|
-- fields in the building.
|
||||||
--
|
--
|
||||||
-- In the patchfields, there are hubs and all the slots
|
-- In the patchfields, there are hubs and all the slots
|
||||||
-- representing the wall connectors. In addition there are
|
-- representing the wall connectors. In addition there are
|
||||||
-- slots that can represent a phone line from the central
|
-- slots that can represent a phone line from the central
|
||||||
-- phone system.
|
-- phone system.
|
||||||
--
|
--
|
||||||
-- Triggers ensure consistency of the patching information.
|
-- Triggers ensure consistency of the patching information.
|
||||||
--
|
--
|
||||||
-- Functions are used to build up powerful views that let
|
-- Functions are used to build up powerful views that let
|
||||||
-- you look behind the wall when looking at a patchfield
|
-- you look behind the wall when looking at a patchfield
|
||||||
-- or into a room.
|
-- or into a room.
|
||||||
--
|
--
|
||||||
create table Room (
|
create table Room (
|
||||||
roomno char(8),
|
roomno char(8),
|
||||||
comment text
|
comment text
|
||||||
@ -84,10 +84,10 @@ create table PHone (
|
|||||||
);
|
);
|
||||||
create unique index PHone_name on PHone using btree (slotname bpchar_ops);
|
create unique index PHone_name on PHone using btree (slotname bpchar_ops);
|
||||||
-- ************************************************************
|
-- ************************************************************
|
||||||
-- *
|
-- *
|
||||||
-- * Trigger procedures and functions for the patchfield
|
-- * Trigger procedures and functions for the patchfield
|
||||||
-- * test of PL/pgSQL
|
-- * test of PL/pgSQL
|
||||||
-- *
|
-- *
|
||||||
-- ************************************************************
|
-- ************************************************************
|
||||||
-- ************************************************************
|
-- ************************************************************
|
||||||
-- * AFTER UPDATE on Room
|
-- * AFTER UPDATE on Room
|
||||||
@ -597,11 +597,11 @@ begin
|
|||||||
mytype := substr(myname, 1, 2);
|
mytype := substr(myname, 1, 2);
|
||||||
link := mytype || substr(blname, 1, 2);
|
link := mytype || substr(blname, 1, 2);
|
||||||
if link = ''PLPL'' then
|
if link = ''PLPL'' then
|
||||||
raise exception
|
raise exception
|
||||||
''backlink between two phone lines does not make sense'';
|
''backlink between two phone lines does not make sense'';
|
||||||
end if;
|
end if;
|
||||||
if link in (''PLWS'', ''WSPL'') then
|
if link in (''PLWS'', ''WSPL'') then
|
||||||
raise exception
|
raise exception
|
||||||
''direct link of phone line to wall slot not permitted'';
|
''direct link of phone line to wall slot not permitted'';
|
||||||
end if;
|
end if;
|
||||||
if mytype = ''PS'' then
|
if mytype = ''PS'' then
|
||||||
@ -745,19 +745,19 @@ begin
|
|||||||
mytype := substr(myname, 1, 2);
|
mytype := substr(myname, 1, 2);
|
||||||
link := mytype || substr(blname, 1, 2);
|
link := mytype || substr(blname, 1, 2);
|
||||||
if link = ''PHPH'' then
|
if link = ''PHPH'' then
|
||||||
raise exception
|
raise exception
|
||||||
''slotlink between two phones does not make sense'';
|
''slotlink between two phones does not make sense'';
|
||||||
end if;
|
end if;
|
||||||
if link in (''PHHS'', ''HSPH'') then
|
if link in (''PHHS'', ''HSPH'') then
|
||||||
raise exception
|
raise exception
|
||||||
''link of phone to hub does not make sense'';
|
''link of phone to hub does not make sense'';
|
||||||
end if;
|
end if;
|
||||||
if link in (''PHIF'', ''IFPH'') then
|
if link in (''PHIF'', ''IFPH'') then
|
||||||
raise exception
|
raise exception
|
||||||
''link of phone to hub does not make sense'';
|
''link of phone to hub does not make sense'';
|
||||||
end if;
|
end if;
|
||||||
if link in (''PSWS'', ''WSPS'') then
|
if link in (''PSWS'', ''WSPS'') then
|
||||||
raise exception
|
raise exception
|
||||||
''slotlink from patchslot to wallslot not permitted'';
|
''slotlink from patchslot to wallslot not permitted'';
|
||||||
end if;
|
end if;
|
||||||
if mytype = ''PS'' then
|
if mytype = ''PS'' then
|
||||||
@ -2936,7 +2936,7 @@ CONTEXT: PL/pgSQL function "footest" line 4 at EXECUTE statement
|
|||||||
drop function footest();
|
drop function footest();
|
||||||
-- test scrollable cursor support
|
-- test scrollable cursor support
|
||||||
create function sc_test() returns setof integer as $$
|
create function sc_test() returns setof integer as $$
|
||||||
declare
|
declare
|
||||||
c scroll cursor for select f1 from int4_tbl;
|
c scroll cursor for select f1 from int4_tbl;
|
||||||
x integer;
|
x integer;
|
||||||
begin
|
begin
|
||||||
@ -2960,7 +2960,7 @@ select * from sc_test();
|
|||||||
(5 rows)
|
(5 rows)
|
||||||
|
|
||||||
create or replace function sc_test() returns setof integer as $$
|
create or replace function sc_test() returns setof integer as $$
|
||||||
declare
|
declare
|
||||||
c no scroll cursor for select f1 from int4_tbl;
|
c no scroll cursor for select f1 from int4_tbl;
|
||||||
x integer;
|
x integer;
|
||||||
begin
|
begin
|
||||||
@ -2978,7 +2978,7 @@ ERROR: cursor can only scan forward
|
|||||||
HINT: Declare it with SCROLL option to enable backward scan.
|
HINT: Declare it with SCROLL option to enable backward scan.
|
||||||
CONTEXT: PL/pgSQL function "sc_test" line 6 at FETCH
|
CONTEXT: PL/pgSQL function "sc_test" line 6 at FETCH
|
||||||
create or replace function sc_test() returns setof integer as $$
|
create or replace function sc_test() returns setof integer as $$
|
||||||
declare
|
declare
|
||||||
c refcursor;
|
c refcursor;
|
||||||
x integer;
|
x integer;
|
||||||
begin
|
begin
|
||||||
@ -3002,7 +3002,7 @@ select * from sc_test();
|
|||||||
(5 rows)
|
(5 rows)
|
||||||
|
|
||||||
create or replace function sc_test() returns setof integer as $$
|
create or replace function sc_test() returns setof integer as $$
|
||||||
declare
|
declare
|
||||||
c refcursor;
|
c refcursor;
|
||||||
x integer;
|
x integer;
|
||||||
begin
|
begin
|
||||||
@ -3288,9 +3288,9 @@ drop function return_dquery();
|
|||||||
-- Tests for 8.4's new RAISE features
|
-- Tests for 8.4's new RAISE features
|
||||||
create or replace function raise_test() returns void as $$
|
create or replace function raise_test() returns void as $$
|
||||||
begin
|
begin
|
||||||
raise notice '% % %', 1, 2, 3
|
raise notice '% % %', 1, 2, 3
|
||||||
using errcode = '55001', detail = 'some detail info', hint = 'some hint';
|
using errcode = '55001', detail = 'some detail info', hint = 'some hint';
|
||||||
raise '% % %', 1, 2, 3
|
raise '% % %', 1, 2, 3
|
||||||
using errcode = 'division_by_zero', detail = 'some detail info';
|
using errcode = 'division_by_zero', detail = 'some detail info';
|
||||||
end;
|
end;
|
||||||
$$ language plpgsql;
|
$$ language plpgsql;
|
||||||
@ -3414,3 +3414,133 @@ select raise_test();
|
|||||||
ERROR: RAISE without parameters cannot be used outside an exception handler
|
ERROR: RAISE without parameters cannot be used outside an exception handler
|
||||||
CONTEXT: PL/pgSQL function "raise_test"
|
CONTEXT: PL/pgSQL function "raise_test"
|
||||||
drop function raise_test();
|
drop function raise_test();
|
||||||
|
-- test CASE statement
|
||||||
|
create or replace function case_test(bigint) returns text as $$
|
||||||
|
declare a int = 10;
|
||||||
|
b int = 1;
|
||||||
|
begin
|
||||||
|
case $1
|
||||||
|
when 1 then
|
||||||
|
return 'one';
|
||||||
|
when 2 then
|
||||||
|
return 'two';
|
||||||
|
when 3,4,3+5 then
|
||||||
|
return 'three, four or eight';
|
||||||
|
when a then
|
||||||
|
return 'ten';
|
||||||
|
when a+b, a+b+1 then
|
||||||
|
return 'eleven, twelve';
|
||||||
|
end case;
|
||||||
|
end;
|
||||||
|
$$ language plpgsql immutable;
|
||||||
|
select case_test(1);
|
||||||
|
case_test
|
||||||
|
-----------
|
||||||
|
one
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
select case_test(2);
|
||||||
|
case_test
|
||||||
|
-----------
|
||||||
|
two
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
select case_test(3);
|
||||||
|
case_test
|
||||||
|
----------------------
|
||||||
|
three, four or eight
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
select case_test(4);
|
||||||
|
case_test
|
||||||
|
----------------------
|
||||||
|
three, four or eight
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
select case_test(5); -- fails
|
||||||
|
ERROR: case not found
|
||||||
|
HINT: CASE statement is missing ELSE part.
|
||||||
|
CONTEXT: PL/pgSQL function "case_test" line 4 at CASE
|
||||||
|
select case_test(8);
|
||||||
|
case_test
|
||||||
|
----------------------
|
||||||
|
three, four or eight
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
select case_test(10);
|
||||||
|
case_test
|
||||||
|
-----------
|
||||||
|
ten
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
select case_test(11);
|
||||||
|
case_test
|
||||||
|
----------------
|
||||||
|
eleven, twelve
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
select case_test(12);
|
||||||
|
case_test
|
||||||
|
----------------
|
||||||
|
eleven, twelve
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
select case_test(13); -- fails
|
||||||
|
ERROR: case not found
|
||||||
|
HINT: CASE statement is missing ELSE part.
|
||||||
|
CONTEXT: PL/pgSQL function "case_test" line 4 at CASE
|
||||||
|
create or replace function catch() returns void as $$
|
||||||
|
begin
|
||||||
|
raise notice '%', case_test(6);
|
||||||
|
exception
|
||||||
|
when case_not_found then
|
||||||
|
raise notice 'caught case_not_found % %', SQLSTATE, SQLERRM;
|
||||||
|
end
|
||||||
|
$$ language plpgsql;
|
||||||
|
select catch();
|
||||||
|
NOTICE: caught case_not_found 20000 case not found
|
||||||
|
catch
|
||||||
|
-------
|
||||||
|
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
-- test the searched variant too, as well as ELSE
|
||||||
|
create or replace function case_test(bigint) returns text as $$
|
||||||
|
declare a int = 10;
|
||||||
|
begin
|
||||||
|
case
|
||||||
|
when $1 = 1 then
|
||||||
|
return 'one';
|
||||||
|
when $1 = a + 2 then
|
||||||
|
return 'twelve';
|
||||||
|
else
|
||||||
|
return 'other';
|
||||||
|
end case;
|
||||||
|
end;
|
||||||
|
$$ language plpgsql immutable;
|
||||||
|
select case_test(1);
|
||||||
|
case_test
|
||||||
|
-----------
|
||||||
|
one
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
select case_test(2);
|
||||||
|
case_test
|
||||||
|
-----------
|
||||||
|
other
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
select case_test(12);
|
||||||
|
case_test
|
||||||
|
-----------
|
||||||
|
twelve
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
select case_test(13);
|
||||||
|
case_test
|
||||||
|
-----------
|
||||||
|
other
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
drop function catch();
|
||||||
|
drop function case_test(bigint);
|
||||||
|
@ -2,24 +2,24 @@
|
|||||||
-- PLPGSQL
|
-- PLPGSQL
|
||||||
--
|
--
|
||||||
-- Scenario:
|
-- Scenario:
|
||||||
--
|
--
|
||||||
-- A building with a modern TP cable installation where any
|
-- A building with a modern TP cable installation where any
|
||||||
-- of the wall connectors can be used to plug in phones,
|
-- of the wall connectors can be used to plug in phones,
|
||||||
-- ethernet interfaces or local office hubs. The backside
|
-- ethernet interfaces or local office hubs. The backside
|
||||||
-- of the wall connectors is wired to one of several patch-
|
-- of the wall connectors is wired to one of several patch-
|
||||||
-- fields in the building.
|
-- fields in the building.
|
||||||
--
|
--
|
||||||
-- In the patchfields, there are hubs and all the slots
|
-- In the patchfields, there are hubs and all the slots
|
||||||
-- representing the wall connectors. In addition there are
|
-- representing the wall connectors. In addition there are
|
||||||
-- slots that can represent a phone line from the central
|
-- slots that can represent a phone line from the central
|
||||||
-- phone system.
|
-- phone system.
|
||||||
--
|
--
|
||||||
-- Triggers ensure consistency of the patching information.
|
-- Triggers ensure consistency of the patching information.
|
||||||
--
|
--
|
||||||
-- Functions are used to build up powerful views that let
|
-- Functions are used to build up powerful views that let
|
||||||
-- you look behind the wall when looking at a patchfield
|
-- you look behind the wall when looking at a patchfield
|
||||||
-- or into a room.
|
-- or into a room.
|
||||||
--
|
--
|
||||||
|
|
||||||
|
|
||||||
create table Room (
|
create table Room (
|
||||||
@ -116,10 +116,10 @@ create unique index PHone_name on PHone using btree (slotname bpchar_ops);
|
|||||||
|
|
||||||
|
|
||||||
-- ************************************************************
|
-- ************************************************************
|
||||||
-- *
|
-- *
|
||||||
-- * Trigger procedures and functions for the patchfield
|
-- * Trigger procedures and functions for the patchfield
|
||||||
-- * test of PL/pgSQL
|
-- * test of PL/pgSQL
|
||||||
-- *
|
-- *
|
||||||
-- ************************************************************
|
-- ************************************************************
|
||||||
|
|
||||||
|
|
||||||
@ -708,11 +708,11 @@ begin
|
|||||||
mytype := substr(myname, 1, 2);
|
mytype := substr(myname, 1, 2);
|
||||||
link := mytype || substr(blname, 1, 2);
|
link := mytype || substr(blname, 1, 2);
|
||||||
if link = ''PLPL'' then
|
if link = ''PLPL'' then
|
||||||
raise exception
|
raise exception
|
||||||
''backlink between two phone lines does not make sense'';
|
''backlink between two phone lines does not make sense'';
|
||||||
end if;
|
end if;
|
||||||
if link in (''PLWS'', ''WSPL'') then
|
if link in (''PLWS'', ''WSPL'') then
|
||||||
raise exception
|
raise exception
|
||||||
''direct link of phone line to wall slot not permitted'';
|
''direct link of phone line to wall slot not permitted'';
|
||||||
end if;
|
end if;
|
||||||
if mytype = ''PS'' then
|
if mytype = ''PS'' then
|
||||||
@ -868,19 +868,19 @@ begin
|
|||||||
mytype := substr(myname, 1, 2);
|
mytype := substr(myname, 1, 2);
|
||||||
link := mytype || substr(blname, 1, 2);
|
link := mytype || substr(blname, 1, 2);
|
||||||
if link = ''PHPH'' then
|
if link = ''PHPH'' then
|
||||||
raise exception
|
raise exception
|
||||||
''slotlink between two phones does not make sense'';
|
''slotlink between two phones does not make sense'';
|
||||||
end if;
|
end if;
|
||||||
if link in (''PHHS'', ''HSPH'') then
|
if link in (''PHHS'', ''HSPH'') then
|
||||||
raise exception
|
raise exception
|
||||||
''link of phone to hub does not make sense'';
|
''link of phone to hub does not make sense'';
|
||||||
end if;
|
end if;
|
||||||
if link in (''PHIF'', ''IFPH'') then
|
if link in (''PHIF'', ''IFPH'') then
|
||||||
raise exception
|
raise exception
|
||||||
''link of phone to hub does not make sense'';
|
''link of phone to hub does not make sense'';
|
||||||
end if;
|
end if;
|
||||||
if link in (''PSWS'', ''WSPS'') then
|
if link in (''PSWS'', ''WSPS'') then
|
||||||
raise exception
|
raise exception
|
||||||
''slotlink from patchslot to wallslot not permitted'';
|
''slotlink from patchslot to wallslot not permitted'';
|
||||||
end if;
|
end if;
|
||||||
if mytype = ''PS'' then
|
if mytype = ''PS'' then
|
||||||
@ -2444,7 +2444,7 @@ drop function footest();
|
|||||||
-- test scrollable cursor support
|
-- test scrollable cursor support
|
||||||
|
|
||||||
create function sc_test() returns setof integer as $$
|
create function sc_test() returns setof integer as $$
|
||||||
declare
|
declare
|
||||||
c scroll cursor for select f1 from int4_tbl;
|
c scroll cursor for select f1 from int4_tbl;
|
||||||
x integer;
|
x integer;
|
||||||
begin
|
begin
|
||||||
@ -2461,7 +2461,7 @@ $$ language plpgsql;
|
|||||||
select * from sc_test();
|
select * from sc_test();
|
||||||
|
|
||||||
create or replace function sc_test() returns setof integer as $$
|
create or replace function sc_test() returns setof integer as $$
|
||||||
declare
|
declare
|
||||||
c no scroll cursor for select f1 from int4_tbl;
|
c no scroll cursor for select f1 from int4_tbl;
|
||||||
x integer;
|
x integer;
|
||||||
begin
|
begin
|
||||||
@ -2478,7 +2478,7 @@ $$ language plpgsql;
|
|||||||
select * from sc_test(); -- fails because of NO SCROLL specification
|
select * from sc_test(); -- fails because of NO SCROLL specification
|
||||||
|
|
||||||
create or replace function sc_test() returns setof integer as $$
|
create or replace function sc_test() returns setof integer as $$
|
||||||
declare
|
declare
|
||||||
c refcursor;
|
c refcursor;
|
||||||
x integer;
|
x integer;
|
||||||
begin
|
begin
|
||||||
@ -2495,7 +2495,7 @@ $$ language plpgsql;
|
|||||||
select * from sc_test();
|
select * from sc_test();
|
||||||
|
|
||||||
create or replace function sc_test() returns setof integer as $$
|
create or replace function sc_test() returns setof integer as $$
|
||||||
declare
|
declare
|
||||||
c refcursor;
|
c refcursor;
|
||||||
x integer;
|
x integer;
|
||||||
begin
|
begin
|
||||||
@ -2688,9 +2688,9 @@ drop function return_dquery();
|
|||||||
|
|
||||||
create or replace function raise_test() returns void as $$
|
create or replace function raise_test() returns void as $$
|
||||||
begin
|
begin
|
||||||
raise notice '% % %', 1, 2, 3
|
raise notice '% % %', 1, 2, 3
|
||||||
using errcode = '55001', detail = 'some detail info', hint = 'some hint';
|
using errcode = '55001', detail = 'some detail info', hint = 'some hint';
|
||||||
raise '% % %', 1, 2, 3
|
raise '% % %', 1, 2, 3
|
||||||
using errcode = 'division_by_zero', detail = 'some detail info';
|
using errcode = 'division_by_zero', detail = 'some detail info';
|
||||||
end;
|
end;
|
||||||
$$ language plpgsql;
|
$$ language plpgsql;
|
||||||
@ -2812,3 +2812,69 @@ $$ language plpgsql;
|
|||||||
select raise_test();
|
select raise_test();
|
||||||
|
|
||||||
drop function raise_test();
|
drop function raise_test();
|
||||||
|
|
||||||
|
-- test CASE statement
|
||||||
|
|
||||||
|
create or replace function case_test(bigint) returns text as $$
|
||||||
|
declare a int = 10;
|
||||||
|
b int = 1;
|
||||||
|
begin
|
||||||
|
case $1
|
||||||
|
when 1 then
|
||||||
|
return 'one';
|
||||||
|
when 2 then
|
||||||
|
return 'two';
|
||||||
|
when 3,4,3+5 then
|
||||||
|
return 'three, four or eight';
|
||||||
|
when a then
|
||||||
|
return 'ten';
|
||||||
|
when a+b, a+b+1 then
|
||||||
|
return 'eleven, twelve';
|
||||||
|
end case;
|
||||||
|
end;
|
||||||
|
$$ language plpgsql immutable;
|
||||||
|
|
||||||
|
select case_test(1);
|
||||||
|
select case_test(2);
|
||||||
|
select case_test(3);
|
||||||
|
select case_test(4);
|
||||||
|
select case_test(5); -- fails
|
||||||
|
select case_test(8);
|
||||||
|
select case_test(10);
|
||||||
|
select case_test(11);
|
||||||
|
select case_test(12);
|
||||||
|
select case_test(13); -- fails
|
||||||
|
|
||||||
|
create or replace function catch() returns void as $$
|
||||||
|
begin
|
||||||
|
raise notice '%', case_test(6);
|
||||||
|
exception
|
||||||
|
when case_not_found then
|
||||||
|
raise notice 'caught case_not_found % %', SQLSTATE, SQLERRM;
|
||||||
|
end
|
||||||
|
$$ language plpgsql;
|
||||||
|
|
||||||
|
select catch();
|
||||||
|
|
||||||
|
-- test the searched variant too, as well as ELSE
|
||||||
|
create or replace function case_test(bigint) returns text as $$
|
||||||
|
declare a int = 10;
|
||||||
|
begin
|
||||||
|
case
|
||||||
|
when $1 = 1 then
|
||||||
|
return 'one';
|
||||||
|
when $1 = a + 2 then
|
||||||
|
return 'twelve';
|
||||||
|
else
|
||||||
|
return 'other';
|
||||||
|
end case;
|
||||||
|
end;
|
||||||
|
$$ language plpgsql immutable;
|
||||||
|
|
||||||
|
select case_test(1);
|
||||||
|
select case_test(2);
|
||||||
|
select case_test(12);
|
||||||
|
select case_test(13);
|
||||||
|
|
||||||
|
drop function catch();
|
||||||
|
drop function case_test(bigint);
|
||||||
|
Reference in New Issue
Block a user