禁止插入值为record不禁止插入值为row
This commit is contained in:
@ -449,6 +449,10 @@ Expr* transformAssignedExpr(ParseState* pstate, Expr* expr, ParseExprKind exprKi
|
||||
checkArrayTypeInsert(pstate, expr);
|
||||
}
|
||||
|
||||
if (IsA(expr, Param) && DISABLE_RECORD_TYPE_IN_DML && type_id == RECORDOID) {
|
||||
ereport(ERROR, (errcode(ERRCODE_PLPGSQL_ERROR),
|
||||
errmsg("The record type variable cannot be used as an insertion value.")));
|
||||
}
|
||||
ELOG_FIELD_NAME_START(colname);
|
||||
|
||||
/*
|
||||
|
||||
@ -397,7 +397,8 @@ static const struct behavior_compat_entry behavior_compat_options[OPT_MAX] = {
|
||||
{"update_unusable_unique_index_on_iud", OPT_UPDATE_UNUSABLE_UNIQUE_INDEX_ON_IUD},
|
||||
{"prefer_parse_cursor_parentheses_as_expr", OPT_PREFER_PARSE_CURSOR_PARENTHESES_AS_EXPR},
|
||||
{"update_global_index_on_partition_change", OPT_UPDATE_GLOBAL_INDEX_ON_PARTITION_CHANGE},
|
||||
{"float_as_numeric", OPT_FLOAT_AS_NUMERIC}
|
||||
{"float_as_numeric", OPT_FLOAT_AS_NUMERIC},
|
||||
{"disable_record_type_in_dml", OPT_DISABLE_RECORD_TYPE_IN_DML}
|
||||
};
|
||||
|
||||
// increase SQL_IGNORE_STRATEGY_NUM if we need more strategy
|
||||
|
||||
@ -223,7 +223,8 @@ extern bool contain_backend_version(uint32 version_number);
|
||||
#define OPT_PREFER_PARSE_CURSOR_PARENTHESES_AS_EXPR (1LL << 31)
|
||||
#define OPT_UPDATE_GLOBAL_INDEX_ON_PARTITION_CHANGE (1LL << 32)
|
||||
#define OPT_FLOAT_AS_NUMERIC (1LL << 33)
|
||||
#define OPT_MAX 34
|
||||
#define OPT_DISABLE_RECORD_TYPE_IN_DML (1LL << 34)
|
||||
#define OPT_MAX 35
|
||||
|
||||
#define PLPSQL_OPT_FOR_LOOP 1
|
||||
#define PLPSQL_OPT_OUTPARAM 2
|
||||
@ -271,6 +272,7 @@ extern bool contain_backend_version(uint32 version_number);
|
||||
#define PREFER_PARSE_CURSOR_PARENTHESES_AS_EXPR (u_sess->utils_cxt.behavior_compat_flags & OPT_PREFER_PARSE_CURSOR_PARENTHESES_AS_EXPR)
|
||||
#define UPDATE_GLOBAL_INDEX_ON_PARTITION_CHANGE (u_sess->utils_cxt.behavior_compat_flags & OPT_UPDATE_GLOBAL_INDEX_ON_PARTITION_CHANGE)
|
||||
#define FLOAT_AS_NUMERIC (u_sess->utils_cxt.behavior_compat_flags & OPT_FLOAT_AS_NUMERIC)
|
||||
#define DISABLE_RECORD_TYPE_IN_DML (u_sess->utils_cxt.behavior_compat_flags & OPT_DISABLE_RECORD_TYPE_IN_DML)
|
||||
|
||||
/* define database compatibility Attribute */
|
||||
typedef struct {
|
||||
|
||||
@ -64,7 +64,154 @@ END;
|
||||
/
|
||||
NOTICE: Result: (,,,,,)
|
||||
drop table test_2 cascade;
|
||||
set behavior_compat_options='allow_procedure_compile_check';
|
||||
set behavior_compat_options='allow_procedure_compile_check,disable_record_type_in_dml';
|
||||
-- Prohibit virtual column insertion
|
||||
create table t1(col1 varchar(10),col varchar(10));
|
||||
create table t2(col1 varchar(10),col varchar(10));
|
||||
insert into t1 values('one','two');
|
||||
declare
|
||||
cursor cur1 is select * from t1;
|
||||
source cur1%rowtype:=('ten','wtu');
|
||||
begin
|
||||
for source in cur1
|
||||
loop
|
||||
raise notice '%',source;
|
||||
insert into t2 values(source.col1, source.col);
|
||||
end loop;
|
||||
end;
|
||||
/
|
||||
NOTICE: (one,two)
|
||||
insert into t1 values('one','two');
|
||||
declare
|
||||
cursor cur1 is select * from t1;
|
||||
source cur1%rowtype:=('ten','wtu');
|
||||
begin
|
||||
for source in cur1
|
||||
loop
|
||||
raise notice '%',source;
|
||||
insert into t2 values(source);
|
||||
end loop;
|
||||
end;
|
||||
/
|
||||
NOTICE: (one,two)
|
||||
ERROR: The record type variable cannot be used as an insertion value.
|
||||
CONTEXT: SQL statement "insert into t2 values(source)"
|
||||
PL/pgSQL function inline_code_block line 7 at SQL statement
|
||||
select * from t2;
|
||||
col1 | col
|
||||
------+-----
|
||||
one | two
|
||||
(1 row)
|
||||
|
||||
drop table t1;
|
||||
drop table t2;
|
||||
create table t1 (a int);
|
||||
create table t2 (a t1);
|
||||
declare
|
||||
source t2%rowtype;
|
||||
begin
|
||||
insert into t2 values(source.a);
|
||||
end;
|
||||
/
|
||||
declare
|
||||
source t2%rowtype;
|
||||
begin
|
||||
update t2 set a = source;
|
||||
end;
|
||||
/
|
||||
ERROR: column "a" is of type t1 but expression is of type t2
|
||||
LINE 1: update t2 set a = source
|
||||
^
|
||||
HINT: You will need to rewrite or cast the expression.
|
||||
QUERY: update t2 set a = source
|
||||
CONTEXT: referenced column: a
|
||||
PL/pgSQL function inline_code_block line 3 at SQL statement
|
||||
declare
|
||||
source t2%rowtype;
|
||||
begin
|
||||
update t2 set a = source.a;
|
||||
end;
|
||||
/
|
||||
drop table t2;
|
||||
drop table t1;
|
||||
-- Prohibit virtual column insertion
|
||||
create table t1(col1 varchar(10), col2 int, col3 varchar(10), col4 varchar(10));
|
||||
insert into t1 values('one',5,'dsa','e');
|
||||
insert into t1 values('two',7,'daw','d');
|
||||
insert into t1 values('three',7,'dsaw','sw');
|
||||
insert into t1 values(NULL);
|
||||
create table t2(col1 varchar(10), col2 int, col3 varchar(10), col4 varchar(10));
|
||||
declare
|
||||
cursor cur1 is select * from t1;
|
||||
source cur1%rowtype;
|
||||
begin
|
||||
for source in cur1
|
||||
loop
|
||||
raise notice '%',source;
|
||||
insert into t2 values('o', 5, source.col4, source.col1);
|
||||
end loop;
|
||||
end;
|
||||
/
|
||||
NOTICE: (one,5,dsa,e)
|
||||
NOTICE: (two,7,daw,d)
|
||||
NOTICE: (three,7,dsaw,sw)
|
||||
NOTICE: (,,,)
|
||||
declare
|
||||
cursor cur1 is select * from t1;
|
||||
source cur1%rowtype;
|
||||
begin
|
||||
for source in cur1
|
||||
loop
|
||||
raise notice '%',source;
|
||||
insert into t2 values('o', 5, source.col4, source);
|
||||
end loop;
|
||||
end;
|
||||
/
|
||||
NOTICE: (one,5,dsa,e)
|
||||
ERROR: The record type variable cannot be used as an insertion value.
|
||||
CONTEXT: SQL statement "insert into t2 values('o', 5, source.col4, source)"
|
||||
PL/pgSQL function inline_code_block line 7 at SQL statement
|
||||
declare
|
||||
cursor cur1 is select * from t1;
|
||||
source cur1%rowtype;
|
||||
begin
|
||||
for source in cur1
|
||||
loop
|
||||
raise notice '%',source;
|
||||
insert into t2 values('o', 5, source, source.col1);
|
||||
end loop;
|
||||
end;
|
||||
/
|
||||
NOTICE: (one,5,dsa,e)
|
||||
ERROR: The record type variable cannot be used as an insertion value.
|
||||
CONTEXT: SQL statement "insert into t2 values('o', 5, source, source.col1)"
|
||||
PL/pgSQL function inline_code_block line 7 at SQL statement
|
||||
declare
|
||||
cursor cur1 is select * from t1;
|
||||
source cur1%rowtype;
|
||||
begin
|
||||
for source in cur1
|
||||
loop
|
||||
raise notice '%',source;
|
||||
insert into t2 values(source);
|
||||
end loop;
|
||||
end;
|
||||
/
|
||||
NOTICE: (one,5,dsa,e)
|
||||
ERROR: The record type variable cannot be used as an insertion value.
|
||||
CONTEXT: SQL statement "insert into t2 values(source)"
|
||||
PL/pgSQL function inline_code_block line 7 at SQL statement
|
||||
select * from t2;
|
||||
col1 | col2 | col3 | col4
|
||||
------+------+------+-------
|
||||
o | 5 | e | one
|
||||
o | 5 | d | two
|
||||
o | 5 | sw | three
|
||||
o | 5 | |
|
||||
(4 rows)
|
||||
|
||||
drop table t1;
|
||||
drop table t2;
|
||||
create table emp (empno int, ename varchar(10), job varchar(10));
|
||||
insert into emp values (1, 'zhangsan', 'job1');
|
||||
insert into emp values (2, 'lisi', 'job2');
|
||||
@ -1060,9 +1207,9 @@ drop procedure pro_cs_trans_1;
|
||||
drop table cs_trans_1;
|
||||
-- test for rec in cursor loop
|
||||
show behavior_compat_options;
|
||||
behavior_compat_options
|
||||
-------------------------------
|
||||
allow_procedure_compile_check
|
||||
behavior_compat_options
|
||||
----------------------------------------------------------
|
||||
allow_procedure_compile_check,disable_record_type_in_dml
|
||||
(1 row)
|
||||
|
||||
create table test_table(col1 varchar2(10));
|
||||
@ -2429,7 +2576,7 @@ BEGIN
|
||||
END;
|
||||
/
|
||||
ERROR: "source.oid" is not a known variable
|
||||
--?.*
|
||||
LINE 10: source.oid := 5;
|
||||
^
|
||||
QUERY: DECLARE
|
||||
CURSOR c IS
|
||||
|
||||
@ -68,7 +68,125 @@ END;
|
||||
|
||||
drop table test_2 cascade;
|
||||
|
||||
set behavior_compat_options='allow_procedure_compile_check';
|
||||
set behavior_compat_options='allow_procedure_compile_check,disable_record_type_in_dml';
|
||||
|
||||
-- Prohibit virtual column insertion
|
||||
create table t1(col1 varchar(10),col varchar(10));
|
||||
create table t2(col1 varchar(10),col varchar(10));
|
||||
insert into t1 values('one','two');
|
||||
declare
|
||||
cursor cur1 is select * from t1;
|
||||
source cur1%rowtype:=('ten','wtu');
|
||||
begin
|
||||
for source in cur1
|
||||
loop
|
||||
raise notice '%',source;
|
||||
insert into t2 values(source.col1, source.col);
|
||||
end loop;
|
||||
end;
|
||||
/
|
||||
|
||||
insert into t1 values('one','two');
|
||||
declare
|
||||
cursor cur1 is select * from t1;
|
||||
source cur1%rowtype:=('ten','wtu');
|
||||
begin
|
||||
for source in cur1
|
||||
loop
|
||||
raise notice '%',source;
|
||||
insert into t2 values(source);
|
||||
end loop;
|
||||
end;
|
||||
/
|
||||
select * from t2;
|
||||
drop table t1;
|
||||
drop table t2;
|
||||
|
||||
create table t1 (a int);
|
||||
create table t2 (a t1);
|
||||
declare
|
||||
source t2%rowtype;
|
||||
begin
|
||||
insert into t2 values(source.a);
|
||||
end;
|
||||
/
|
||||
|
||||
declare
|
||||
source t2%rowtype;
|
||||
begin
|
||||
update t2 set a = source;
|
||||
end;
|
||||
/
|
||||
|
||||
declare
|
||||
source t2%rowtype;
|
||||
begin
|
||||
update t2 set a = source.a;
|
||||
end;
|
||||
/
|
||||
|
||||
drop table t2;
|
||||
drop table t1;
|
||||
|
||||
-- Prohibit virtual column insertion
|
||||
create table t1(col1 varchar(10), col2 int, col3 varchar(10), col4 varchar(10));
|
||||
insert into t1 values('one',5,'dsa','e');
|
||||
insert into t1 values('two',7,'daw','d');
|
||||
insert into t1 values('three',7,'dsaw','sw');
|
||||
insert into t1 values(NULL);
|
||||
|
||||
create table t2(col1 varchar(10), col2 int, col3 varchar(10), col4 varchar(10));
|
||||
|
||||
declare
|
||||
cursor cur1 is select * from t1;
|
||||
source cur1%rowtype;
|
||||
begin
|
||||
for source in cur1
|
||||
loop
|
||||
raise notice '%',source;
|
||||
insert into t2 values('o', 5, source.col4, source.col1);
|
||||
end loop;
|
||||
end;
|
||||
/
|
||||
|
||||
declare
|
||||
cursor cur1 is select * from t1;
|
||||
source cur1%rowtype;
|
||||
begin
|
||||
for source in cur1
|
||||
loop
|
||||
raise notice '%',source;
|
||||
insert into t2 values('o', 5, source.col4, source);
|
||||
end loop;
|
||||
end;
|
||||
/
|
||||
|
||||
declare
|
||||
cursor cur1 is select * from t1;
|
||||
source cur1%rowtype;
|
||||
begin
|
||||
for source in cur1
|
||||
loop
|
||||
raise notice '%',source;
|
||||
insert into t2 values('o', 5, source, source.col1);
|
||||
end loop;
|
||||
end;
|
||||
/
|
||||
|
||||
declare
|
||||
cursor cur1 is select * from t1;
|
||||
source cur1%rowtype;
|
||||
begin
|
||||
for source in cur1
|
||||
loop
|
||||
raise notice '%',source;
|
||||
insert into t2 values(source);
|
||||
end loop;
|
||||
end;
|
||||
/
|
||||
select * from t2;
|
||||
drop table t1;
|
||||
drop table t2;
|
||||
|
||||
create table emp (empno int, ename varchar(10), job varchar(10));
|
||||
insert into emp values (1, 'zhangsan', 'job1');
|
||||
@ -1837,4 +1955,4 @@ delete from employees;
|
||||
call f1(2);
|
||||
|
||||
set current_schema=public;
|
||||
drop schema cursor_rowtype cascade;
|
||||
drop schema cursor_rowtype cascade;
|
||||
|
||||
Reference in New Issue
Block a user