!2598 修复基于外表的视图更新的check option不生效的问题
Merge pull request !2598 from chenxiaobin/fixFdwCheckOption
This commit is contained in:
@ -121,7 +121,7 @@ static bool foreign_expr_walker(Node *node, foreign_glob_cxt *glob_cxt, foreign_
|
||||
static void deparseTargetList(StringInfo buf, RangeTblEntry *rte, Index rtindex, Relation rel, bool is_returning,
|
||||
Bitmapset *attrs_used, bool qualify_col, List **retrieved_attrs);
|
||||
static void deparseReturningList(StringInfo buf, RangeTblEntry *root, Index rtindex, Relation rel, bool trig_after_row,
|
||||
List *returningList, List **retrieved_attrs);
|
||||
List *withCheckOptionList, List *returningList, List **retrieved_attrs);
|
||||
static void deparseColumnRef(StringInfo buf, int varno, int varattno, RangeTblEntry *rte, bool qualify_col);
|
||||
static void deparseRelation(StringInfo buf, Relation rel);
|
||||
static void deparseStringLiteral(StringInfo buf, const char *val);
|
||||
@ -1844,11 +1844,11 @@ static void deparseRangeTblRef(StringInfo buf, PlannerInfo *root, RelOptInfo *fo
|
||||
* deparse remote INSERT statement
|
||||
*
|
||||
* The statement text is appended to buf, and we also create an integer List
|
||||
* of the columns being retrieved by RETURNING (if any), which is returned
|
||||
* to *retrieved_attrs.
|
||||
* of the columns being retrieved by WITH CHECK OPTION or RETURNING (if any),
|
||||
* which is returned to *retrieved_attrs.
|
||||
*/
|
||||
void deparseInsertSql(StringInfo buf, RangeTblEntry *rte, Index rtindex, Relation rel, List *targetAttrs,
|
||||
List *returningList, List **retrieved_attrs)
|
||||
List *withCheckOptionList, List *returningList, List **retrieved_attrs)
|
||||
{
|
||||
AttrNumber pindex;
|
||||
ListCell *lc = NULL;
|
||||
@ -1890,19 +1890,19 @@ void deparseInsertSql(StringInfo buf, RangeTblEntry *rte, Index rtindex, Relatio
|
||||
appendStringInfoString(buf, " DEFAULT VALUES");
|
||||
}
|
||||
|
||||
deparseReturningList(buf, rte, rtindex, rel, rel->trigdesc && rel->trigdesc->trig_insert_after_row, returningList,
|
||||
retrieved_attrs);
|
||||
deparseReturningList(buf, rte, rtindex, rel, rel->trigdesc && rel->trigdesc->trig_insert_after_row,
|
||||
withCheckOptionList, returningList, retrieved_attrs);
|
||||
}
|
||||
|
||||
/*
|
||||
* deparse remote UPDATE statement
|
||||
*
|
||||
* The statement text is appended to buf, and we also create an integer List
|
||||
* of the columns being retrieved by RETURNING (if any), which is returned
|
||||
* to *retrieved_attrs.
|
||||
* of the columns being retrieved by WITH CHECK OPTION or RETURNING (if any),
|
||||
* which is returned to *retrieved_attrs.
|
||||
*/
|
||||
void deparseUpdateSql(StringInfo buf, RangeTblEntry *rte, Index rtindex, Relation rel, List *targetAttrs,
|
||||
List *returningList, List **retrieved_attrs)
|
||||
List *withCheckOptionList, List *returningList, List **retrieved_attrs)
|
||||
{
|
||||
AttrNumber pindex;
|
||||
ListCell *lc = NULL;
|
||||
@ -1927,8 +1927,8 @@ void deparseUpdateSql(StringInfo buf, RangeTblEntry *rte, Index rtindex, Relatio
|
||||
}
|
||||
appendStringInfoString(buf, " WHERE ctid = $1 and tableoid = $2");
|
||||
|
||||
deparseReturningList(buf, rte, rtindex, rel, rel->trigdesc && rel->trigdesc->trig_update_after_row, returningList,
|
||||
retrieved_attrs);
|
||||
deparseReturningList(buf, rte, rtindex, rel, rel->trigdesc && rel->trigdesc->trig_update_after_row,
|
||||
withCheckOptionList, returningList, retrieved_attrs);
|
||||
}
|
||||
|
||||
/*
|
||||
@ -1945,15 +1945,15 @@ void deparseDeleteSql(StringInfo buf, RangeTblEntry *rte, Index rtindex, Relatio
|
||||
deparseRelation(buf, rel);
|
||||
appendStringInfoString(buf, " WHERE ctid = $1 and tableoid = $2");
|
||||
|
||||
deparseReturningList(buf, rte, rtindex, rel, rel->trigdesc && rel->trigdesc->trig_delete_after_row, returningList,
|
||||
retrieved_attrs);
|
||||
deparseReturningList(buf, rte, rtindex, rel, rel->trigdesc && rel->trigdesc->trig_delete_after_row, NIL,
|
||||
returningList, retrieved_attrs);
|
||||
}
|
||||
|
||||
/*
|
||||
* Add a RETURNING clause, if needed, to an INSERT/UPDATE/DELETE.
|
||||
*/
|
||||
static void deparseReturningList(StringInfo buf, RangeTblEntry *rte, Index rtindex, Relation rel, bool trig_after_row,
|
||||
List *returningList, List **retrieved_attrs)
|
||||
List *withCheckOptionList, List *returningList, List **retrieved_attrs)
|
||||
{
|
||||
Bitmapset *attrs_used = NULL;
|
||||
|
||||
@ -1962,6 +1962,19 @@ static void deparseReturningList(StringInfo buf, RangeTblEntry *rte, Index rtind
|
||||
attrs_used = bms_make_singleton(0 - FirstLowInvalidHeapAttributeNumber);
|
||||
}
|
||||
|
||||
if (withCheckOptionList != NIL) {
|
||||
/*
|
||||
* We need the attrs, non-system and system, mentioned in the local
|
||||
* query's WITH CHECK OPTION list.
|
||||
*
|
||||
* Note: we do this to ensure that WCO constraints will be evaluated
|
||||
* on the data actually inserted/updated on the remote side, which
|
||||
* might differ from the data supplied by the core code, for example
|
||||
* as a result of remote triggers.
|
||||
*/
|
||||
pull_varattnos((Node*)withCheckOptionList, rtindex, &attrs_used);
|
||||
}
|
||||
|
||||
if (returningList != NIL) {
|
||||
/*
|
||||
* We need the attrs, non-system and system, mentioned in the local
|
||||
|
||||
@ -8381,22 +8381,348 @@ UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
|
||||
ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
|
||||
ERROR: constraint "ft1_c2negative" of relation "ft1" does not exist
|
||||
-- ======================================================================================================================================
|
||||
-- TEST-MODULE: WITH CHECK OPTION constraints
|
||||
-- TEST-MODULE: IUD VIEW and WITH CHECK OPTION constraints
|
||||
-- --------------------------------------
|
||||
-- openGauss not support WITH CHECK OPTION, so this test module is unuseful and cannot be fixed, remove it.
|
||||
-- ======================================================================================================================================
|
||||
CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
|
||||
CREATE TABLE base_tbl (a int, b int);
|
||||
CREATE TABLE base_tbl (id int, a int, b int);
|
||||
ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
|
||||
CREATE FOREIGN TABLE foreign_tbl (id int, a int, b int) SERVER loopback OPTIONS (table_name 'base_tbl');
|
||||
CREATE VIEW rw_view1 AS SELECT * FROM foreign_tbl WHERE a < b and id = 1;
|
||||
CREATE VIEW rw_view2 AS SELECT * FROM foreign_tbl WHERE a < b and id = 2 WITH CHECK OPTION;
|
||||
\d+ rw_view1
|
||||
View "public.rw_view1"
|
||||
Column | Type | Modifiers | Storage | Description
|
||||
--------+---------+-----------+---------+-------------
|
||||
id | integer | | plain |
|
||||
a | integer | | plain |
|
||||
b | integer | | plain |
|
||||
View definition:
|
||||
SELECT *
|
||||
FROM foreign_tbl
|
||||
WHERE foreign_tbl.a < foreign_tbl.b AND foreign_tbl.id = 1;
|
||||
|
||||
\d+ rw_view2
|
||||
View "public.rw_view2"
|
||||
Column | Type | Modifiers | Storage | Description
|
||||
--------+---------+-----------+---------+-------------
|
||||
id | integer | | plain |
|
||||
a | integer | | plain |
|
||||
b | integer | | plain |
|
||||
View definition:
|
||||
SELECT *
|
||||
FROM foreign_tbl
|
||||
WHERE foreign_tbl.a < foreign_tbl.b AND foreign_tbl.id = 2;
|
||||
Options: check_option=cascaded
|
||||
|
||||
CREATE OR REPLACE FUNCTION checkdata(out tbname text, out id int, out a int, out b int) RETURNS SETOF record as $$
|
||||
select * from (
|
||||
(select 'rw_view1', * from rw_view1 where id = 1) union all
|
||||
(select 'rw_view2', * from rw_view2 where id = 2) union all
|
||||
(select 'base_tbl', * from base_tbl) union all
|
||||
(select 'foreign_tbl', * from foreign_tbl)
|
||||
) data(tbname, id, a, b)
|
||||
order by 1,2,3,4;
|
||||
$$ language sql;
|
||||
-- simple case
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 0, 5); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 1, 0, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view1 VALUES (1, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 10, 5); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 1, 10, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view1 VALUES (1, 10, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 5); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 2, 0, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 10, 5); -- should failed
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 2, 10, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view2 VALUES (2, 10, 5);
|
||||
ERROR: new row violates WITH CHECK OPTION for view "rw_view2"
|
||||
DETAIL: Failing row contains (2, 10, 5).
|
||||
select * from checkdata();
|
||||
tbname | id | a | b
|
||||
-------------+----+----+---
|
||||
base_tbl | 1 | 0 | 5
|
||||
base_tbl | 1 | 10 | 5
|
||||
base_tbl | 2 | 0 | 5
|
||||
foreign_tbl | 1 | 0 | 5
|
||||
foreign_tbl | 1 | 10 | 5
|
||||
foreign_tbl | 2 | 0 | 5
|
||||
rw_view1 | 1 | 0 | 5
|
||||
rw_view2 | 2 | 0 | 5
|
||||
(8 rows)
|
||||
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 20 where id = 1; -- should success
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a + 20), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
Seq Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 1))
|
||||
|
||||
(12 rows)
|
||||
|
||||
UPDATE rw_view1 SET a = a + 20 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a + 20 where id = 2; -- should failed
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a + 20), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
Seq Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 2))
|
||||
|
||||
(12 rows)
|
||||
|
||||
UPDATE rw_view2 SET a = a + 20 where id = 2;
|
||||
ERROR: new row violates WITH CHECK OPTION for view "rw_view2"
|
||||
DETAIL: Failing row contains (2, 20, 5).
|
||||
select * from checkdata();
|
||||
tbname | id | a | b
|
||||
-------------+----+----+---
|
||||
base_tbl | 1 | 10 | 5
|
||||
base_tbl | 1 | 20 | 5
|
||||
base_tbl | 2 | 0 | 5
|
||||
foreign_tbl | 1 | 10 | 5
|
||||
foreign_tbl | 1 | 20 | 5
|
||||
foreign_tbl | 2 | 0 | 5
|
||||
rw_view2 | 2 | 0 | 5
|
||||
(7 rows)
|
||||
|
||||
insert into base_tbl values(1,100,99),(2,100,99);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) delete from rw_view1 where id = 1;
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------------------------------------------------------------------
|
||||
Delete on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
Seq Scan on public.base_tbl
|
||||
Output: ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 1))
|
||||
|
||||
(12 rows)
|
||||
|
||||
delete from rw_view1 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) delete from rw_view2 where id = 2;
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------------------------------------------------------------------
|
||||
Delete on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
Seq Scan on public.base_tbl
|
||||
Output: ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 2))
|
||||
|
||||
(12 rows)
|
||||
|
||||
delete from rw_view2 where id = 2;
|
||||
select * from checkdata();
|
||||
tbname | id | a | b
|
||||
-------------+----+-----+----
|
||||
base_tbl | 1 | 10 | 5
|
||||
base_tbl | 1 | 20 | 5
|
||||
base_tbl | 1 | 100 | 99
|
||||
base_tbl | 2 | 100 | 99
|
||||
foreign_tbl | 1 | 10 | 5
|
||||
foreign_tbl | 1 | 20 | 5
|
||||
foreign_tbl | 1 | 100 | 99
|
||||
foreign_tbl | 2 | 100 | 99
|
||||
(8 rows)
|
||||
|
||||
delete from base_tbl;
|
||||
-- with trigger
|
||||
CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
|
||||
CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
|
||||
CREATE FOREIGN TABLE foreign_tbl (a int, b int)
|
||||
SERVER loopback OPTIONS (table_name 'base_tbl');
|
||||
-- CREATE VIEW rw_view AS SELECT * FROM foreign_tbl
|
||||
-- WHERE a < b WITH CHECK OPTION;
|
||||
-- \d+ rw_view
|
||||
DROP FOREIGN TABLE foreign_tbl CASCADE;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 0, 5); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 1, 0, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view1 VALUES (1, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 0, 16); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 1, 0, 16
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view1 VALUES (1, 0, 16);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 5); -- should failed
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 2, 0, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 5);
|
||||
ERROR: new row violates WITH CHECK OPTION for view "rw_view2"
|
||||
DETAIL: Failing row contains (2, 10, 5).
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 16); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 2, 0, 16
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 16);
|
||||
select * from checkdata();
|
||||
tbname | id | a | b
|
||||
-------------+----+----+----
|
||||
base_tbl | 1 | 10 | 5
|
||||
base_tbl | 1 | 10 | 16
|
||||
base_tbl | 2 | 10 | 16
|
||||
foreign_tbl | 1 | 10 | 5
|
||||
foreign_tbl | 1 | 10 | 16
|
||||
foreign_tbl | 2 | 10 | 16
|
||||
rw_view1 | 1 | 10 | 16
|
||||
rw_view2 | 2 | 10 | 16
|
||||
(8 rows)
|
||||
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a - 1 where id = 1;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a - 1), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
Seq Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 1))
|
||||
|
||||
(12 rows)
|
||||
|
||||
UPDATE rw_view1 SET a = a - 1 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 1 where id = 1;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a + 1), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
Seq Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 1))
|
||||
|
||||
(12 rows)
|
||||
|
||||
UPDATE rw_view1 SET a = a + 1 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a - 10 where id = 2;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a - 10), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
Seq Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 2))
|
||||
|
||||
(12 rows)
|
||||
|
||||
UPDATE rw_view2 SET a = a - 10 where id = 2;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a + 10 where id = 2;
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a + 10), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
Seq Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 2))
|
||||
|
||||
(12 rows)
|
||||
|
||||
UPDATE rw_view2 SET a = a + 10 where id = 2;
|
||||
ERROR: new row violates WITH CHECK OPTION for view "rw_view2"
|
||||
DETAIL: Failing row contains (2, 30, 16).
|
||||
select * from checkdata();
|
||||
tbname | id | a | b
|
||||
-------------+----+----+----
|
||||
base_tbl | 1 | 10 | 5
|
||||
base_tbl | 1 | 19 | 16
|
||||
base_tbl | 2 | 10 | 16
|
||||
foreign_tbl | 1 | 10 | 5
|
||||
foreign_tbl | 1 | 19 | 16
|
||||
foreign_tbl | 2 | 10 | 16
|
||||
rw_view2 | 2 | 10 | 16
|
||||
(7 rows)
|
||||
|
||||
DROP TRIGGER row_before_insupd_trigger ON base_tbl;
|
||||
DROP TABLE base_tbl;
|
||||
DROP FUNCTION row_before_insupd_trigfunc;
|
||||
DROP FUNCTION checkdata;
|
||||
DROP VIEW rw_view1 cascade;
|
||||
DROP VIEW rw_view2 cascade;
|
||||
DROP FOREIGN TABLE foreign_tbl CASCADE;
|
||||
DROP TABLE base_tbl CASCADE;
|
||||
-- ======================================================================================================================================
|
||||
-- TEST-MODULE: test serial columns (ie, sequence-based defaults)
|
||||
-- --------------------------------------
|
||||
|
||||
@ -7089,25 +7089,166 @@ CONTEXT: Remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid, ta
|
||||
ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
|
||||
ERROR: constraint "ft1_c2negative" of relation "ft1" does not exist
|
||||
-- ======================================================================================================================================
|
||||
-- TEST-MODULE: WITH CHECK OPTION constraints
|
||||
-- TEST-MODULE: IUD VIEW and WITH CHECK OPTION constraints
|
||||
-- --------------------------------------
|
||||
-- openGauss not support WITH CHECK OPTION, so this test module
|
||||
-- is unuseful.
|
||||
-- ======================================================================================================================================
|
||||
CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
|
||||
CREATE TABLE base_tbl (a int, b int) with (orientation=column);
|
||||
CREATE TABLE base_tbl (id int, a int, b int) with (orientation=column);
|
||||
ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
|
||||
CREATE FOREIGN TABLE foreign_tbl (id int, a int, b int) SERVER loopback OPTIONS (table_name 'base_tbl');
|
||||
CREATE VIEW rw_view1 AS SELECT * FROM foreign_tbl WHERE a < b and id = 1;
|
||||
CREATE VIEW rw_view2 AS SELECT * FROM foreign_tbl WHERE a < b and id = 2 WITH CHECK OPTION;
|
||||
\d+ rw_view1
|
||||
View "public.rw_view1"
|
||||
Column | Type | Modifiers | Storage | Description
|
||||
--------+---------+-----------+---------+-------------
|
||||
id | integer | | plain |
|
||||
a | integer | | plain |
|
||||
b | integer | | plain |
|
||||
View definition:
|
||||
SELECT *
|
||||
FROM foreign_tbl
|
||||
WHERE foreign_tbl.a < foreign_tbl.b AND foreign_tbl.id = 1;
|
||||
|
||||
\d+ rw_view2
|
||||
View "public.rw_view2"
|
||||
Column | Type | Modifiers | Storage | Description
|
||||
--------+---------+-----------+---------+-------------
|
||||
id | integer | | plain |
|
||||
a | integer | | plain |
|
||||
b | integer | | plain |
|
||||
View definition:
|
||||
SELECT *
|
||||
FROM foreign_tbl
|
||||
WHERE foreign_tbl.a < foreign_tbl.b AND foreign_tbl.id = 2;
|
||||
Options: check_option=cascaded
|
||||
|
||||
CREATE OR REPLACE FUNCTION checkdata(out tbname text, out id int, out a int, out b int) RETURNS SETOF record as $$
|
||||
select * from (
|
||||
(select 'rw_view1', * from rw_view1 where id = 1) union all
|
||||
(select 'rw_view2', * from rw_view2 where id = 2) union all
|
||||
(select 'base_tbl', * from base_tbl) union all
|
||||
(select 'foreign_tbl', * from foreign_tbl)
|
||||
) data(tbname, id, a, b)
|
||||
order by 1,2,3,4;
|
||||
$$ language sql;
|
||||
-- simple case
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 0, 5); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 1, 0, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view1 VALUES (1, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 10, 5); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 1, 10, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view1 VALUES (1, 10, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 5); -- should failed
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 2, 0, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 5);
|
||||
ERROR: Un-support feature
|
||||
DETAIL: column stored relation doesn't support INSERT returning
|
||||
CONTEXT: Remote SQL command: INSERT INTO public.base_tbl(id, a, b) VALUES ($1, $2, $3) RETURNING id, a, b
|
||||
select * from checkdata();
|
||||
tbname | id | a | b
|
||||
-------------+----+----+---
|
||||
base_tbl | 1 | 0 | 5
|
||||
base_tbl | 1 | 10 | 5
|
||||
foreign_tbl | 1 | 0 | 5
|
||||
foreign_tbl | 1 | 10 | 5
|
||||
rw_view1 | 1 | 0 | 5
|
||||
(5 rows)
|
||||
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 20 where id = 1; -- should success
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a + 20), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
Row Adapter
|
||||
Output: id, a, b, ctid, tableoid
|
||||
-> CStore Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 1))
|
||||
|
||||
(14 rows)
|
||||
|
||||
UPDATE rw_view1 SET a = a + 20 where id = 1;
|
||||
select * from checkdata();
|
||||
tbname | id | a | b
|
||||
-------------+----+----+---
|
||||
base_tbl | 1 | 10 | 5
|
||||
base_tbl | 1 | 20 | 5
|
||||
foreign_tbl | 1 | 10 | 5
|
||||
foreign_tbl | 1 | 20 | 5
|
||||
(4 rows)
|
||||
|
||||
insert into base_tbl values(1,100,99),(2,100,99);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) delete from rw_view1 where id = 1;
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------------------------------------------------------------------
|
||||
Delete on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
Row Adapter
|
||||
Output: ctid, tableoid
|
||||
-> CStore Scan on public.base_tbl
|
||||
Output: ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 1))
|
||||
|
||||
(14 rows)
|
||||
|
||||
delete from rw_view1 where id = 1;
|
||||
select * from checkdata();
|
||||
tbname | id | a | b
|
||||
-------------+----+-----+----
|
||||
base_tbl | 1 | 10 | 5
|
||||
base_tbl | 1 | 20 | 5
|
||||
base_tbl | 1 | 100 | 99
|
||||
base_tbl | 2 | 100 | 99
|
||||
foreign_tbl | 1 | 10 | 5
|
||||
foreign_tbl | 1 | 20 | 5
|
||||
foreign_tbl | 1 | 100 | 99
|
||||
foreign_tbl | 2 | 100 | 99
|
||||
(8 rows)
|
||||
|
||||
delete from base_tbl;
|
||||
-- with trigger
|
||||
CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
|
||||
CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
|
||||
ERROR: Only support CREATE TRIGGER on regular row table.
|
||||
CREATE FOREIGN TABLE foreign_tbl (a int, b int)
|
||||
SERVER loopback OPTIONS (table_name 'base_tbl');
|
||||
-- CREATE VIEW rw_view AS SELECT * FROM foreign_tbl
|
||||
-- WHERE a < b WITH CHECK OPTION;
|
||||
-- \d+ rw_view
|
||||
DROP FOREIGN TABLE foreign_tbl CASCADE;
|
||||
-- not support, do nothing
|
||||
DROP TRIGGER row_before_insupd_trigger ON base_tbl;
|
||||
ERROR: trigger "row_before_insupd_trigger" for table "base_tbl" does not exist
|
||||
DROP TABLE base_tbl;
|
||||
DROP FUNCTION row_before_insupd_trigfunc;
|
||||
DROP FUNCTION checkdata;
|
||||
DROP VIEW rw_view1 cascade;
|
||||
DROP VIEW rw_view2 cascade;
|
||||
DROP FOREIGN TABLE foreign_tbl CASCADE;
|
||||
DROP TABLE base_tbl CASCADE;
|
||||
-- ======================================================================================================================================
|
||||
-- TEST-MODULE: test serial columns (ie, sequence-based defaults)
|
||||
-- --------------------------------------
|
||||
|
||||
@ -6788,6 +6788,459 @@ SELECT f_test(100);
|
||||
|
||||
DROP FUNCTION f_test(int);
|
||||
-- ======================================================================================================================================
|
||||
-- TEST-MODULE: IUD VIEW and WITH CHECK OPTION constraints
|
||||
-- --------------------------------------
|
||||
-- ======================================================================================================================================
|
||||
CREATE TABLE base_tbl (id int, a int, b int)
|
||||
partition by range(a) (partition a1 values less than(100), partition a2 values less than(200));
|
||||
ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
|
||||
CREATE FOREIGN TABLE foreign_tbl (id int, a int, b int) SERVER loopback OPTIONS (table_name 'base_tbl');
|
||||
CREATE VIEW rw_view1 AS SELECT * FROM foreign_tbl WHERE a < b and id = 1;
|
||||
CREATE VIEW rw_view2 AS SELECT * FROM foreign_tbl WHERE a < b and id = 2 WITH CHECK OPTION;
|
||||
\d+ rw_view1
|
||||
View "public.rw_view1"
|
||||
Column | Type | Modifiers | Storage | Description
|
||||
--------+---------+-----------+---------+-------------
|
||||
id | integer | | plain |
|
||||
a | integer | | plain |
|
||||
b | integer | | plain |
|
||||
View definition:
|
||||
SELECT *
|
||||
FROM foreign_tbl
|
||||
WHERE foreign_tbl.a < foreign_tbl.b AND foreign_tbl.id = 1;
|
||||
|
||||
\d+ rw_view2
|
||||
View "public.rw_view2"
|
||||
Column | Type | Modifiers | Storage | Description
|
||||
--------+---------+-----------+---------+-------------
|
||||
id | integer | | plain |
|
||||
a | integer | | plain |
|
||||
b | integer | | plain |
|
||||
View definition:
|
||||
SELECT *
|
||||
FROM foreign_tbl
|
||||
WHERE foreign_tbl.a < foreign_tbl.b AND foreign_tbl.id = 2;
|
||||
Options: check_option=cascaded
|
||||
|
||||
CREATE OR REPLACE FUNCTION checkdata(out tbname text, out id int, out a int, out b int) RETURNS SETOF record as $$
|
||||
select * from (
|
||||
(select 'rw_view1', * from rw_view1 where id = 1) union all
|
||||
(select 'rw_view2', * from rw_view2 where id = 2) union all
|
||||
(select 'base_tbl p1', * from base_tbl) union all
|
||||
(select 'base_tbl p2', * from base_tbl) union all
|
||||
(select 'foreign_tbl', * from foreign_tbl)
|
||||
) data(tbname, id, a, b)
|
||||
order by 1,2,3,4;
|
||||
$$ language sql;
|
||||
-- simple case
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 0, 5); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 1, 0, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view1 VALUES (1, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 100, 5); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 1, 100, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view1 VALUES (1, 100, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 1000, 5000); -- should failed
|
||||
QUERY PLAN
|
||||
-------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 1, 1000, 5000
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view1 VALUES (1, 1000, 5000);
|
||||
ERROR: inserted partition key does not map to any table partition
|
||||
CONTEXT: Remote SQL command: INSERT INTO public.base_tbl(id, a, b) VALUES ($1, $2, $3)
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 5); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 2, 0, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 100, 5); -- should failed
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 2, 100, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view2 VALUES (2, 100, 5);
|
||||
ERROR: new row violates WITH CHECK OPTION for view "rw_view2"
|
||||
DETAIL: Failing row contains (2, 100, 5).
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 1000, 5000); -- should failed
|
||||
QUERY PLAN
|
||||
-------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 2, 1000, 5000
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view2 VALUES (2, 1000, 5000);
|
||||
ERROR: inserted partition key does not map to any table partition
|
||||
CONTEXT: Remote SQL command: INSERT INTO public.base_tbl(id, a, b) VALUES ($1, $2, $3) RETURNING id, a, b
|
||||
select * from checkdata();
|
||||
tbname | id | a | b
|
||||
-------------+----+-----+---
|
||||
base_tbl p1 | 1 | 0 | 5
|
||||
base_tbl p1 | 1 | 100 | 5
|
||||
base_tbl p1 | 2 | 0 | 5
|
||||
base_tbl p2 | 1 | 0 | 5
|
||||
base_tbl p2 | 1 | 100 | 5
|
||||
base_tbl p2 | 2 | 0 | 5
|
||||
foreign_tbl | 1 | 0 | 5
|
||||
foreign_tbl | 1 | 100 | 5
|
||||
foreign_tbl | 2 | 0 | 5
|
||||
rw_view1 | 1 | 0 | 5
|
||||
rw_view2 | 2 | 0 | 5
|
||||
(11 rows)
|
||||
|
||||
delete from base_tbl;
|
||||
insert into base_tbl values(1, 65, 100), (2, 85, 100); -- in and cross partition update
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 20 where id = 1; -- should success
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a + 20), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
Partition Iterator
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Iterations: 2
|
||||
-> Partitioned Seq Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 1))
|
||||
Selected Partitions: 1..2
|
||||
|
||||
(16 rows)
|
||||
|
||||
UPDATE rw_view1 SET a = a + 10 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 20 where id = 1; -- should success
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a + 20), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
Partition Iterator
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Iterations: 2
|
||||
-> Partitioned Seq Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 1))
|
||||
Selected Partitions: 1..2
|
||||
|
||||
(16 rows)
|
||||
|
||||
UPDATE rw_view1 SET a = a + 10 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a + 20 where id = 2; -- should failed
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a + 20), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
Partition Iterator
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Iterations: 2
|
||||
-> Partitioned Seq Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 2))
|
||||
Selected Partitions: 1..2
|
||||
|
||||
(16 rows)
|
||||
|
||||
UPDATE rw_view2 SET a = a + 20 where id = 2;
|
||||
ERROR: new row violates WITH CHECK OPTION for view "rw_view2"
|
||||
DETAIL: Failing row contains (2, 105, 100).
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a + 20, b = 200 where id = 2; -- should success
|
||||
QUERY PLAN
|
||||
---------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a + 20), 200, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
Partition Iterator
|
||||
Output: id, a, ctid, tableoid
|
||||
Iterations: 2
|
||||
-> Partitioned Seq Scan on public.base_tbl
|
||||
Output: id, a, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 2))
|
||||
Selected Partitions: 1..2
|
||||
|
||||
(16 rows)
|
||||
|
||||
UPDATE rw_view2 SET a = a + 20, b = 200 where id = 2;
|
||||
select * from checkdata();
|
||||
tbname | id | a | b
|
||||
-------------+----+-----+-----
|
||||
base_tbl p1 | 1 | 85 | 100
|
||||
base_tbl p1 | 2 | 105 | 200
|
||||
base_tbl p2 | 1 | 85 | 100
|
||||
base_tbl p2 | 2 | 105 | 200
|
||||
foreign_tbl | 1 | 85 | 100
|
||||
foreign_tbl | 2 | 105 | 200
|
||||
rw_view1 | 1 | 85 | 100
|
||||
rw_view2 | 2 | 105 | 200
|
||||
(8 rows)
|
||||
|
||||
delete from base_tbl;
|
||||
insert into base_tbl values(1, 100, 99),(2, 100, 99);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) delete from rw_view1 where id = 1;
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------------------------------------------------------------------
|
||||
Delete on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
Partition Iterator
|
||||
Output: ctid, tableoid
|
||||
Iterations: 2
|
||||
-> Partitioned Seq Scan on public.base_tbl
|
||||
Output: ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 1))
|
||||
Selected Partitions: 1..2
|
||||
|
||||
(16 rows)
|
||||
|
||||
delete from rw_view1 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) delete from rw_view2 where id = 2;
|
||||
QUERY PLAN
|
||||
--------------------------------------------------------------------------------------------------------------------
|
||||
Delete on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
Partition Iterator
|
||||
Output: ctid, tableoid
|
||||
Iterations: 2
|
||||
-> Partitioned Seq Scan on public.base_tbl
|
||||
Output: ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 2))
|
||||
Selected Partitions: 1..2
|
||||
|
||||
(16 rows)
|
||||
|
||||
delete from rw_view2 where id = 2;
|
||||
select * from checkdata();
|
||||
tbname | id | a | b
|
||||
-------------+----+-----+----
|
||||
base_tbl p1 | 1 | 100 | 99
|
||||
base_tbl p1 | 2 | 100 | 99
|
||||
base_tbl p2 | 1 | 100 | 99
|
||||
base_tbl p2 | 2 | 100 | 99
|
||||
foreign_tbl | 1 | 100 | 99
|
||||
foreign_tbl | 2 | 100 | 99
|
||||
(6 rows)
|
||||
|
||||
delete from base_tbl;
|
||||
-- with trigger
|
||||
CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
|
||||
CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 0, 5); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 1, 0, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view1 VALUES (1, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 80, 16); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 1, 80, 16
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view1 VALUES (1, 80, 16);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 5); -- should failed
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 2, 0, 5
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 5);
|
||||
ERROR: new row violates WITH CHECK OPTION for view "rw_view2"
|
||||
DETAIL: Failing row contains (2, 10, 5).
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 16); -- should success
|
||||
QUERY PLAN
|
||||
------------------------------
|
||||
Insert on public.foreign_tbl
|
||||
-> Result
|
||||
Output: 2, 0, 16
|
||||
(3 rows)
|
||||
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 16);
|
||||
select * from checkdata();
|
||||
tbname | id | a | b
|
||||
-------------+----+----+----
|
||||
base_tbl p1 | 1 | 10 | 5
|
||||
base_tbl p1 | 1 | 90 | 16
|
||||
base_tbl p1 | 2 | 10 | 16
|
||||
base_tbl p2 | 1 | 10 | 5
|
||||
base_tbl p2 | 1 | 90 | 16
|
||||
base_tbl p2 | 2 | 10 | 16
|
||||
foreign_tbl | 1 | 10 | 5
|
||||
foreign_tbl | 1 | 90 | 16
|
||||
foreign_tbl | 2 | 10 | 16
|
||||
rw_view2 | 2 | 10 | 16
|
||||
(10 rows)
|
||||
|
||||
delete from base_tbl;
|
||||
insert into base_tbl values(1, 50, 101), (2, 50, 120); -- in and cross partition update
|
||||
-- (1, 60, 101), (2, 60, 120)
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 20 where id = 1; -- should success
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a + 20), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
Partition Iterator
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Iterations: 2
|
||||
-> Partitioned Seq Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 1))
|
||||
Selected Partitions: 1..2
|
||||
|
||||
(16 rows)
|
||||
|
||||
UPDATE rw_view1 SET a = a +20 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 20 where id = 1; -- should success
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a + 20), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 1))
|
||||
Partition Iterator
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Iterations: 2
|
||||
-> Partitioned Seq Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 1))
|
||||
Selected Partitions: 1..2
|
||||
|
||||
(16 rows)
|
||||
|
||||
UPDATE rw_view1 SET a = a +20 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a + 55 where id = 2; -- should failed
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a + 55), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
Partition Iterator
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Iterations: 2
|
||||
-> Partitioned Seq Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 2))
|
||||
Selected Partitions: 1..2
|
||||
|
||||
(16 rows)
|
||||
|
||||
UPDATE rw_view2 SET a = a + 55 where id = 2;
|
||||
ERROR: new row violates WITH CHECK OPTION for view "rw_view2"
|
||||
DETAIL: Failing row contains (2, 125, 120).
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a + 45 where id = 2; -- should success
|
||||
QUERY PLAN
|
||||
------------------------------------------------------------------------------------------------------------------------------
|
||||
Update on public.foreign_tbl
|
||||
-> Foreign Scan on public.foreign_tbl
|
||||
Output: foreign_tbl.id, (foreign_tbl.a + 45), foreign_tbl.b, foreign_tbl.ctid, foreign_tbl.tableoid
|
||||
Node ID: 1
|
||||
Remote SQL: SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
|
||||
FDW remote plans:
|
||||
Node 1: EXPLAIN (VERBOSE ON, COSTS OFF) SELECT id, a, b, ctid, tableoid FROM public.base_tbl WHERE ((a < b)) AND ((id = 2))
|
||||
Partition Iterator
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Iterations: 2
|
||||
-> Partitioned Seq Scan on public.base_tbl
|
||||
Output: id, a, b, ctid, tableoid
|
||||
Filter: ((base_tbl.a < base_tbl.b) AND (base_tbl.id = 2))
|
||||
Selected Partitions: 1..2
|
||||
|
||||
(16 rows)
|
||||
|
||||
UPDATE rw_view2 SET a = a + 45 where id = 2;
|
||||
select * from checkdata();
|
||||
tbname | id | a | b
|
||||
-------------+----+-----+-----
|
||||
base_tbl p1 | 1 | 120 | 101
|
||||
base_tbl p1 | 2 | 115 | 120
|
||||
base_tbl p2 | 1 | 120 | 101
|
||||
base_tbl p2 | 2 | 115 | 120
|
||||
foreign_tbl | 1 | 120 | 101
|
||||
foreign_tbl | 2 | 115 | 120
|
||||
rw_view2 | 2 | 115 | 120
|
||||
(7 rows)
|
||||
|
||||
DROP TRIGGER row_before_insupd_trigger ON base_tbl;
|
||||
DROP FUNCTION row_before_insupd_trigfunc;
|
||||
DROP FUNCTION checkdata;
|
||||
DROP VIEW rw_view1 cascade;
|
||||
DROP VIEW rw_view2 cascade;
|
||||
DROP FOREIGN TABLE foreign_tbl CASCADE;
|
||||
DROP TABLE base_tbl CASCADE;
|
||||
-- ======================================================================================================================================
|
||||
-- TEST-MODULE: test writable foreign table stuff
|
||||
-- --------------------------------------
|
||||
-- ======================================================================================================================================
|
||||
|
||||
@ -1300,6 +1300,7 @@ static List *postgresPlanForeignModify(PlannerInfo *root, ModifyTable *plan, Ind
|
||||
RangeTblEntry *rte = planner_rt_fetch(resultRelation, root);
|
||||
StringInfoData sql;
|
||||
List *targetAttrs = NIL;
|
||||
List *withCheckOptionList = NIL;
|
||||
List *returningList = NIL;
|
||||
List *retrieved_attrs = NIL;
|
||||
|
||||
@ -1347,6 +1348,13 @@ static List *postgresPlanForeignModify(PlannerInfo *root, ModifyTable *plan, Ind
|
||||
}
|
||||
}
|
||||
|
||||
/*
|
||||
* Extract the relevant WITH CHECK OPTION list if any.
|
||||
*/
|
||||
if (plan->withCheckOptionLists) {
|
||||
withCheckOptionList = (List*)list_nth(plan->withCheckOptionLists, subplan_index);
|
||||
}
|
||||
|
||||
/*
|
||||
* Extract the relevant RETURNING list if any.
|
||||
*/
|
||||
@ -1359,10 +1367,12 @@ static List *postgresPlanForeignModify(PlannerInfo *root, ModifyTable *plan, Ind
|
||||
*/
|
||||
switch (operation) {
|
||||
case CMD_INSERT:
|
||||
deparseInsertSql(&sql, rte, resultRelation, rel, targetAttrs, returningList, &retrieved_attrs);
|
||||
deparseInsertSql(&sql, rte, resultRelation, rel, targetAttrs, withCheckOptionList, returningList,
|
||||
&retrieved_attrs);
|
||||
break;
|
||||
case CMD_UPDATE:
|
||||
deparseUpdateSql(&sql, rte, resultRelation, rel, targetAttrs, returningList, &retrieved_attrs);
|
||||
deparseUpdateSql(&sql, rte, resultRelation, rel, targetAttrs, withCheckOptionList, returningList,
|
||||
&retrieved_attrs);
|
||||
break;
|
||||
case CMD_DELETE:
|
||||
deparseDeleteSql(&sql, rte, resultRelation, rel, returningList, &retrieved_attrs);
|
||||
@ -1535,7 +1545,7 @@ static TupleTableSlot *postgresExecForeignInsert(EState *estate, ResultRelInfo *
|
||||
targetAttrs = lappend_int(targetAttrs, attnum);
|
||||
}
|
||||
}
|
||||
deparseInsertSql(&sql, rte, resultRelation, rel, targetAttrs, NULL, &retrieved_attrs);
|
||||
deparseInsertSql(&sql, rte, resultRelation, rel, targetAttrs, NULL, NULL, &retrieved_attrs);
|
||||
|
||||
fmstate = createForeignModify(estate, rte, resultRelInfo, CMD_INSERT, NULL, sql.data, targetAttrs,
|
||||
retrieved_attrs != NIL, retrieved_attrs);
|
||||
|
||||
@ -151,9 +151,9 @@ extern void classifyConditions(PlannerInfo *root, RelOptInfo *baserel, List *inp
|
||||
extern bool is_foreign_expr(PlannerInfo *root, RelOptInfo *baserel, Expr *expr);
|
||||
extern bool is_foreign_pathkey(PlannerInfo *root, RelOptInfo *baserel, PathKey *pathkey);
|
||||
extern void deparseInsertSql(StringInfo buf, RangeTblEntry *rte, Index rtindex, Relation rel, List *targetAttrs,
|
||||
List *returningList, List **retrieved_attrs);
|
||||
List *withCheckOptionList, List *returningList, List **retrieved_attrs);
|
||||
extern void deparseUpdateSql(StringInfo buf, RangeTblEntry *rte, Index rtindex, Relation rel, List *targetAttrs,
|
||||
List *returningList, List **retrieved_attrs);
|
||||
List *withCheckOptionList, List *returningList, List **retrieved_attrs);
|
||||
extern void deparseDeleteSql(StringInfo buf, RangeTblEntry *rte, Index rtindex, Relation rel, List *returningList,
|
||||
List **retrieved_attrs);
|
||||
extern void deparseAnalyzeSizeSql(StringInfo buf, Relation rel);
|
||||
|
||||
@ -1371,24 +1371,85 @@ UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
|
||||
ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
|
||||
|
||||
-- ======================================================================================================================================
|
||||
-- TEST-MODULE: WITH CHECK OPTION constraints
|
||||
-- TEST-MODULE: IUD VIEW and WITH CHECK OPTION constraints
|
||||
-- --------------------------------------
|
||||
-- openGauss not support WITH CHECK OPTION, so this test module is unuseful and cannot be fixed, remove it.
|
||||
-- ======================================================================================================================================
|
||||
CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TABLE base_tbl (a int, b int);
|
||||
CREATE TABLE base_tbl (id int, a int, b int);
|
||||
ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
|
||||
CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
|
||||
CREATE FOREIGN TABLE foreign_tbl (a int, b int)
|
||||
SERVER loopback OPTIONS (table_name 'base_tbl');
|
||||
-- CREATE VIEW rw_view AS SELECT * FROM foreign_tbl
|
||||
-- WHERE a < b WITH CHECK OPTION;
|
||||
-- \d+ rw_view
|
||||
CREATE FOREIGN TABLE foreign_tbl (id int, a int, b int) SERVER loopback OPTIONS (table_name 'base_tbl');
|
||||
CREATE VIEW rw_view1 AS SELECT * FROM foreign_tbl WHERE a < b and id = 1;
|
||||
CREATE VIEW rw_view2 AS SELECT * FROM foreign_tbl WHERE a < b and id = 2 WITH CHECK OPTION;
|
||||
\d+ rw_view1
|
||||
\d+ rw_view2
|
||||
CREATE OR REPLACE FUNCTION checkdata(out tbname text, out id int, out a int, out b int) RETURNS SETOF record as $$
|
||||
select * from (
|
||||
(select 'rw_view1', * from rw_view1 where id = 1) union all
|
||||
(select 'rw_view2', * from rw_view2 where id = 2) union all
|
||||
(select 'base_tbl', * from base_tbl) union all
|
||||
(select 'foreign_tbl', * from foreign_tbl)
|
||||
) data(tbname, id, a, b)
|
||||
order by 1,2,3,4;
|
||||
$$ language sql;
|
||||
|
||||
-- simple case
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 0, 5); -- should success
|
||||
INSERT INTO rw_view1 VALUES (1, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 10, 5); -- should success
|
||||
INSERT INTO rw_view1 VALUES (1, 10, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 5); -- should success
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 10, 5); -- should failed
|
||||
INSERT INTO rw_view2 VALUES (2, 10, 5);
|
||||
select * from checkdata();
|
||||
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 20 where id = 1; -- should success
|
||||
UPDATE rw_view1 SET a = a + 20 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a + 20 where id = 2; -- should failed
|
||||
UPDATE rw_view2 SET a = a + 20 where id = 2;
|
||||
select * from checkdata();
|
||||
|
||||
insert into base_tbl values(1,100,99),(2,100,99);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) delete from rw_view1 where id = 1;
|
||||
delete from rw_view1 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) delete from rw_view2 where id = 2;
|
||||
delete from rw_view2 where id = 2;
|
||||
select * from checkdata();
|
||||
|
||||
delete from base_tbl;
|
||||
|
||||
-- with trigger
|
||||
CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
|
||||
CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
|
||||
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 0, 5); -- should success
|
||||
INSERT INTO rw_view1 VALUES (1, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 0, 16); -- should success
|
||||
INSERT INTO rw_view1 VALUES (1, 0, 16);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 5); -- should failed
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 16); -- should success
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 16);
|
||||
select * from checkdata();
|
||||
|
||||
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a - 1 where id = 1;
|
||||
UPDATE rw_view1 SET a = a - 1 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 1 where id = 1;
|
||||
UPDATE rw_view1 SET a = a + 1 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a - 10 where id = 2;
|
||||
UPDATE rw_view2 SET a = a - 10 where id = 2;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a + 10 where id = 2;
|
||||
UPDATE rw_view2 SET a = a + 10 where id = 2;
|
||||
select * from checkdata();
|
||||
|
||||
|
||||
DROP FOREIGN TABLE foreign_tbl CASCADE;
|
||||
DROP TRIGGER row_before_insupd_trigger ON base_tbl;
|
||||
DROP TABLE base_tbl;
|
||||
DROP FUNCTION row_before_insupd_trigfunc;
|
||||
DROP FUNCTION checkdata;
|
||||
DROP VIEW rw_view1 cascade;
|
||||
DROP VIEW rw_view2 cascade;
|
||||
DROP FOREIGN TABLE foreign_tbl CASCADE;
|
||||
DROP TABLE base_tbl CASCADE;
|
||||
|
||||
|
||||
-- ======================================================================================================================================
|
||||
|
||||
@ -1008,26 +1008,59 @@ UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
|
||||
ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
|
||||
|
||||
-- ======================================================================================================================================
|
||||
-- TEST-MODULE: WITH CHECK OPTION constraints
|
||||
-- TEST-MODULE: IUD VIEW and WITH CHECK OPTION constraints
|
||||
-- --------------------------------------
|
||||
-- openGauss not support WITH CHECK OPTION, so this test module
|
||||
-- is unuseful.
|
||||
-- ======================================================================================================================================
|
||||
|
||||
CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE TABLE base_tbl (a int, b int) with (orientation=column);
|
||||
CREATE TABLE base_tbl (id int, a int, b int) with (orientation=column);
|
||||
ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
|
||||
CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
|
||||
CREATE FOREIGN TABLE foreign_tbl (a int, b int)
|
||||
SERVER loopback OPTIONS (table_name 'base_tbl');
|
||||
-- CREATE VIEW rw_view AS SELECT * FROM foreign_tbl
|
||||
-- WHERE a < b WITH CHECK OPTION;
|
||||
-- \d+ rw_view
|
||||
CREATE FOREIGN TABLE foreign_tbl (id int, a int, b int) SERVER loopback OPTIONS (table_name 'base_tbl');
|
||||
CREATE VIEW rw_view1 AS SELECT * FROM foreign_tbl WHERE a < b and id = 1;
|
||||
CREATE VIEW rw_view2 AS SELECT * FROM foreign_tbl WHERE a < b and id = 2 WITH CHECK OPTION;
|
||||
\d+ rw_view1
|
||||
\d+ rw_view2
|
||||
CREATE OR REPLACE FUNCTION checkdata(out tbname text, out id int, out a int, out b int) RETURNS SETOF record as $$
|
||||
select * from (
|
||||
(select 'rw_view1', * from rw_view1 where id = 1) union all
|
||||
(select 'rw_view2', * from rw_view2 where id = 2) union all
|
||||
(select 'base_tbl', * from base_tbl) union all
|
||||
(select 'foreign_tbl', * from foreign_tbl)
|
||||
) data(tbname, id, a, b)
|
||||
order by 1,2,3,4;
|
||||
$$ language sql;
|
||||
|
||||
-- simple case
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 0, 5); -- should success
|
||||
INSERT INTO rw_view1 VALUES (1, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 10, 5); -- should success
|
||||
INSERT INTO rw_view1 VALUES (1, 10, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 5); -- should failed
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 5);
|
||||
select * from checkdata();
|
||||
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 20 where id = 1; -- should success
|
||||
UPDATE rw_view1 SET a = a + 20 where id = 1;
|
||||
select * from checkdata();
|
||||
|
||||
insert into base_tbl values(1,100,99),(2,100,99);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) delete from rw_view1 where id = 1;
|
||||
delete from rw_view1 where id = 1;
|
||||
select * from checkdata();
|
||||
|
||||
delete from base_tbl;
|
||||
|
||||
-- with trigger
|
||||
CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
|
||||
CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
|
||||
-- not support, do nothing
|
||||
|
||||
DROP FOREIGN TABLE foreign_tbl CASCADE;
|
||||
DROP TRIGGER row_before_insupd_trigger ON base_tbl;
|
||||
DROP TABLE base_tbl;
|
||||
DROP FUNCTION row_before_insupd_trigfunc;
|
||||
DROP FUNCTION checkdata;
|
||||
DROP VIEW rw_view1 cascade;
|
||||
DROP VIEW rw_view2 cascade;
|
||||
DROP FOREIGN TABLE foreign_tbl CASCADE;
|
||||
DROP TABLE base_tbl CASCADE;
|
||||
|
||||
|
||||
-- ======================================================================================================================================
|
||||
-- TEST-MODULE: test serial columns (ie, sequence-based defaults)
|
||||
|
||||
@ -1053,6 +1053,101 @@ $$ LANGUAGE plpgsql;
|
||||
SELECT f_test(100);
|
||||
DROP FUNCTION f_test(int);
|
||||
|
||||
-- ======================================================================================================================================
|
||||
-- TEST-MODULE: IUD VIEW and WITH CHECK OPTION constraints
|
||||
-- --------------------------------------
|
||||
-- ======================================================================================================================================
|
||||
CREATE TABLE base_tbl (id int, a int, b int)
|
||||
partition by range(a) (partition a1 values less than(100), partition a2 values less than(200));
|
||||
ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
|
||||
CREATE FOREIGN TABLE foreign_tbl (id int, a int, b int) SERVER loopback OPTIONS (table_name 'base_tbl');
|
||||
CREATE VIEW rw_view1 AS SELECT * FROM foreign_tbl WHERE a < b and id = 1;
|
||||
CREATE VIEW rw_view2 AS SELECT * FROM foreign_tbl WHERE a < b and id = 2 WITH CHECK OPTION;
|
||||
\d+ rw_view1
|
||||
\d+ rw_view2
|
||||
CREATE OR REPLACE FUNCTION checkdata(out tbname text, out id int, out a int, out b int) RETURNS SETOF record as $$
|
||||
select * from (
|
||||
(select 'rw_view1', * from rw_view1 where id = 1) union all
|
||||
(select 'rw_view2', * from rw_view2 where id = 2) union all
|
||||
(select 'base_tbl p1', * from base_tbl) union all
|
||||
(select 'base_tbl p2', * from base_tbl) union all
|
||||
(select 'foreign_tbl', * from foreign_tbl)
|
||||
) data(tbname, id, a, b)
|
||||
order by 1,2,3,4;
|
||||
$$ language sql;
|
||||
|
||||
-- simple case
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 0, 5); -- should success
|
||||
INSERT INTO rw_view1 VALUES (1, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 100, 5); -- should success
|
||||
INSERT INTO rw_view1 VALUES (1, 100, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 1000, 5000); -- should failed
|
||||
INSERT INTO rw_view1 VALUES (1, 1000, 5000);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 5); -- should success
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 100, 5); -- should failed
|
||||
INSERT INTO rw_view2 VALUES (2, 100, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 1000, 5000); -- should failed
|
||||
INSERT INTO rw_view2 VALUES (2, 1000, 5000);
|
||||
select * from checkdata();
|
||||
delete from base_tbl;
|
||||
|
||||
insert into base_tbl values(1, 65, 100), (2, 85, 100); -- in and cross partition update
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 20 where id = 1; -- should success
|
||||
UPDATE rw_view1 SET a = a + 10 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 20 where id = 1; -- should success
|
||||
UPDATE rw_view1 SET a = a + 10 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a + 20 where id = 2; -- should failed
|
||||
UPDATE rw_view2 SET a = a + 20 where id = 2;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a + 20, b = 200 where id = 2; -- should success
|
||||
UPDATE rw_view2 SET a = a + 20, b = 200 where id = 2;
|
||||
select * from checkdata();
|
||||
delete from base_tbl;
|
||||
|
||||
insert into base_tbl values(1, 100, 99),(2, 100, 99);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) delete from rw_view1 where id = 1;
|
||||
delete from rw_view1 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) delete from rw_view2 where id = 2;
|
||||
delete from rw_view2 where id = 2;
|
||||
select * from checkdata();
|
||||
delete from base_tbl;
|
||||
|
||||
-- with trigger
|
||||
CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
|
||||
CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
|
||||
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 0, 5); -- should success
|
||||
INSERT INTO rw_view1 VALUES (1, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view1 VALUES (1, 80, 16); -- should success
|
||||
INSERT INTO rw_view1 VALUES (1, 80, 16);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 5); -- should failed
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 5);
|
||||
EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO rw_view2 VALUES (2, 0, 16); -- should success
|
||||
INSERT INTO rw_view2 VALUES (2, 0, 16);
|
||||
select * from checkdata();
|
||||
delete from base_tbl;
|
||||
|
||||
insert into base_tbl values(1, 50, 101), (2, 50, 120); -- in and cross partition update
|
||||
-- (1, 60, 101), (2, 60, 120)
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 20 where id = 1; -- should success
|
||||
UPDATE rw_view1 SET a = a +20 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view1 SET a = a + 20 where id = 1; -- should success
|
||||
UPDATE rw_view1 SET a = a +20 where id = 1;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a + 55 where id = 2; -- should failed
|
||||
UPDATE rw_view2 SET a = a + 55 where id = 2;
|
||||
EXPLAIN (VERBOSE, COSTS OFF) UPDATE rw_view2 SET a = a + 45 where id = 2; -- should success
|
||||
UPDATE rw_view2 SET a = a + 45 where id = 2;
|
||||
select * from checkdata();
|
||||
|
||||
DROP TRIGGER row_before_insupd_trigger ON base_tbl;
|
||||
DROP FUNCTION row_before_insupd_trigfunc;
|
||||
DROP FUNCTION checkdata;
|
||||
DROP VIEW rw_view1 cascade;
|
||||
DROP VIEW rw_view2 cascade;
|
||||
DROP FOREIGN TABLE foreign_tbl CASCADE;
|
||||
DROP TABLE base_tbl CASCADE;
|
||||
|
||||
|
||||
-- ======================================================================================================================================
|
||||
-- TEST-MODULE: test writable foreign table stuff
|
||||
-- --------------------------------------
|
||||
|
||||
@ -88,6 +88,7 @@
|
||||
#include "commands/vacuum.h"
|
||||
#include "commands/verify.h"
|
||||
#include "commands/matview.h"
|
||||
#include "commands/view.h"
|
||||
#include "executor/executor.h"
|
||||
#include "executor/node/nodeModifyTable.h"
|
||||
#include "foreign/fdwapi.h"
|
||||
@ -15729,9 +15730,9 @@ static void ATExecSetRelOptions(Relation rel, List* defList, AlterTableType oper
|
||||
}
|
||||
|
||||
/*
|
||||
* If the check option is specified, look to see if the view is
|
||||
* actually auto-updatable or not.
|
||||
*/
|
||||
* If the check option is specified, look to see if the view is
|
||||
* actually auto-updatable or not.
|
||||
*/
|
||||
if (check_option) {
|
||||
const char *view_updatable_error = view_query_is_auto_updatable(view_query, true);
|
||||
|
||||
@ -15740,6 +15741,15 @@ static void ATExecSetRelOptions(Relation rel, List* defList, AlterTableType oper
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("WITH CHECK OPTION is supported only on auto-updatable views"),
|
||||
errhint("%s", view_updatable_error)));
|
||||
|
||||
/*
|
||||
* Views based on MySQL foreign table is not allowed to add check option,
|
||||
* because returning clause which check option dependend on is not supported
|
||||
* on MySQL.
|
||||
*/
|
||||
if (CheckMySQLFdwForWCO(view_query))
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("WITH CHECK OPTION is not supported on views that base on MySQL foreign table")));
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
@ -33,6 +33,7 @@
|
||||
#include "nodes/nodeFuncs.h"
|
||||
#include "parser/analyze.h"
|
||||
#include "parser/parse_relation.h"
|
||||
#include "parser/parsetree.h"
|
||||
#include "rewrite/rewriteDefine.h"
|
||||
#include "rewrite/rewriteManip.h"
|
||||
#include "rewrite/rewriteHandler.h"
|
||||
@ -44,6 +45,7 @@
|
||||
#include "utils/rel.h"
|
||||
#include "utils/rel_gs.h"
|
||||
#include "utils/syscache.h"
|
||||
#include "foreign/foreign.h"
|
||||
#ifdef PGXC
|
||||
#include "pgxc/execRemote.h"
|
||||
#include "tcop/utility.h"
|
||||
@ -531,6 +533,41 @@ static void CreateMvCommand(ViewStmt* stmt, const char* queryString)
|
||||
}
|
||||
#endif
|
||||
|
||||
/*
|
||||
* Check the base relation of view whether is a MySQL foreign table
|
||||
* for WITH CHECK OPTION.
|
||||
*
|
||||
* Return true if it is, false means that it isn't or the view could not
|
||||
* be auto-updatable.
|
||||
*/
|
||||
bool CheckMySQLFdwForWCO(Query* viewquery)
|
||||
{
|
||||
RangeTblRef* rtr = NULL;
|
||||
|
||||
if (list_length(viewquery->jointree->fromlist) != 1) {
|
||||
return false;
|
||||
}
|
||||
|
||||
rtr = (RangeTblRef*)linitial(viewquery->jointree->fromlist);
|
||||
if (!IsA(rtr, RangeTblRef)) {
|
||||
return false;
|
||||
}
|
||||
|
||||
RangeTblEntry* base_rte = rt_fetch(rtr->rtindex, viewquery->rtable);
|
||||
|
||||
if (base_rte->relkind == RELKIND_FOREIGN_TABLE) {
|
||||
return isMysqlFDWFromTblOid(base_rte->relid);
|
||||
} else if (base_rte->relkind == RELKIND_VIEW) {
|
||||
/* recursive check for view */
|
||||
Relation base_rel = try_relation_open(base_rte->relid, AccessShareLock);
|
||||
bool res = CheckMySQLFdwForWCO(get_view_query(base_rel));
|
||||
relation_close(base_rel, AccessShareLock);
|
||||
return res;
|
||||
}
|
||||
|
||||
return false;
|
||||
}
|
||||
|
||||
/*
|
||||
* DefineView
|
||||
* Execute a CREATE VIEW command.
|
||||
@ -620,6 +657,15 @@ Oid DefineView(ViewStmt* stmt, const char* queryString, bool send_remote, bool i
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("WITH CHECK OPTION is supported only on auto-updatable views"),
|
||||
errhint("%s", view_updatable_error)));
|
||||
|
||||
/*
|
||||
* Views based on MySQL foreign table is not allowed to add check option,
|
||||
* because returning clause which check option dependend on is not supported
|
||||
* on MySQL.
|
||||
*/
|
||||
if (CheckMySQLFdwForWCO(viewParse))
|
||||
ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("WITH CHECK OPTION is not supported on views that base on MySQL foreign table")));
|
||||
}
|
||||
|
||||
/*
|
||||
|
||||
@ -20,5 +20,6 @@ extern void validateWithCheckOption(const char* value);
|
||||
extern Oid DefineView(ViewStmt* stmt, const char* queryString, bool send_remote = true, bool isFirstNode = true);
|
||||
extern bool IsViewTemp(ViewStmt* stmt, const char* queryString);
|
||||
extern void StoreViewQuery(Oid viewOid, Query *viewParse, bool replace);
|
||||
extern bool CheckMySQLFdwForWCO(Query* viewquery);
|
||||
|
||||
#endif /* VIEW_H */
|
||||
|
||||
Reference in New Issue
Block a user