Skip to content

Commit 1c82d10

Browse files
committed
Fix UPDATE to account BR trigger changes.
Earlier, only columns that are present in the UPDATE query got updated at the MySQL side. However, in any column value which is not present in the UPDATE query but modified in the BEFORE ROW trigger was not updated at MySQL side. Fix that by marking all columns as updatable in such cases. The fix for this was given by Francois Payette through pull request #194 on GitHub, which is further revised by Suraj Kharage. Also, updating a row-identifier column is not supported. However, this was broken when the BR update trigger is trying to update that. Fix that by comparing old and new value for the row-identifier column and throwing an error if they are not the same. Reported on GitHub through issues #193 by Francois Payette. FDW-193, Suraj Kharage, reviewed by Vaibhav Dalvi and me.
1 parent 7b81a18 commit 1c82d10

File tree

4 files changed

+316
-30
lines changed

4 files changed

+316
-30
lines changed

expected/dml.out

Lines changed: 102 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -14,7 +14,7 @@ CREATE USER MAPPING FOR public SERVER mysql_svr
1414
-- Create foreign tables
1515
CREATE FOREIGN TABLE f_mysql_test(a int, b int)
1616
SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'mysql_test');
17-
CREATE FOREIGN TABLE fdw126_ft1(stu_id int, stu_name varchar(255))
17+
CREATE FOREIGN TABLE fdw126_ft1(stu_id int, stu_name varchar(255), stu_dept int)
1818
SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'student');
1919
CREATE FOREIGN TABLE fdw126_ft2(stu_id int, stu_name varchar(255))
2020
SERVER mysql_svr OPTIONS (table_name 'student');
@@ -28,6 +28,8 @@ CREATE FOREIGN TABLE fdw126_ft6(stu_id int, stu_name varchar(255))
2828
SERVER mysql_svr OPTIONS (table_name 'mysql_fdw_regress1.student');
2929
CREATE FOREIGN TABLE f_empdata(emp_id int, emp_dat bytea)
3030
SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'empdata');
31+
CREATE FOREIGN TABLE fdw193_ft1(stu_id varchar(10), stu_name varchar(255), stu_dept int)
32+
SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress1', table_name 'student1');
3133
-- Operation on blob data.
3234
INSERT INTO f_empdata VALUES (1, decode ('01234567', 'hex'));
3335
SELECT count(*) FROM f_empdata ORDER BY 1;
@@ -56,7 +58,7 @@ SELECT emp_id, emp_dat FROM f_empdata ORDER BY 1;
5658
-- the operation on foreign table created for tables in mysql_fdw_regress
5759
-- MySQL database. Below operations will be performed for foreign table
5860
-- created for table in mysql_fdw_regress1 MySQL database.
59-
INSERT INTO fdw126_ft1 VALUES(1, 'One');
61+
INSERT INTO fdw126_ft1 VALUES(1, 'One', 101);
6062
UPDATE fdw126_ft1 SET stu_name = 'one' WHERE stu_id = 1;
6163
DELETE FROM fdw126_ft1 WHERE stu_id = 1;
6264
-- Select on f_mysql_test foreign table which is created for mysql_test table
@@ -116,9 +118,105 @@ ANALYZE f_empdata(emp_id);
116118
WARNING: skipping "f_empdata" --- cannot analyze this foreign table
117119
VACUUM ANALYZE f_empdata;
118120
WARNING: skipping "f_empdata" --- cannot vacuum non-tables or special system tables
121+
-- Verify the before update trigger which modifies the column value which is not
122+
-- part of update statement.
123+
CREATE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$
124+
BEGIN
125+
NEW.stu_name := NEW.stu_name || ' trigger updated!';
126+
RETURN NEW;
127+
END
128+
$$ language plpgsql;
129+
CREATE TRIGGER before_row_update_trig
130+
BEFORE UPDATE ON fdw126_ft1
131+
FOR EACH ROW EXECUTE PROCEDURE before_row_update_func();
132+
INSERT INTO fdw126_ft1 VALUES(1, 'One', 101);
133+
EXPLAIN (verbose, costs off)
134+
UPDATE fdw126_ft1 SET stu_dept = 201 WHERE stu_id = 1;
135+
QUERY PLAN
136+
-------------------------------------------------------------------------------------------------------------------------------------
137+
Update on public.fdw126_ft1
138+
-> Foreign Scan on public.fdw126_ft1
139+
Output: stu_id, stu_name, 201, stu_id, fdw126_ft1.*
140+
Local server startup cost: 10
141+
Remote query: SELECT `stu_id`, `stu_name`, `stu_dept` FROM `mysql_fdw_regress1`.`student` WHERE ((`stu_id` = 1)) FOR UPDATE
142+
(5 rows)
143+
144+
UPDATE fdw126_ft1 SET stu_dept = 201 WHERE stu_id = 1;
145+
SELECT * FROM fdw126_ft1 ORDER BY stu_id;
146+
stu_id | stu_name | stu_dept
147+
--------+----------------------+----------
148+
1 | One trigger updated! | 201
149+
(1 row)
150+
151+
-- Throw an error when target list has row identifier column.
152+
UPDATE fdw126_ft1 SET stu_dept = 201, stu_id = 10 WHERE stu_id = 1;
153+
ERROR: row identifier column update is not supported
154+
-- Throw an error when before row update trigger modify the row identifier
155+
-- column (int column) value.
156+
CREATE OR REPLACE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$
157+
BEGIN
158+
NEW.stu_name := NEW.stu_name || ' trigger updated!';
159+
NEW.stu_id = 20;
160+
RETURN NEW;
161+
END
162+
$$ language plpgsql;
163+
UPDATE fdw126_ft1 SET stu_dept = 301 WHERE stu_id = 1;
164+
ERROR: row identifier column update is not supported
165+
-- Verify the before update trigger which modifies the column value which is
166+
-- not part of update statement.
167+
CREATE OR REPLACE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$
168+
BEGIN
169+
NEW.stu_name := NEW.stu_name || ' trigger updated!';
170+
RETURN NEW;
171+
END
172+
$$ language plpgsql;
173+
CREATE TRIGGER before_row_update_trig1
174+
BEFORE UPDATE ON fdw193_ft1
175+
FOR EACH ROW EXECUTE PROCEDURE before_row_update_func();
176+
INSERT INTO fdw193_ft1 VALUES('aa', 'One', 101);
177+
EXPLAIN (verbose, costs off)
178+
UPDATE fdw193_ft1 SET stu_dept = 201 WHERE stu_id = 'aa';
179+
QUERY PLAN
180+
-----------------------------------------------------------------------------------------------------------------------------------------
181+
Update on public.fdw193_ft1
182+
-> Foreign Scan on public.fdw193_ft1
183+
Output: stu_id, stu_name, 201, stu_id, fdw193_ft1.*
184+
Local server startup cost: 10
185+
Remote query: SELECT `stu_id`, `stu_name`, `stu_dept` FROM `mysql_fdw_regress1`.`student1` WHERE ((`stu_id` = 'aa')) FOR UPDATE
186+
(5 rows)
187+
188+
UPDATE fdw193_ft1 SET stu_dept = 201 WHERE stu_id = 'aa';
189+
SELECT * FROM fdw193_ft1 ORDER BY stu_id;
190+
stu_id | stu_name | stu_dept
191+
--------+----------------------+----------
192+
aa | One trigger updated! | 201
193+
(1 row)
194+
195+
-- Throw an error when before row update trigger modify the row identifier
196+
-- column (varchar column) value.
197+
CREATE OR REPLACE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$
198+
BEGIN
199+
NEW.stu_name := NEW.stu_name || ' trigger updated!';
200+
NEW.stu_id = 'bb';
201+
RETURN NEW;
202+
END
203+
$$ language plpgsql;
204+
UPDATE fdw193_ft1 SET stu_dept = 301 WHERE stu_id = 'aa';
205+
ERROR: row identifier column update is not supported
206+
-- Verify the NULL assignment scenario.
207+
CREATE OR REPLACE FUNCTION before_row_update_func() RETURNS TRIGGER AS $$
208+
BEGIN
209+
NEW.stu_name := NEW.stu_name || ' trigger updated!';
210+
NEW.stu_id = NULL;
211+
RETURN NEW;
212+
END
213+
$$ language plpgsql;
214+
UPDATE fdw193_ft1 SET stu_dept = 401 WHERE stu_id = 'aa';
215+
ERROR: row identifier column update is not supported
119216
-- Cleanup
120217
DELETE FROM fdw126_ft1;
121218
DELETE FROM f_empdata;
219+
DELETE FROM fdw193_ft1;
122220
DROP FOREIGN TABLE f_mysql_test;
123221
DROP FOREIGN TABLE fdw126_ft1;
124222
DROP FOREIGN TABLE fdw126_ft2;
@@ -127,6 +225,8 @@ DROP FOREIGN TABLE fdw126_ft4;
127225
DROP FOREIGN TABLE fdw126_ft5;
128226
DROP FOREIGN TABLE fdw126_ft6;
129227
DROP FOREIGN TABLE f_empdata;
228+
DROP FOREIGN TABLE fdw193_ft1;
229+
DROP FUNCTION before_row_update_func();
130230
DROP USER MAPPING FOR public SERVER mysql_svr;
131231
DROP SERVER mysql_svr;
132232
DROP EXTENSION mysql_fdw;

