支持游标参数默认值
This commit is contained in:
@ -803,10 +803,14 @@ declare_stmt : T_DECLARE_CURSOR decl_varname K_CURSOR opt_scrollable
|
||||
true);
|
||||
|
||||
newp->cursor_explicit_expr = $8;
|
||||
if ($6 == NULL)
|
||||
if ($6 == NULL) {
|
||||
newp->cursor_explicit_argrow = -1;
|
||||
else
|
||||
newp->cursor_implicit_argrow = -1;
|
||||
}
|
||||
else {
|
||||
newp->cursor_explicit_argrow = $6->dno;
|
||||
newp->cursor_implicit_argrow = ((PLpgSQL_row*)$6)->needValDno;
|
||||
}
|
||||
newp->cursor_options = CURSOR_OPT_FAST_PLAN | $4;
|
||||
u_sess->plsql_cxt.plpgsql_yylloc = plpgsql_yylloc;
|
||||
newp->datatype->cursorCompositeOid = IS_ANONYMOUS_BLOCK ?
|
||||
@ -1344,10 +1348,13 @@ decl_statement : decl_varname_list decl_const decl_datatype decl_collate decl_no
|
||||
true);
|
||||
|
||||
newp->cursor_explicit_expr = $7;
|
||||
if ($5 == NULL)
|
||||
if ($5 == NULL) {
|
||||
newp->cursor_explicit_argrow = -1;
|
||||
else
|
||||
newp->cursor_implicit_argrow = -1;
|
||||
} else {
|
||||
newp->cursor_explicit_argrow = $5->dno;
|
||||
newp->cursor_implicit_argrow = ((PLpgSQL_row*)$5)->needValDno;
|
||||
}
|
||||
newp->cursor_options = CURSOR_OPT_FAST_PLAN | $3;
|
||||
u_sess->plsql_cxt.plpgsql_yylloc = plpgsql_yylloc;
|
||||
newp->datatype->cursorCompositeOid = IS_ANONYMOUS_BLOCK ?
|
||||
@ -2305,15 +2312,23 @@ decl_cursor_args :
|
||||
newp->rowtupdesc = NULL;
|
||||
newp->nfields = list_length($2);
|
||||
newp->fieldnames = (char **)palloc(newp->nfields * sizeof(char *));
|
||||
newp->argDefExpr = (PLpgSQL_expr**)palloc(newp->nfields * sizeof(PLpgSQL_expr*));
|
||||
newp->varnos = (int *)palloc(newp->nfields * sizeof(int));
|
||||
newp->isImplicit = true;
|
||||
newp->addNamespace = false;
|
||||
i = 0;
|
||||
newp->needValDno = 0;
|
||||
foreach (l, $2)
|
||||
{
|
||||
PLpgSQL_variable *arg = (PLpgSQL_variable *) lfirst(l);
|
||||
newp->fieldnames[i] = arg->refname;
|
||||
newp->varnos[i] = arg->dno;
|
||||
newp->argDefExpr[i] = arg->dtype == PLPGSQL_DTYPE_VAR ? ((PLpgSQL_var*)arg)->default_val :
|
||||
arg->dtype == PLPGSQL_DTYPE_ROW ? ((PLpgSQL_row*)arg)->default_val :
|
||||
arg->dtype == PLPGSQL_DTYPE_RECORD ? ((PLpgSQL_row*)arg)->default_val :
|
||||
arg->dtype == PLPGSQL_DTYPE_REC ? ((PLpgSQL_rec*)arg)->default_val: NULL ;
|
||||
if(newp->argDefExpr[i] == NULL)
|
||||
newp->needValDno = i+1;
|
||||
i++;
|
||||
}
|
||||
list_free_ext($2);
|
||||
@ -2333,13 +2348,36 @@ decl_cursor_arglist : decl_cursor_arg
|
||||
}
|
||||
;
|
||||
|
||||
decl_cursor_arg : decl_varname cursor_in_out_option decl_datatype
|
||||
decl_cursor_arg : decl_varname cursor_in_out_option decl_datatype decl_rec_defval
|
||||
{
|
||||
$$ = (PLpgSQL_datum *)
|
||||
plpgsql_build_variable($1->name, $1->lineno,
|
||||
$3, true);
|
||||
PLpgSQL_variable* arg =
|
||||
plpgsql_build_variable($1->name, $1->lineno, $3, true);
|
||||
if (arg != NULL) {
|
||||
switch (arg->dtype) {
|
||||
case PLPGSQL_DTYPE_VAR: {
|
||||
((PLpgSQL_var*)arg)->default_val = $4;
|
||||
break;
|
||||
}
|
||||
case PLPGSQL_DTYPE_ROW:
|
||||
case PLPGSQL_DTYPE_RECORD: {
|
||||
((PLpgSQL_row*)arg)->default_val = $4;
|
||||
break;
|
||||
}
|
||||
case PLPGSQL_DTYPE_REC: {
|
||||
((PLpgSQL_rec*)arg)->default_val = $4;
|
||||
break;
|
||||
}
|
||||
default: {
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_UNRECOGNIZED_NODE_TYPE),
|
||||
errmodule(MOD_PLSQL),
|
||||
errmsg("unrecognized variable type for cursor argument.")));
|
||||
}
|
||||
}
|
||||
}
|
||||
$$ = (PLpgSQL_datum*)arg;
|
||||
pfree_ext($1->name);
|
||||
pfree($1);
|
||||
pfree($1);
|
||||
}
|
||||
;
|
||||
cursor_in_out_option : K_IN |
|
||||
@ -13057,7 +13095,7 @@ read_cursor_args(PLpgSQL_var *cursor, int until, const char *expected)
|
||||
}
|
||||
|
||||
/* Else better provide arguments */
|
||||
if (tok != '(') {
|
||||
if (tok != '(' && cursor->cursor_implicit_argrow > 0) {
|
||||
const char* message = "cursor has arguments";
|
||||
InsertErrorMessage(message, plpgsql_yylloc);
|
||||
ereport(errstate,
|
||||
@ -13093,7 +13131,8 @@ read_cursor_args(PLpgSQL_var *cursor, int until, const char *expected)
|
||||
}
|
||||
argv = (char **) palloc0(row->nfields * sizeof(char *));
|
||||
|
||||
for (argc = 0; argc < row->nfields; argc++)
|
||||
/* No need to process value exprs in case of 'open c;' */
|
||||
for (argc = 0; argc < row->nfields && tok == '('; argc++)
|
||||
{
|
||||
PLpgSQL_expr *item;
|
||||
int endtoken;
|
||||
@ -13104,6 +13143,12 @@ read_cursor_args(PLpgSQL_var *cursor, int until, const char *expected)
|
||||
|
||||
/* Check if it's a named parameter: "param := value" */
|
||||
plpgsql_peek2(&tok1, &tok2, &arglocation, NULL);
|
||||
/* Done reading value exprs */
|
||||
if (tok1 == ')'){
|
||||
/* read ')' */
|
||||
yylex();
|
||||
break;
|
||||
}
|
||||
if (tok1 == IDENT && tok2 == COLON_EQUALS)
|
||||
{
|
||||
char *argname;
|
||||
@ -13173,14 +13218,9 @@ read_cursor_args(PLpgSQL_var *cursor, int until, const char *expected)
|
||||
|
||||
argv[argpos] = item->query + strlen(sqlstart);
|
||||
|
||||
if (endtoken == ')' && !(argc == row->nfields - 1)) {
|
||||
const char* message = "not enough arguments for cursor";
|
||||
InsertErrorMessage(message, plpgsql_yylloc);
|
||||
ereport(errstate,
|
||||
(errcode(ERRCODE_SYNTAX_ERROR),
|
||||
errmsg("not enough arguments for cursor \"%s\"",
|
||||
cursor->refname),
|
||||
parser_errposition(yylloc)));
|
||||
if (endtoken == ')') {
|
||||
argc++;
|
||||
break;
|
||||
}
|
||||
|
||||
if (endtoken == ',' && (argc == row->nfields - 1)) {
|
||||
@ -13194,6 +13234,24 @@ read_cursor_args(PLpgSQL_var *cursor, int until, const char *expected)
|
||||
}
|
||||
}
|
||||
|
||||
/* fill rest arguments with default values, if they have any */
|
||||
for (argc = 0; argc < row->nfields; argc++)
|
||||
{
|
||||
if (argv[argc] != NULL)
|
||||
continue;
|
||||
PLpgSQL_expr* defexpr = row->argDefExpr[argc];
|
||||
if(!defexpr){
|
||||
const char* message = "not enough values for cursor arguments";
|
||||
InsertErrorMessage(message, plpgsql_yylloc);
|
||||
ereport(errstate,
|
||||
(errcode(ERRCODE_SYNTAX_ERROR),
|
||||
errmsg("not enough values for arguments of cursor \"%s\"",
|
||||
cursor->refname),
|
||||
parser_errposition(yylloc)));
|
||||
}
|
||||
argv[argc] = defexpr->query + strlen(sqlstart);
|
||||
}
|
||||
|
||||
/* Make positional argument list */
|
||||
initStringInfo(&ds);
|
||||
appendStringInfoString(&ds, sqlstart);
|
||||
@ -13227,7 +13285,8 @@ read_cursor_args(PLpgSQL_var *cursor, int until, const char *expected)
|
||||
pfree_ext(ds.data);
|
||||
|
||||
/* Next we'd better find the until token */
|
||||
tok = yylex();
|
||||
if(tok == '(')
|
||||
tok = yylex();
|
||||
if (tok != until)
|
||||
yyerror("syntax error");
|
||||
|
||||
|
||||
@ -951,6 +951,9 @@ void plpgsql_free_function_memory(PLpgSQL_function* func, bool fromPackage)
|
||||
case PLPGSQL_DTYPE_RECORD:
|
||||
case PLPGSQL_DTYPE_ROW: {
|
||||
PLpgSQL_row* row = (PLpgSQL_row*)d;
|
||||
if (row->argDefExpr != NULL)
|
||||
for (int i = 0; i < row->nfields; i++)
|
||||
free_expr(row->argDefExpr[i]);
|
||||
free_expr(row->default_val);
|
||||
} break;
|
||||
case PLPGSQL_DTYPE_REC:
|
||||
@ -1060,6 +1063,9 @@ void plpgsql_free_package_memory(PLpgSQL_package* pkg)
|
||||
case PLPGSQL_DTYPE_RECORD:
|
||||
case PLPGSQL_DTYPE_ROW: {
|
||||
PLpgSQL_row* row = (PLpgSQL_row*)d;
|
||||
if (row->argDefExpr != NULL)
|
||||
for (int i = 0; i < row->nfields; i++)
|
||||
free_expr(row->argDefExpr[i]);
|
||||
free_expr(row->default_val);
|
||||
} break;
|
||||
case PLPGSQL_DTYPE_REC:
|
||||
|
||||
@ -492,7 +492,8 @@ typedef struct PLpgSQL_var { /* Scalar variable */
|
||||
int notnull;
|
||||
PLpgSQL_expr* default_val;
|
||||
PLpgSQL_expr* cursor_explicit_expr;
|
||||
int cursor_explicit_argrow;
|
||||
int cursor_explicit_argrow; /* count of cursor's args including those with default exprs */
|
||||
int cursor_implicit_argrow; /* count of cursor's args requiring values (those without default exprs) */
|
||||
int cursor_options;
|
||||
|
||||
Datum value;
|
||||
@ -531,6 +532,8 @@ typedef struct { /* Row variable */
|
||||
*/
|
||||
int nfields;
|
||||
char** fieldnames;
|
||||
int needValDno; /* count of fields that require values (don't have defaults) */
|
||||
PLpgSQL_expr** argDefExpr;
|
||||
int* varnos; /* only use for unpkg's var, pkg's var is in row->pkg->datums */
|
||||
int customErrorCode; /* only for exception variable. */
|
||||
|
||||
@ -588,6 +591,7 @@ typedef struct { /* Record variable (non-fixed structure) */
|
||||
bool freetupdesc;
|
||||
List* pkg_name = NULL;
|
||||
PLpgSQL_package* pkg = NULL;
|
||||
PLpgSQL_expr* default_val = NULL;
|
||||
} PLpgSQL_rec;
|
||||
|
||||
typedef struct { /* Field in record */
|
||||
|
||||
205
src/test/regress/expected/test_cursor_arg_defexpr.out
Normal file
205
src/test/regress/expected/test_cursor_arg_defexpr.out
Normal file
@ -0,0 +1,205 @@
|
||||
DROP SCHEMA IF EXISTS test_cursor_param_defexpr CASCADE;
|
||||
NOTICE: schema "test_cursor_param_defexpr" does not exist, skipping
|
||||
CREATE SCHEMA test_cursor_param_defexpr;
|
||||
SET CURRENT_SCHEMA TO test_cursor_param_defexpr;
|
||||
CREATE TABLE tb1(a int, b char(10));
|
||||
INSERT INTO tb1 VALUES (1,'a'),(2,'b'),(3,'c'),(4,'d'),(5,'e');
|
||||
-- regular cursor without defexprs
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c FOR SELECT * FROM tb1 t;
|
||||
BEGIN
|
||||
OPEN c;
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
NOTICE: 1, a
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int) FOR SELECT * FROM tb1 t WHERE a>=arg1;
|
||||
BEGIN
|
||||
OPEN c(1);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
NOTICE: 1, a
|
||||
-- define cursor with defexprs, and open cursor without values specified
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int default 2) FOR SELECT * FROM tb1 t WHERE a>=arg1;
|
||||
BEGIN
|
||||
OPEN c();
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
NOTICE: 2, b
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int = 2) FOR SELECT * FROM tb1 t WHERE a>=arg1;
|
||||
BEGIN
|
||||
OPEN c;
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
NOTICE: 2, b
|
||||
-- default cursor composite type argv
|
||||
CREATE OR REPLACE TYPE rectype AS (a int, b char(10));
|
||||
DECLARE
|
||||
CURSOR c (r rectype default (3,'c')) FOR SELECT * from tb1 where a=r.a;
|
||||
rec RECORD;
|
||||
BEGIN
|
||||
OPEN c;
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
NOTICE: 3, c
|
||||
DECLARE
|
||||
CURSOR c (r tb1%ROWTYPE default (4,'d')) FOR SELECT * from tb1 where a=r.a;
|
||||
rec RECORD;
|
||||
BEGIN
|
||||
OPEN c;
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
NOTICE: 4, d
|
||||
-- open cursor with values specified
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int default 2) FOR SELECT * FROM tb1 t WHERE a>=arg1;
|
||||
BEGIN
|
||||
OPEN c(arg1:=1);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
NOTICE: 1, a
|
||||
-- open cursor in functions
|
||||
CREATE OR REPLACE FUNCTION test_cursor RETURNS int as $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int default 2) FOR SELECT * FROM tb1 WHERE a>=arg1;
|
||||
res INTEGER;
|
||||
BEGIN
|
||||
OPEN c(3);
|
||||
FETCH c INTO rec;
|
||||
res := rec.a;
|
||||
CLOSE c;
|
||||
return res;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
CALL test_cursor();
|
||||
test_cursor
|
||||
-------------
|
||||
3
|
||||
(1 row)
|
||||
|
||||
-- error situation
|
||||
-- open cursor without value list while having args without defexpr
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int, arg2 int, arg3 int default 3) FOR SELECT * FROM tb1 t WHERE a>=(arg1 - arg3);
|
||||
BEGIN
|
||||
OPEN c;
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
ERROR: cursor "c" has arguments
|
||||
LINE 4: OPEN c;
|
||||
^
|
||||
QUERY: DECLARE rec RECORD;
|
||||
CURSOR c (arg1 int, arg2 int, arg3 int default 3) FOR SELECT * FROM tb1 t WHERE a>=(arg1 - arg3);
|
||||
BEGIN
|
||||
OPEN c;
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END
|
||||
-- open cursor without enough values specified
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int, arg2 int, arg3 int default 3) FOR SELECT * FROM tb1 t WHERE a>=(arg1 - arg3);
|
||||
BEGIN
|
||||
OPEN c(1);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
ERROR: not enough values for arguments of cursor "c"
|
||||
LINE 4: OPEN c(1);
|
||||
^
|
||||
QUERY: DECLARE rec RECORD;
|
||||
CURSOR c (arg1 int, arg2 int, arg3 int default 3) FOR SELECT * FROM tb1 t WHERE a>=(arg1 - arg3);
|
||||
BEGIN
|
||||
OPEN c(1);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END
|
||||
-- args with defexpr that defined ahead of those without defexpr
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int default 2, arg2 int, arg3 int default 3) FOR SELECT * FROM tb1 t WHERE a>=(arg1 - arg3);
|
||||
BEGIN
|
||||
OPEN c(2);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
ERROR: not enough values for arguments of cursor "c"
|
||||
LINE 4: OPEN c(2);
|
||||
^
|
||||
QUERY: DECLARE rec RECORD;
|
||||
CURSOR c (arg1 int default 2, arg2 int, arg3 int default 3) FOR SELECT * FROM tb1 t WHERE a>=(arg1 - arg3);
|
||||
BEGIN
|
||||
OPEN c(2);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int default 2, arg2 int, arg3 int default 3) FOR SELECT * FROM tb1 t WHERE a>=(arg1 - arg3);
|
||||
BEGIN
|
||||
OPEN c(5,2);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
NOTICE: 2, b
|
||||
-- cursor arg type mismatch with the defexpr
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
defarg int default 2;
|
||||
CURSOR c (arg1 int default 2, arg2 int default 'arg', arg3 int default 3) FOR SELECT * FROM tb1 t WHERE a>=(arg1 - arg3);
|
||||
BEGIN
|
||||
OPEN c(5,2);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
ERROR: invalid input syntax for integer: "arg"
|
||||
CONTEXT: PL/pgSQL function inline_code_block line 4 during statement block local variable initialization
|
||||
DROP SCHEMA IF EXISTS test_cursor_param_defexpr CASCADE;
|
||||
NOTICE: drop cascades to 3 other objects
|
||||
DETAIL: drop cascades to table tb1
|
||||
drop cascades to type rectype
|
||||
drop cascades to function test_cursor()
|
||||
@ -46,7 +46,7 @@ test: smp
|
||||
test: alter_hw_package
|
||||
test: hw_grant_package gsc_func gsc_db
|
||||
test: uppercase_attribute_name decode_compatible_with_o outerjoin_bugfix
|
||||
test: replace_func_with_two_args trunc_func_for_date nlssort_pinyin updatable_views
|
||||
test: replace_func_with_two_args trunc_func_for_date nlssort_pinyin updatable_views test_cursor_arg_defexpr
|
||||
|
||||
# test multiple statistics
|
||||
test: functional_dependency
|
||||
|
||||
@ -16,7 +16,7 @@ test: hw_smp
|
||||
# test INSERT UPDATE UPSERT
|
||||
#test: insert_update_002 insert_update_003 insert_update_008 insert_update_009 insert_update_010
|
||||
#test: insert_update_001#
|
||||
test: delete update namespace case select_having select_implicit
|
||||
test: delete update namespace case select_having select_implicit test_cursor_arg_defexpr
|
||||
test: hw_test_operate_user multi_update
|
||||
test: hw_createtbl_llt multi_delete
|
||||
#test: gsqlerr#
|
||||
|
||||
167
src/test/regress/sql/test_cursor_arg_defexpr.sql
Normal file
167
src/test/regress/sql/test_cursor_arg_defexpr.sql
Normal file
@ -0,0 +1,167 @@
|
||||
DROP SCHEMA IF EXISTS test_cursor_param_defexpr CASCADE;
|
||||
CREATE SCHEMA test_cursor_param_defexpr;
|
||||
SET CURRENT_SCHEMA TO test_cursor_param_defexpr;
|
||||
|
||||
CREATE TABLE tb1(a int, b char(10));
|
||||
INSERT INTO tb1 VALUES (1,'a'),(2,'b'),(3,'c'),(4,'d'),(5,'e');
|
||||
|
||||
-- regular cursor without defexprs
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c FOR SELECT * FROM tb1 t;
|
||||
BEGIN
|
||||
OPEN c;
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int) FOR SELECT * FROM tb1 t WHERE a>=arg1;
|
||||
BEGIN
|
||||
OPEN c(1);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
|
||||
-- define cursor with defexprs, and open cursor without values specified
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int default 2) FOR SELECT * FROM tb1 t WHERE a>=arg1;
|
||||
BEGIN
|
||||
OPEN c();
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int = 2) FOR SELECT * FROM tb1 t WHERE a>=arg1;
|
||||
BEGIN
|
||||
OPEN c;
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
|
||||
-- default cursor composite type argv
|
||||
CREATE OR REPLACE TYPE rectype AS (a int, b char(10));
|
||||
DECLARE
|
||||
CURSOR c (r rectype default (3,'c')) FOR SELECT * from tb1 where a=r.a;
|
||||
rec RECORD;
|
||||
BEGIN
|
||||
OPEN c;
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
|
||||
DECLARE
|
||||
CURSOR c (r tb1%ROWTYPE default (4,'d')) FOR SELECT * from tb1 where a=r.a;
|
||||
rec RECORD;
|
||||
BEGIN
|
||||
OPEN c;
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
|
||||
-- open cursor with values specified
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int default 2) FOR SELECT * FROM tb1 t WHERE a>=arg1;
|
||||
BEGIN
|
||||
OPEN c(arg1:=1);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
|
||||
-- open cursor in functions
|
||||
CREATE OR REPLACE FUNCTION test_cursor RETURNS int as $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int default 2) FOR SELECT * FROM tb1 WHERE a>=arg1;
|
||||
res INTEGER;
|
||||
BEGIN
|
||||
OPEN c(3);
|
||||
FETCH c INTO rec;
|
||||
res := rec.a;
|
||||
CLOSE c;
|
||||
return res;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
CALL test_cursor();
|
||||
|
||||
-- error situation
|
||||
-- open cursor without value list while having args without defexpr
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int, arg2 int, arg3 int default 3) FOR SELECT * FROM tb1 t WHERE a>=(arg1 - arg3);
|
||||
BEGIN
|
||||
OPEN c;
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
|
||||
-- open cursor without enough values specified
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int, arg2 int, arg3 int default 3) FOR SELECT * FROM tb1 t WHERE a>=(arg1 - arg3);
|
||||
BEGIN
|
||||
OPEN c(1);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
|
||||
-- args with defexpr that defined ahead of those without defexpr
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int default 2, arg2 int, arg3 int default 3) FOR SELECT * FROM tb1 t WHERE a>=(arg1 - arg3);
|
||||
BEGIN
|
||||
OPEN c(2);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
CURSOR c (arg1 int default 2, arg2 int, arg3 int default 3) FOR SELECT * FROM tb1 t WHERE a>=(arg1 - arg3);
|
||||
BEGIN
|
||||
OPEN c(5,2);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
|
||||
-- cursor arg type mismatch with the defexpr
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
defarg int default 2;
|
||||
CURSOR c (arg1 int default 2, arg2 int default 'arg', arg3 int default 3) FOR SELECT * FROM tb1 t WHERE a>=(arg1 - arg3);
|
||||
BEGIN
|
||||
OPEN c(5,2);
|
||||
FETCH c INTO rec;
|
||||
RAISE NOTICE '%, %', rec.a, rec.b;
|
||||
CLOSE c;
|
||||
END;
|
||||
/
|
||||
|
||||
DROP SCHEMA IF EXISTS test_cursor_param_defexpr CASCADE;
|
||||
Reference in New Issue
Block a user