强游标

This commit is contained in:
pulsar
2024-03-26 17:18:32 +08:00
committed by yaoxin
parent 814908724a
commit 6b8c910168
3 changed files with 201 additions and 3 deletions

View File

@ -354,7 +354,7 @@ static void processFunctionRecordOutParam(int varno, Oid funcoid, int* outparam)
%type <list> decl_varname_list %type <list> decl_varname_list
%type <boolean> decl_const decl_notnull exit_type %type <boolean> decl_const decl_notnull exit_type
%type <expr> decl_defval decl_rec_defval decl_cursor_query %type <expr> decl_defval decl_rec_defval decl_cursor_query
%type <dtype> decl_datatype %type <dtype> decl_datatype opt_cursor_returntype
%type <oid> decl_collate %type <oid> decl_collate
%type <datum> decl_cursor_args %type <datum> decl_cursor_args
%type <list> decl_cursor_arglist assign_list %type <list> decl_cursor_arglist assign_list
@ -1355,7 +1355,7 @@ decl_statement : decl_varname_list decl_const decl_datatype decl_collate decl_no
pfree_ext($2->name); pfree_ext($2->name);
pfree($2); pfree($2);
} }
| K_TYPE decl_varname as_is K_REF K_CURSOR ';' | K_TYPE decl_varname as_is K_REF K_CURSOR opt_cursor_returntype ';'
{ {
IsInPublicNamespace($2->name); IsInPublicNamespace($2->name);
/* add name of cursor type to PLPGSQL_NSTYPE_REFCURSOR */ /* add name of cursor type to PLPGSQL_NSTYPE_REFCURSOR */
@ -2347,6 +2347,31 @@ cursor_in_out_option : K_IN |
/* empty */ /* empty */
; ;
opt_cursor_returntype: /* empty */
{
$$ = NULL;
}
| K_RETURN decl_datatype
{
if (u_sess->attr.attr_sql.sql_compatibility != A_FORMAT) {
const char* message = "cursor return type is only supposed in A compatibility";
InsertErrorMessage(message, plpgsql_yylloc);
ereport(errstate,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("cursor return type is only supposed in A compatibility")));
}
if ($2->dtype != PLPGSQL_DTYPE_RECORD_TYPE && $2->typinput.fn_oid != F_RECORD_IN) {
const char* message = "invalid cursor return type";
InsertErrorMessage(message, plpgsql_yylloc);
ereport(errstate,
(errcode(ERRCODE_SYNTAX_ERROR),
errmsg("invalid cursor return type; %s must be a record type", $2->typname)));
}
$$ = $2;
}
;
decl_is_for : K_IS | /* A db */ decl_is_for : K_IS | /* A db */
K_FOR; /* SQL standard */ K_FOR; /* SQL standard */

View File

@ -370,9 +370,101 @@ NOTICE: SQL%ROWCOUNT :NULL
(1 row) (1 row)
--test strong cursor
create table tb1(a int);
create table tb2(a int, b text);
insert into tb1 values(1);
insert into tb2 values(1,'one'),(2,'two');
declare
type cur1 is ref cursor return record;
var cur1;
begin
open var for select * from tb1;
end;
/
declare
type cur1 is ref cursor return;
begin
null;
end;
/
ERROR: missing data type declaration
LINE 1: DECLARE type cur1 is ref cursor return;
^
QUERY: DECLARE type cur1 is ref cursor return;
begin
null;
end
declare
type cur1 is ref cursor return int[];
begin
null;
end;
/
ERROR: invalid cursor return type; _int4 must be a record type
CONTEXT: compilation of PL/pgSQL function "inline_code_block" near line 1
create type typ1_rec as (a int, b text);
declare
type cur1 is ref cursor return typ1_rec;
begin
null;
end;
/
drop type typ1_rec;
--use in function
create or replace function func1() return int as
declare
type cur1 is ref cursor return tb1%rowtype;
var cur1;
res int;
begin
open var for select * from tb1;
fetch var into res;
return res;
end;
/
call func1();
func1
-------
1
(1 row)
drop function func1;
--use in package
create or replace package pkg1 as
type typ1 is record(a int, b text);
type cur1 is ref cursor return typ1;
procedure proc1(a inout cur1);
end pkg1;
/
create or replace package body pkg1 as
procedure proc1(a inout cur1) is
declare
var cur1;
res record;
begin
open var for select * from tb2;
fetch var into res;
raise info 'res = %',res;
end;
end pkg1;
/
declare
var pkg1.cur1;
begin
pkg1.proc1(var);
end;
/
INFO: res = (1,one)
CONTEXT: SQL statement "CALL pkg1.proc1(var)"
PL/pgSQL function inline_code_block line 3 at SQL statement
drop package pkg1;
NOTICE: drop cascades to function hw_cursor_part4.proc1(refcursor)
DROP schema hw_cursor_part4 CASCADE; DROP schema hw_cursor_part4 CASCADE;
NOTICE: drop cascades to 4 other objects NOTICE: drop cascades to 6 other objects
DETAIL: drop cascades to table tbl_rcwscfg DETAIL: drop cascades to table tbl_rcwscfg
drop cascades to table tbl_temp_module_312 drop cascades to table tbl_temp_module_312
drop cascades to function test_temp() drop cascades to function test_temp()
drop cascades to function test_crs_rpt_emptysor(integer) drop cascades to function test_crs_rpt_emptysor(integer)
drop cascades to table tb1
drop cascades to table tb2

View File

@ -295,5 +295,86 @@ END;
CALL TEST_CRS_RPT_EMPTYSOR(0); CALL TEST_CRS_RPT_EMPTYSOR(0);
CALL TEST_CRS_RPT_EMPTYSOR(1); CALL TEST_CRS_RPT_EMPTYSOR(1);
--test strong cursor
create table tb1(a int);
create table tb2(a int, b text);
insert into tb1 values(1);
insert into tb2 values(1,'one'),(2,'two');
declare
type cur1 is ref cursor return record;
var cur1;
begin
open var for select * from tb1;
end;
/
declare
type cur1 is ref cursor return;
begin
null;
end;
/
declare
type cur1 is ref cursor return int[];
begin
null;
end;
/
create type typ1_rec as (a int, b text);
declare
type cur1 is ref cursor return typ1_rec;
begin
null;
end;
/
drop type typ1_rec;
--use in function
create or replace function func1() return int as
declare
type cur1 is ref cursor return tb1%rowtype;
var cur1;
res int;
begin
open var for select * from tb1;
fetch var into res;
return res;
end;
/
call func1();
drop function func1;
--use in package
create or replace package pkg1 as
type typ1 is record(a int, b text);
type cur1 is ref cursor return typ1;
procedure proc1(a inout cur1);
end pkg1;
/
create or replace package body pkg1 as
procedure proc1(a inout cur1) is
declare
var cur1;
res record;
begin
open var for select * from tb2;
fetch var into res;
raise info 'res = %',res;
end;
end pkg1;
/
declare
var pkg1.cur1;
begin
pkg1.proc1(var);
end;
/
drop package pkg1;
DROP schema hw_cursor_part4 CASCADE; DROP schema hw_cursor_part4 CASCADE;