Fix WITH CHECK OPTION on views referencing postgres_fdw tables.

If a view references a foreign table, and the foreign table has a
BEFORE INSERT trigger, then it's possible for a tuple inserted or
updated through the view to be changed such that it violates the
view's WITH CHECK OPTION constraint.

Before this commit, postgres_fdw handled this case inconsistently. A
RETURNING clause on the INSERT or UPDATE statement targeting the view
would cause the finally-inserted tuple to be read back, and the WITH
CHECK OPTION violation would throw an error. But without a RETURNING
clause, postgres_fdw would not read the final tuple back, and WITH
CHECK OPTION would not throw an error for the violation (or may throw
an error when there is no real violation). AFTER ROW triggers on the
foreign table had a similar effect as a RETURNING clause on the INSERT
or UPDATE statement.

To fix, this commit retrieves the attributes needed to enforce the
WITH CHECK OPTION constraint along with the attributes needed for the
RETURNING clause (if any) from the remote side. Thus, the WITH CHECK
OPTION constraint is always evaluated against the final tuple after
any triggers on the remote side.

This fix may be considered inconsistent with CHECK constraints
declared on foreign tables, which are not enforced locally at all
(because the constraint is on a remote object). The discussion
concluded that this difference is reasonable, because the WITH CHECK
OPTION is a constraint on the local view (not any remote object);
therefore it only makes sense to enforce its WITH CHECK OPTION
constraint locally.

Author: Etsuro Fujita
Reviewed-by: Arthur Zakirov, Stephen Frost
Discussion: https://www.postgresql.org/message-id/7eb58fab-fd3b-781b-ac33-f7cfec96021f%40lab.ntt.co.jp
This commit is contained in:
Jeff Davis 2018-07-08 00:14:51 -07:00
parent e915fed291
commit a45adc747e
6 changed files with 269 additions and 66 deletions

View File

