If the user modifies a view that has CHECK OPTIONs and this gets
translated into a modification to an underlying relation which happens
to be a foreign table, the check options should be enforced. In the
normal code path, that was happening properly, but it was not working
properly for "direct" modification because the whole operation gets
pushed to the remote side in that case and we never have an option to
enforce the constraint against individual tuples. Fix by disabling
direct modification when there is a need to enforce CHECK OPTIONs.
Etsuro Fujita, reviewed by Kyotaro Horiguchi and by me.
Discussion: http://postgr.es/m/
f8a48f54-6f02-9c8a-5250-
9791603171ee@lab.ntt.co.jp
UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
-- ===================================================================
+-- test WITH CHECK OPTION constraints
+-- ===================================================================
+CREATE TABLE base_tbl (a int, b int);
+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
+ View "public.rw_view"
+ Column | Type | Modifiers | Storage | Description
+--------+---------+-----------+---------+-------------
+ a | integer | | plain |
+ b | integer | | plain |
+View definition:
+ SELECT foreign_tbl.a,
+ foreign_tbl.b
+ FROM foreign_tbl
+ 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)
+
+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
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (0, -20).
+SELECT * FROM foreign_tbl;
+ a | b
+---+----
+ 0 | 20
+(1 row)
+
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP TABLE base_tbl;
+-- ===================================================================
-- test serial columns (ie, sequence-based defaults)
-- ===================================================================
create table loc1 (f1 serial, f2 text);
UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
+-- ===================================================================
+-- test WITH CHECK OPTION constraints
+-- ===================================================================
+
+CREATE TABLE base_tbl (a int, b int);
+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
+
+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
+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
+SELECT * FROM foreign_tbl;
+
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+DROP TABLE base_tbl;
+
-- ===================================================================
-- test serial columns (ie, sequence-based defaults)
-- ===================================================================
<filename>postgres_fdw</> attempts to optimize the query execution by
sending the whole query to the remote server if there are no query
<literal>WHERE</> clauses that cannot be sent to the remote server,
- no local joins for the query, and no row-level local <literal>BEFORE</> or
- <literal>AFTER</> triggers on the target table. In <command>UPDATE</>,
+ no local joins for the query, no row-level local <literal>BEFORE</> or
+ <literal>AFTER</> triggers on the target table, and no
+ <literal>CHECK OPTION</> constraints from parent views.
+ In <command>UPDATE</>,
expressions to assign to target columns must use only built-in data types,
<literal>IMMUTABLE</> operators, or <literal>IMMUTABLE</> functions,
to reduce the risk of misexecution of the query.
}
/*
- * If the target foreign table has any row-level triggers, we can't
- * modify the foreign table directly.
+ * Try to modify the foreign table directly if (1) the FDW provides
+ * callback functions needed for that, (2) there are no row-level
+ * triggers on the foreign table, and (3) there are no WITH CHECK
+ * OPTIONs from parent views.
*/
direct_modify = false;
if (fdwroutine != NULL &&
fdwroutine->BeginDirectModify != NULL &&
fdwroutine->IterateDirectModify != NULL &&
fdwroutine->EndDirectModify != NULL &&
+ withCheckOptionLists == NIL &&
!has_row_triggers(root, rti, operation))
direct_modify = fdwroutine->PlanDirectModify(root, node, rti, i);
if (direct_modify)