diff --git a/src/common/pl/plpgsql/src/pl_exec.cpp b/src/common/pl/plpgsql/src/pl_exec.cpp index af153151a13b9128147ddd96b1e29aba87c1028d..4874c76a1848426b19d93febc02b77d9c6b0641e 100644 --- a/src/common/pl/plpgsql/src/pl_exec.cpp +++ b/src/common/pl/plpgsql/src/pl_exec.cpp @@ -8967,6 +8967,7 @@ static int exec_stmt_open(PLpgSQL_execstate* estate, PLpgSQL_stmt_open* stmt) char* curname = NULL; PLpgSQL_expr* query = NULL; Portal portal = NULL; + Portal old_portal = NULL; ParamListInfo paramLI = NULL; /* ---------- * Get the cursor variable and if it has an assigned name, check @@ -9009,11 +9010,14 @@ static int exec_stmt_open(PLpgSQL_execstate* estate, PLpgSQL_stmt_open* stmt) } else { curname = TextDatumGetCString(curvar->value); } - if (SPI_cursor_find(curname) != NULL) { - ereport(ERROR, - (errcode(ERRCODE_DUPLICATE_CURSOR), - errmodule(MOD_PLSQL), - errmsg("cursor \"%s\" already in use in OPEN statement.", curname))); + old_portal = SPI_cursor_find(curname); + if (old_portal != NULL) { + SPI_cursor_close(old_portal); + exec_set_isopen(estate, false, stmt->curvar + CURSOR_ISOPEN); + exec_set_cursor_found(estate, PLPGSQL_NULL, stmt->curvar + CURSOR_FOUND); + exec_set_notfound(estate, PLPGSQL_NULL, stmt->curvar + CURSOR_NOTFOUND); + exec_set_rowcount(estate, -1, true, stmt->curvar + CURSOR_ROWCOUNT); + curvar->cursor_closed = true; } } #ifdef ENABLE_MULTIPLE_NODES diff --git a/src/test/regress/expected/cursor_expression.out b/src/test/regress/expected/cursor_expression.out index 1e7b0a4d18b6124e677875f8f369d4737734aa2a..882b49acf387768577991e8e7709a38113d35d3b 100644 --- a/src/test/regress/expected/cursor_expression.out +++ b/src/test/regress/expected/cursor_expression.out @@ -950,6 +950,53 @@ ERROR: syntax error at or near "'abort'" LINE 1: close 'abort'; ^ commit; +drop table if exists employees; +drop table if exists employees2; +create table employees ( + last_name varchar(20), + job_id int +); +create table employees2 ( + age int, + dep_id int +); +insert into employees values ('wang',1), ('hu',2), ('zhou',3); +insert into employees2 values (119,12), (45,21), (51,33); +DECLARE + cv SYS_REFCURSOR; -- cursor variable + v_lastname employees.last_name%TYPE; -- variable for last_name + v_jobid employees.job_id%TYPE; -- variable for job_id + v_age employees2.age%TYPE; + v_depid employees2.dep_id%TYPE; + query_2 VARCHAR2(200) := 'SELECT * FROM employees2 WHERE dep_id = 33'; + v_employees employees%ROWTYPE; -- record variable row of table +BEGIN + OPEN cv FOR + SELECT last_name, job_id FROM employees + WHERE job_id = 1; + LOOP + FETCH cv INTO v_lastname, v_jobid; + EXIT WHEN cv%NOTFOUND; + raise info 'v_lastname is %',v_lastname; + raise info 'v_jobid is %',v_jobid; + END LOOP; + raise info '----------------------------'; + OPEN cv FOR query_2; + LOOP + FETCH cv INTO v_age, v_depid; + EXIT WHEN cv%NOTFOUND; + raise info 'v_age is %',v_age; + raise info 'v_depid is %',v_depid; + END LOOP; + raise info '----------------------------'; +END; +/ +INFO: v_lastname is wang +INFO: v_jobid is 1 +INFO: ---------------------------- +INFO: v_age is 51 +INFO: v_depid is 33 +INFO: ---------------------------- -- clean drop table abort_test; drop table test_insert; diff --git a/src/test/regress/sql/cursor_expression.sql b/src/test/regress/sql/cursor_expression.sql index ac563df18b860867ecc500c890a86639423b867d..d9fa19aa00386a34177dd40cfe8de11b07815a34 100644 --- a/src/test/regress/sql/cursor_expression.sql +++ b/src/test/regress/sql/cursor_expression.sql @@ -557,6 +557,51 @@ cursor 'abort' for select * from abort_test order by 1; close 'abort'; commit; +drop table if exists employees; +drop table if exists employees2; +create table employees ( + last_name varchar(20), + job_id int +); +create table employees2 ( + age int, + dep_id int +); + +insert into employees values ('wang',1), ('hu',2), ('zhou',3); +insert into employees2 values (119,12), (45,21), (51,33); + +DECLARE + cv SYS_REFCURSOR; -- cursor variable + + v_lastname employees.last_name%TYPE; -- variable for last_name + v_jobid employees.job_id%TYPE; -- variable for job_id + v_age employees2.age%TYPE; + v_depid employees2.dep_id%TYPE; + query_2 VARCHAR2(200) := 'SELECT * FROM employees2 WHERE dep_id = 33'; + v_employees employees%ROWTYPE; -- record variable row of table +BEGIN + OPEN cv FOR + SELECT last_name, job_id FROM employees + WHERE job_id = 1; + LOOP + FETCH cv INTO v_lastname, v_jobid; + EXIT WHEN cv%NOTFOUND; + raise info 'v_lastname is %',v_lastname; + raise info 'v_jobid is %',v_jobid; + END LOOP; + raise info '----------------------------'; + OPEN cv FOR query_2; + LOOP + FETCH cv INTO v_age, v_depid; + EXIT WHEN cv%NOTFOUND; + raise info 'v_age is %',v_age; + raise info 'v_depid is %',v_depid; + END LOOP; + raise info '----------------------------'; +END; +/ + -- clean drop table abort_test; drop table test_insert;