@ -140,6 +140,7 @@ static void deparseSubqueryTargetList(deparse_expr_cxt *context);
static void deparseReturningList(StringInfo buf, RangeTblEntry *rte,
Index rtindex, Relation rel,
bool trig_after_row,
List *withCheckOptionList,
List *returningList,
List **retrieved_attrs);
static void deparseColumnRef(StringInfo buf, int varno, int varattno,
@ -1645,14 +1646,15 @@ deparseRangeTblRef(StringInfo buf, PlannerInfo *root, RelOptInfo *foreignrel,
* 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, bool doNothing,
List *returningList, List **retrieved_attrs)
List *withCheckOptionList, List *returningList,
List **retrieved_attrs)
{
AttrNumber pindex;
bool first;
@ -1701,20 +1703,21 @@ deparseInsertSql(StringInfo buf, RangeTblEntry *rte,
deparseReturningList(buf, rte, rtindex, rel,
rel->trigdesc && rel->trigdesc->trig_insert_after_row,
returningList, retrieved_attrs);
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 *targetAttrs,
List *withCheckOptionList, List *returningList,
List **retrieved_attrs)
{
AttrNumber pindex;
@ -1743,7 +1746,7 @@ deparseUpdateSql(StringInfo buf, RangeTblEntry *rte,
deparseReturningList(buf, rte, rtindex, rel,
rel->trigdesc && rel->trigdesc->trig_update_after_row,
returningList, retrieved_attrs);
withCheckOptionList, returningList, retrieved_attrs);
}
/*
@ -1837,7 +1840,7 @@ deparseDirectUpdateSql(StringInfo buf, PlannerInfo *root,
&context);
else
deparseReturningList(buf, rte, rtindex, rel, false,
returningList, retrieved_attrs);
NIL, returningList, retrieved_attrs);
}
/*
@ -1859,7 +1862,7 @@ deparseDeleteSql(StringInfo buf, RangeTblEntry *rte,
deparseReturningList(buf, rte, rtindex, rel,
rel->trigdesc && rel->trigdesc->trig_delete_after_row,
returningList, retrieved_attrs);
NIL, returningList, retrieved_attrs);
}
/*
@ -1921,7 +1924,7 @@ deparseDirectDeleteSql(StringInfo buf, PlannerInfo *root,
else
deparseReturningList(buf, planner_rt_fetch(rtindex, root),
rtindex, rel, false,
returningList, retrieved_attrs);
NIL, returningList, retrieved_attrs);
}
/*
@ -1931,6 +1934,7 @@ static void
deparseReturningList(StringInfo buf, RangeTblEntry *rte,
Index rtindex, Relation rel,
bool trig_after_row,
List *withCheckOptionList,
List *returningList,
List **retrieved_attrs)
{
@ -1943,6 +1947,21 @@ deparseReturningList(StringInfo buf, RangeTblEntry *rte,
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)
{
/*

View File

@ -6173,10 +6173,12 @@ ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
-- ===================================================================
-- test WITH CHECK OPTION constraints
-- ===================================================================
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);
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');
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
@ -6192,45 +6194,162 @@ View definition:
WHERE foreign_tbl.a < foreign_tbl.b;
Options: check_option=cascaded
INSERT INTO rw_view VALUES (0, 10); -- ok
INSERT INTO rw_view VALUES (10, 0); -- should fail
ERROR: new row violates check option for view "rw_view"
DETAIL: Failing row contains (10, 0).
EXPLAIN (VERBOSE, COSTS OFF)
UPDATE rw_view SET b = 20 WHERE a = 0; -- not pushed down
QUERY PLAN
--------------------------------------------------------------------------------------------------
Update on public.foreign_tbl
Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1
-> Foreign Scan on public.foreign_tbl
Output: foreign_tbl.a, 20, foreign_tbl.ctid
Remote SQL: SELECT a, ctid FROM public.base_tbl WHERE ((a < b)) AND ((a = 0)) FOR UPDATE
(5 rows)
INSERT INTO rw_view VALUES (0, 5);
QUERY PLAN
--------------------------------------------------------------------------------
Insert on public.foreign_tbl
Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
-> Result
Output: 0, 5
(4 rows)
UPDATE rw_view SET b = 20 WHERE a = 0; -- ok
EXPLAIN (VERBOSE, COSTS OFF)
UPDATE rw_view SET b = -20 WHERE a = 0; -- not pushed down
QUERY PLAN
--------------------------------------------------------------------------------------------------
Update on public.foreign_tbl
Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1
-> Foreign Scan on public.foreign_tbl
Output: foreign_tbl.a, '-20'::integer, foreign_tbl.ctid
Remote SQL: SELECT a, ctid FROM public.base_tbl WHERE ((a < b)) AND ((a = 0)) FOR UPDATE
(5 rows)
UPDATE rw_view SET b = -20 WHERE a = 0; -- should fail
INSERT INTO rw_view VALUES (0, 5); -- should fail
ERROR: new row violates check option for view "rw_view"
DETAIL: Failing row contains (0, -20).
DETAIL: Failing row contains (10, 5).
EXPLAIN (VERBOSE, COSTS OFF)
INSERT INTO rw_view VALUES (0, 15);
QUERY PLAN
--------------------------------------------------------------------------------
Insert on public.foreign_tbl
Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
-> Result
Output: 0, 15
(4 rows)
INSERT INTO rw_view VALUES (0, 15); -- ok
SELECT * FROM foreign_tbl;
a | b
---+----
0 | 20
a | b
----+----
10 | 15
(1 row)
EXPLAIN (VERBOSE, COSTS OFF)
UPDATE rw_view SET b = b + 5;
QUERY PLAN
---------------------------------------------------------------------------------------
Update on public.foreign_tbl
Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
-> Foreign Scan on public.foreign_tbl
Output: foreign_tbl.a, (foreign_tbl.b + 5), foreign_tbl.ctid
Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
(5 rows)
UPDATE rw_view SET b = b + 5; -- should fail
ERROR: new row violates check option for view "rw_view"
DETAIL: Failing row contains (20, 20).
EXPLAIN (VERBOSE, COSTS OFF)
UPDATE rw_view SET b = b + 15;
QUERY PLAN
---------------------------------------------------------------------------------------
Update on public.foreign_tbl
Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
-> Foreign Scan on public.foreign_tbl
Output: foreign_tbl.a, (foreign_tbl.b + 15), foreign_tbl.ctid
Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
(5 rows)
UPDATE rw_view SET b = b + 15; -- ok
SELECT * FROM foreign_tbl;
a | b
----+----
20 | 30
(1 row)
DROP FOREIGN TABLE foreign_tbl CASCADE;
NOTICE: drop cascades to view rw_view
DROP TRIGGER row_before_insupd_trigger ON base_tbl;
DROP TABLE base_tbl;
-- test WCO for partitions
CREATE TABLE child_tbl (a int, b int);
ALTER TABLE child_tbl SET (autovacuum_enabled = 'false');
CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON child_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
CREATE FOREIGN TABLE foreign_tbl (a int, b int)
SERVER loopback OPTIONS (table_name 'child_tbl');
CREATE TABLE parent_tbl (a int, b int) PARTITION BY RANGE(a);
ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
CREATE VIEW rw_view AS SELECT * FROM parent_tbl
WHERE a < b WITH CHECK OPTION;
\d+ rw_view
View "public.rw_view"
Column | Type | Collation | Nullable | Default | Storage | Description
--------+---------+-----------+----------+---------+---------+-------------
a | integer | | | | plain |
b | integer | | | | plain |
View definition:
SELECT parent_tbl.a,
parent_tbl.b
FROM parent_tbl
WHERE parent_tbl.a < parent_tbl.b;
Options: check_option=cascaded
EXPLAIN (VERBOSE, COSTS OFF)
INSERT INTO rw_view VALUES (0, 5);
QUERY PLAN
-----------------------------
Insert on public.parent_tbl
-> Result
Output: 0, 5
(3 rows)
INSERT INTO rw_view VALUES (0, 5); -- should fail
ERROR: new row violates check option for view "rw_view"
DETAIL: Failing row contains (10, 5).
EXPLAIN (VERBOSE, COSTS OFF)
INSERT INTO rw_view VALUES (0, 15);
QUERY PLAN
-----------------------------
Insert on public.parent_tbl
-> Result
Output: 0, 15
(3 rows)
INSERT INTO rw_view VALUES (0, 15); -- ok
SELECT * FROM foreign_tbl;
a | b
----+----
10 | 15
(1 row)
EXPLAIN (VERBOSE, COSTS OFF)
UPDATE rw_view SET b = b + 5;
QUERY PLAN
----------------------------------------------------------------------------------------
Update on public.parent_tbl
Foreign Update on public.foreign_tbl
Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
-> Foreign Scan on public.foreign_tbl
Output: foreign_tbl.a, (foreign_tbl.b + 5), foreign_tbl.ctid
Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
(6 rows)
UPDATE rw_view SET b = b + 5; -- should fail
ERROR: new row violates check option for view "rw_view"
DETAIL: Failing row contains (20, 20).
EXPLAIN (VERBOSE, COSTS OFF)
UPDATE rw_view SET b = b + 15;
QUERY PLAN
----------------------------------------------------------------------------------------
Update on public.parent_tbl
Foreign Update on public.foreign_tbl
Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
-> Foreign Scan on public.foreign_tbl
Output: foreign_tbl.a, (foreign_tbl.b + 15), foreign_tbl.ctid
Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
(6 rows)
UPDATE rw_view SET b = b + 15; -- ok
SELECT * FROM foreign_tbl;
a | b
----+----
20 | 30
(1 row)
DROP FOREIGN TABLE foreign_tbl CASCADE;
DROP TRIGGER row_before_insupd_trigger ON child_tbl;
DROP TABLE parent_tbl CASCADE;
NOTICE: drop cascades to view rw_view
DROP FUNCTION row_before_insupd_trigfunc;
-- ===================================================================
-- test serial columns (ie, sequence-based defaults)
-- ===================================================================

View File

@ -1582,6 +1582,7 @@ postgresPlanForeignModify(PlannerInfo *root,
Relation rel;
StringInfoData sql;
List *targetAttrs = NIL;
List *withCheckOptionList = NIL;
List *returningList = NIL;
List *retrieved_attrs = NIL;
bool doNothing = false;
@ -1630,6 +1631,13 @@ postgresPlanForeignModify(PlannerInfo *root,
}
}
/*
* 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.
*/
@ -1655,12 +1663,14 @@ postgresPlanForeignModify(PlannerInfo *root,
{
case CMD_INSERT:
deparseInsertSql(&sql, rte, resultRelation, rel,
targetAttrs, doNothing, returningList,
targetAttrs, doNothing,
withCheckOptionList, returningList,
&retrieved_attrs);
break;
case CMD_UPDATE:
deparseUpdateSql(&sql, rte, resultRelation, rel,
targetAttrs, returningList,
targetAttrs,
withCheckOptionList, returningList,
&retrieved_attrs);
break;
case CMD_DELETE:
@ -2046,7 +2056,9 @@ postgresBeginForeignInsert(ModifyTableState *mtstate,
/* Construct the SQL command string. */
deparseInsertSql(&sql, rte, resultRelation, rel, targetAttrs, doNothing,
resultRelInfo->ri_returningList, &retrieved_attrs);
resultRelInfo->ri_WithCheckOptions,
resultRelInfo->ri_returningList,
&retrieved_attrs);
/* Construct an execution state. */
fmstate = create_foreign_modify(mtstate->ps.state,

View File

@ -142,11 +142,13 @@ extern bool is_foreign_expr(PlannerInfo *root,
Expr *expr);
extern void deparseInsertSql(StringInfo buf, RangeTblEntry *rte,
Index rtindex, Relation rel,
List *targetAttrs, bool doNothing, List *returningList,
List *targetAttrs, bool doNothing,
List *withCheckOptionList, List *returningList,
List **retrieved_attrs);
extern void deparseUpdateSql(StringInfo buf, RangeTblEntry *rte,
Index rtindex, Relation rel,
List *targetAttrs, List *returningList,
List *targetAttrs,
List *withCheckOptionList, List *returningList,
List **retrieved_attrs);
extern void deparseDirectUpdateSql(StringInfo buf, PlannerInfo *root,
Index rtindex, Relation rel,

View File

@ -1262,27 +1262,74 @@ ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
-- test WITH CHECK OPTION constraints
-- ===================================================================
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);
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');
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
INSERT INTO rw_view VALUES (0, 10); -- ok
INSERT INTO rw_view VALUES (10, 0); -- should fail
EXPLAIN (VERBOSE, COSTS OFF)
UPDATE rw_view SET b = 20 WHERE a = 0; -- not pushed down
UPDATE rw_view SET b = 20 WHERE a = 0; -- ok
INSERT INTO rw_view VALUES (0, 5);
INSERT INTO rw_view VALUES (0, 5); -- should fail
EXPLAIN (VERBOSE, COSTS OFF)
UPDATE rw_view SET b = -20 WHERE a = 0; -- not pushed down
UPDATE rw_view SET b = -20 WHERE a = 0; -- should fail
INSERT INTO rw_view VALUES (0, 15);
INSERT INTO rw_view VALUES (0, 15); -- ok
SELECT * FROM foreign_tbl;
EXPLAIN (VERBOSE, COSTS OFF)
UPDATE rw_view SET b = b + 5;
UPDATE rw_view SET b = b + 5; -- should fail
EXPLAIN (VERBOSE, COSTS OFF)
UPDATE rw_view SET b = b + 15;
UPDATE rw_view SET b = b + 15; -- ok
SELECT * FROM foreign_tbl;
DROP FOREIGN TABLE foreign_tbl CASCADE;
DROP TRIGGER row_before_insupd_trigger ON base_tbl;
DROP TABLE base_tbl;
-- test WCO for partitions
CREATE TABLE child_tbl (a int, b int);
ALTER TABLE child_tbl SET (autovacuum_enabled = 'false');
CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON child_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
CREATE FOREIGN TABLE foreign_tbl (a int, b int)
SERVER loopback OPTIONS (table_name 'child_tbl');
CREATE TABLE parent_tbl (a int, b int) PARTITION BY RANGE(a);
ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
CREATE VIEW rw_view AS SELECT * FROM parent_tbl
WHERE a < b WITH CHECK OPTION;
\d+ rw_view
EXPLAIN (VERBOSE, COSTS OFF)
INSERT INTO rw_view VALUES (0, 5);
INSERT INTO rw_view VALUES (0, 5); -- should fail
EXPLAIN (VERBOSE, COSTS OFF)
INSERT INTO rw_view VALUES (0, 15);
INSERT INTO rw_view VALUES (0, 15); -- ok
SELECT * FROM foreign_tbl;
EXPLAIN (VERBOSE, COSTS OFF)
UPDATE rw_view SET b = b + 5;
UPDATE rw_view SET b = b + 5; -- should fail
EXPLAIN (VERBOSE, COSTS OFF)
UPDATE rw_view SET b = b + 15;
UPDATE rw_view SET b = b + 15; -- ok
SELECT * FROM foreign_tbl;
DROP FOREIGN TABLE foreign_tbl CASCADE;
DROP TRIGGER row_before_insupd_trigger ON child_tbl;
DROP TABLE parent_tbl CASCADE;
DROP FUNCTION row_before_insupd_trigfunc;
-- ===================================================================
-- test serial columns (ie, sequence-based defaults)
-- ===================================================================

View File

@ -573,12 +573,14 @@ ExecForeignInsert(EState *estate,
<para>
The data in the returned slot is used only if the <command>INSERT</command>
query has a <literal>RETURNING</literal> clause or the foreign table has
an <literal>AFTER ROW</literal> trigger. Triggers require all columns, but the
FDW could choose to optimize away returning some or all columns depending
on the contents of the <literal>RETURNING</literal> clause. Regardless, some
slot must be returned to indicate success, or the query's reported row
count will be wrong.
statement has a <literal>RETURNING</literal> clause or involves a view
<literal>WITH CHECK OPTION</literal>; or if the foreign table has
an <literal>AFTER ROW</literal> trigger. Triggers require all columns,
but the FDW could choose to optimize away returning some or all columns
depending on the contents of the <literal>RETURNING</literal> clause or
<literal>WITH CHECK OPTION</literal> constraints. Regardless, some slot
must be returned to indicate success, or the query's reported row count
will be wrong.
</para>
<para>
@ -619,12 +621,14 @@ ExecForeignUpdate(EState *estate,
<para>
The data in the returned slot is used only if the <command>UPDATE</command>
query has a <literal>RETURNING</literal> clause or the foreign table has
an <literal>AFTER ROW</literal> trigger. Triggers require all columns, but the
FDW could choose to optimize away returning some or all columns depending
on the contents of the <literal>RETURNING</literal> clause. Regardless, some
slot must be returned to indicate success, or the query's reported row
count will be wrong.
statement has a <literal>RETURNING</literal> clause or involves a view
<literal>WITH CHECK OPTION</literal>; or if the foreign table has
an <literal>AFTER ROW</literal> trigger. Triggers require all columns,
but the FDW could choose to optimize away returning some or all columns
depending on the contents of the <literal>RETURNING</literal> clause or
<literal>WITH CHECK OPTION</literal> constraints. Regardless, some slot
must be returned to indicate success, or the query's reported row count
will be wrong.
</para>
<para>