mysql_fdw.c

Lines changed: 128 additions & 25 deletions
Original file line numberDiff line numberDiff line change
@@ -26,6 +26,7 @@
2626
#include <sys/stat.h>
2727
#include <unistd.h>
2828

29+
#include "access/htup_details.h"
2930
#include "access/sysattr.h"
3031
#include "access/reloptions.h"
3132
#if PG_VERSION_NUM >= 120000
@@ -48,9 +49,11 @@
4849
#include "parser/parsetree.h"
4950
#include "storage/ipc.h"
5051
#include "utils/builtins.h"
52+
#include "utils/datum.h"
5153
#include "utils/guc.h"
5254
#include "utils/lsyscache.h"
5355
#include "utils/memutils.h"
56+
#include "utils/syscache.h"
5457

5558
/* Declarations for dynamic loading */
5659
PG_MODULE_MAGIC;
@@ -215,6 +218,7 @@ static int interactive_timeout = INTERACTIVE_TIMEOUT;
215218
static void mysql_error_print(MYSQL *conn);
216219
static void mysql_stmt_error_print(MySQLFdwExecState *festate,
217220
const char *msg);
221+
static List *getUpdateTargetAttrs(RangeTblEntry *rte);
218222

219223
/*
220224
* mysql_load_library function dynamically load the mysql's library
@@ -1186,11 +1190,32 @@ mysqlPlanForeignModify(PlannerInfo *root,
11861190
(errcode(ERRCODE_FDW_UNABLE_TO_CREATE_EXECUTION),
11871191
errmsg("first column of remote table must be unique for INSERT/UPDATE/DELETE operation")));
11881192

1189-
if (operation == CMD_INSERT)
1193+
/*
1194+
* In an INSERT, we transmit all columns that are defined in the foreign
1195+
* table. In an UPDATE, if there are BEFORE ROW UPDATE triggers on the
1196+
* foreign table, we transmit all columns like INSERT; else we transmit
1197+
* only columns that were explicitly targets of the UPDATE, so as to avoid
1198+
* unnecessary data transmission. (We can't do that for INSERT since we
1199+
* would miss sending default values for columns not listed in the source
1200+
* statement, and for UPDATE if there are BEFORE ROW UPDATE triggers since
1201+
* those triggers might change values for non-target columns, in which
1202+
* case we would miss sending changed values for those columns.)
1203+
*/
1204+
if (operation == CMD_INSERT ||
1205+
(operation == CMD_UPDATE &&
1206+
rel->trigdesc &&
1207+
rel->trigdesc->trig_update_before_row))
11901208
{
11911209
TupleDesc tupdesc = RelationGetDescr(rel);
11921210
int attnum;
11931211

1212+
/*
1213+
* If it is an UPDATE operation, check for row identifier column in
1214+
* target attribute list by calling getUpdateTargetAttrs().
1215+
*/
1216+
if (operation == CMD_UPDATE)
1217+
getUpdateTargetAttrs(rte);
1218+
11941219
for (attnum = 1; attnum <= tupdesc->natts; attnum++)
11951220
{
11961221
Form_pg_attribute attr = TupleDescAttr(tupdesc, attnum - 1);
@@ -1201,27 +1226,7 @@ mysqlPlanForeignModify(PlannerInfo *root,
12011226
}
12021227
else if (operation == CMD_UPDATE)
12031228
{
1204-
#if PG_VERSION_NUM >= 90500
1205-
Bitmapset *tmpset = bms_copy(rte->updatedCols);
1206-
#else
1207-
Bitmapset *tmpset = bms_copy(rte->modifiedCols);
1208-
#endif
1209-
AttrNumber col;
1210-
1211-
while ((col = bms_first_member(tmpset)) >= 0)
1212-
{
1213-
col += FirstLowInvalidHeapAttributeNumber;
1214-
if (col <= InvalidAttrNumber) /* shouldn't happen */
1215-
elog(ERROR, "system-column update is not supported");
1216-
1217-
/*
1218-
* We also disallow updates to the first column
1219-
*/
1220-
if (col == 1) /* shouldn't happen */
1221-
elog(ERROR, "row identifier column update is not supported");
1222-
1223-
targetAttrs = lappend_int(targetAttrs, col);
1224-
}
1229+
targetAttrs = getUpdateTargetAttrs(rte);
12251230
/* We also want the rowid column to be available for the update */
12261231
targetAttrs = lcons_int(1, targetAttrs);
12271232
}
@@ -1437,6 +1442,10 @@ mysqlExecForeignUpdate(EState *estate,
14371442
Datum value;
14381443
int n_params;
14391444
bool *isnull;
1445+
Datum new_value;
1446+
HeapTuple tuple;
1447+
Form_pg_attribute attr;
1448+
bool found_row_id_col = false;
14401449

14411450
n_params = list_length(fmstate->retrieved_attrs);
14421451

@@ -1449,9 +1458,16 @@ mysqlExecForeignUpdate(EState *estate,
14491458
int attnum = lfirst_int(lc);
14501459
Oid type;
14511460

1452-
/* first attribute cannot be in target list attribute */
1461+
/*
1462+
* The first attribute cannot be in the target list attribute. Set the
1463+
* found_row_id_col to true once we find it so that we can fetch the
1464+
* value later.
1465+
*/
14531466
if (attnum == 1)
1467+
{
1468+
found_row_id_col = true;
14541469
continue;
1470+
}
14551471

14561472
type = TupleDescAttr(slot->tts_tupleDescriptor, attnum - 1)->atttypid;
14571473
value = slot_getattr(slot, attnum, (bool *) (&isnull[bindnum]));
@@ -1461,9 +1477,62 @@ mysqlExecForeignUpdate(EState *estate,
14611477
bindnum++;
14621478
}
14631479

1464-
/* Get the id that was passed up as a resjunk column */
1480+
/*
1481+
* Since we add a row identifier column in the target list always, so
1482+
* found_row_id_col flag should be true.
1483+
*/
1484+
if (!found_row_id_col)
1485+
elog(ERROR, "missing row identifier column value in UPDATE");
1486+
1487+
new_value = slot_getattr(slot, 1, &is_null);
1488+
1489+
/*
1490+
* Get the row identifier column value that was passed up as a resjunk
1491+
* column and compare that value with the new value to identify if that
1492+
* value is changed.
1493+
*/
14651494
value = ExecGetJunkAttribute(planSlot, 1, &is_null);
1466-
typeoid = get_atttype(foreignTableId, 1);
1495+
1496+
tuple = SearchSysCache2(ATTNUM,
1497+
ObjectIdGetDatum(foreignTableId),
1498+
Int16GetDatum(1));
1499+
if (!HeapTupleIsValid(tuple))
1500+
elog(ERROR, "cache lookup failed for attribute %d of relation %u",
1501+
1, foreignTableId);
1502+
1503+
attr = (Form_pg_attribute) GETSTRUCT(tuple);
1504+
typeoid = attr->atttypid;
1505+
1506+
if (DatumGetPointer(new_value) != NULL && DatumGetPointer(value) != NULL)
1507+
{
1508+
Datum n_value = new_value;
1509+
Datum o_value = value;
1510+
1511+
/* If the attribute type is varlena then need to detoast the datums. */
1512+
if (attr->attlen == -1)
1513+
{
1514+
n_value = PointerGetDatum(PG_DETOAST_DATUM(new_value));
1515+
o_value = PointerGetDatum(PG_DETOAST_DATUM(value));
1516+
}
1517+
1518+
if (!datumIsEqual(o_value, n_value, attr->attbyval, attr->attlen))
1519+
ereport(ERROR,
1520+
(errcode(ERRCODE_FDW_UNABLE_TO_CREATE_EXECUTION),
1521+
errmsg("row identifier column update is not supported")));
1522+
1523+
/* Free memory if it's a copy made above */
1524+
if (DatumGetPointer(n_value) != DatumGetPointer(new_value))
1525+
pfree(DatumGetPointer(n_value));
1526+
if (DatumGetPointer(o_value) != DatumGetPointer(value))
1527+
pfree(DatumGetPointer(o_value));
1528+
}
1529+
else if (!(DatumGetPointer(new_value) == NULL &&
1530+
DatumGetPointer(value) == NULL))
1531+
ereport(ERROR,
1532+
(errcode(ERRCODE_FDW_UNABLE_TO_CREATE_EXECUTION),
1533+
errmsg("row identifier column update is not supported")));
1534+
1535+
ReleaseSysCache(tuple);
14671536

14681537
/* Bind qual */
14691538
mysql_bind_sql_var(typeoid, bindnum, value, mysql_bind_buffer, &is_null);
@@ -2009,3 +2078,37 @@ mysql_stmt_error_print(MySQLFdwExecState *festate, const char *msg)
20092078
break;
20102079
}
20112080
}
2081+
2082+
/*
2083+
* getUpdateTargetAttrs
2084+
* Returns the list of attribute numbers of the columns being updated.
2085+
*/
2086+
static List *
2087+
getUpdateTargetAttrs(RangeTblEntry *rte)
2088+
{
2089+
List *targetAttrs = NIL;
2090+
2091+
#if PG_VERSION_NUM >= 90500
2092+
Bitmapset *tmpset = bms_copy(rte->updatedCols);
2093+
#else
2094+
Bitmapset *tmpset = bms_copy(rte->modifiedCols);
2095+
#endif
2096+
AttrNumber col;
2097+
2098+
while ((col = bms_first_member(tmpset)) >= 0)
2099+
{
2100+
col += FirstLowInvalidHeapAttributeNumber;
2101+
if (col <= InvalidAttrNumber) /* shouldn't happen */
2102+
elog(ERROR, "system-column update is not supported");
2103+
2104+
/* We also disallow updates to the first column */
2105+
if (col == 1)
2106+
ereport(ERROR,
2107+
(errcode(ERRCODE_FDW_UNABLE_TO_CREATE_EXECUTION),
2108+
errmsg("row identifier column update is not supported")));
2109+
2110+
targetAttrs = lappend_int(targetAttrs, col);
2111+
}
2112+
2113+
return targetAttrs;
2114+
}

mysql_init.sh

Lines changed: 3 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -29,14 +29,16 @@ mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e
2929
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "DROP TABLE IF EXISTS student;"
3030
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "DROP TABLE IF EXISTS numbers;"
3131
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "DROP TABLE IF EXISTS enum_t1;"
32+
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "DROP TABLE IF EXISTS student1;"
3233

3334
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE mysql_test(a int primary key, b int);"
3435
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "INSERT INTO mysql_test(a,b) VALUES (1,1);"
3536
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE empdata (emp_id int, emp_dat blob, PRIMARY KEY (emp_id));"
3637
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE numbers (a int PRIMARY KEY, b varchar(255));"
3738
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE test_tbl1 (c1 INT primary key, c2 VARCHAR(10), c3 CHAR(9), c4 MEDIUMINT, c5 DATE, c6 DECIMAL(10,5), c7 INT, c8 SMALLINT);"
3839
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE test_tbl2 (c1 INT primary key, c2 TEXT, c3 TEXT);"
39-
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "CREATE TABLE student (stu_id int PRIMARY KEY, stu_name text);"
40+
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "CREATE TABLE student (stu_id int PRIMARY KEY, stu_name text, stu_dept int);"
4041
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "CREATE TABLE numbers (a int, b varchar(255));"
4142
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE enum_t1 (id int PRIMARY KEY, size ENUM('small', 'medium', 'large'));"
4243
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "INSERT INTO enum_t1 VALUES (1, 'small'),(2, 'medium'),(3, 'medium');"
44+
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "CREATE TABLE student1 (stu_id varchar(10) PRIMARY KEY, stu_name text, stu_dept int);"

0 commit comments

Comments
 (0)