Skip to content

Commit a2932f4

Browse files
committed
Fix issue while inserting to enum value column.
While binding value in mysql_bind_sql_var(), we map PG type id to the corresponding MySQL type in mysql_from_pgtyp() and then appropriately create a buffer containing the value. However, this logic only cares about the built-in types and as enum has a user-defined type, it resulted in an error. To support bind for enum values, if the type is an enum then use ANYENUMOID builtin type and convert the value to string form using its output function. MySQL accepts enum value in string form so we map ANYENUMOID to MYSQL_TYPE_STRING too. Note that we set sql_mode to ANSI_QUOTES while creating a connection with MySQL that causes to insert an empty string at MySQL side for the enum column when the given enum value is not present. And thus, to select from such a table having enum value as '', we need to create an enum type at Postgres side with all valid values and ''. Also, if we try to insert an enum value which is not present in PG's enum type, then PG's sanity check itself throws an error. FDW-169, Suraj Kharage, reviewed by Jeevan Ladhe.
1 parent 420dd25 commit a2932f4

File tree

4 files changed

+92
-1
lines changed

4 files changed

+92
-1
lines changed

expected/select.out

Lines changed: 52 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1033,6 +1033,57 @@ SELECT t1.c1, t2.c1
10331033

10341034
DELETE FROM f_test_tbl2 WHERE c1 IN (50, 60);
10351035
ALTER SERVER mysql_svr OPTIONS (SET use_remote_estimate 'false');
1036+
-- FDW-169: Insert/Update/Delete on enum column.
1037+
INSERT INTO f_enum_t1
1038+
VALUES (1, 'small'), (2, 'medium'), (3, 'medium'), (4, 'small');
1039+
SELECT * FROM f_enum_t1 WHERE id = 4;
1040+
id | size
1041+
----+-------
1042+
4 | small
1043+
(1 row)
1044+
1045+
UPDATE f_enum_t1 SET size = 'large' WHERE id = 4;
1046+
SELECT * FROM f_enum_t1 WHERE id = 4;
1047+
id | size
1048+
----+-------
1049+
4 | large
1050+
(1 row)
1051+
1052+
DELETE FROM f_enum_t1 WHERE size = 'large';
1053+
SELECT * FROM f_enum_t1 WHERE id = 4;
1054+
id | size
1055+
----+------
1056+
(0 rows)
1057+
1058+
-- Negative scenarios for ENUM handling.
1059+
-- Test that if we insert the ENUM value which is not present on MySQL side,
1060+
-- but present on Postgres side.
1061+
DROP FOREIGN TABLE f_enum_t1;
1062+
DROP TYPE size_t;
1063+
-- Create the type with extra enum values.
1064+
CREATE TYPE size_t AS enum('small', 'medium', 'large', 'largest', '');
1065+
CREATE FOREIGN TABLE f_enum_t1(id int, size size_t)
1066+
SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'enum_t1');
1067+
-- If we insert the enum value which is not present on MySQL side then it
1068+
-- inserts empty string in ANSI_QUOTES sql_mode, so verify that.
1069+
INSERT INTO f_enum_t1 VALUES (4, 'largest');
1070+
SELECT * from f_enum_t1;
1071+
id | size
1072+
----+--------
1073+
1 | small
1074+
2 | medium
1075+
3 | medium
1076+
4 |
1077+
(4 rows)
1078+
1079+
DELETE FROM f_enum_t1 WHERE size = '';
1080+
-- Postgres should throw an error as the value which we are inserting for enum
1081+
-- column is not present in enum on Postgres side, no matter whether it is
1082+
-- present on MySQL side or not. PG's sanity check itself throws an error.
1083+
INSERT INTO f_enum_t1 VALUES (4, 'big');
1084+
ERROR: invalid input value for enum size_t: "big"
1085+
LINE 1: INSERT INTO f_enum_t1 VALUES (4, 'big');
1086+
^
10361087
-- FDW-155: Enum data type can be handled correctly in select statements on
10371088
-- foreign table.
10381089
SELECT * FROM f_enum_t1 WHERE size = 'medium' ORDER BY id;
@@ -1251,6 +1302,7 @@ DROP VIEW mul_tbl_view;
12511302
DELETE FROM f_test_tbl1;
12521303
DELETE FROM f_test_tbl2;
12531304
DELETE FROM f_numbers;
1305+
DELETE FROM f_enum_t1;
12541306
DROP FOREIGN TABLE f_test_tbl1;
12551307
DROP FOREIGN TABLE f_test_tbl2;
12561308
DROP FOREIGN TABLE f_numbers;

mysql_init.sh

Lines changed: 0 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -41,7 +41,6 @@ mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e
4141
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);"
4242
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress1 -e "CREATE TABLE numbers (a int, b varchar(255));"
4343
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'));"
44-
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');"
4544
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);"
4645
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "CREATE TABLE enum_t2 (id int PRIMARY KEY, size ENUM('S', 'M', 'L'));"
4746
mysql -h $MYSQL_HOST -u $MYSQL_USER_NAME -P $MYSQL_PORT -D mysql_fdw_regress -e "INSERT INTO enum_t2 VALUES (10, 'S'),(20, 'M'),(30, 'M');"

mysql_query.c

Lines changed: 9 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -144,6 +144,7 @@ mysql_from_pgtyp(Oid type)
144144
case VARCHAROID:
145145
case TEXTOID:
146146
case JSONOID:
147+
case ANYENUMOID:
147148
return MYSQL_TYPE_STRING;
148149
case NAMEOID:
149150
return MYSQL_TYPE_STRING;
@@ -188,6 +189,13 @@ mysql_bind_sql_var(Oid type, int attnum, Datum value, MYSQL_BIND *binds,
188189
if (*isnull)
189190
return;
190191

192+
/*
193+
* If type is an enum, use ANYENUMOID. We will send string containing the
194+
* enum value to the MySQL.
195+
*/
196+
if (type_is_enum(type))
197+
type = ANYENUMOID;
198+
191199
/* Assign the buffer type if value is not null */
192200
binds[attnum].buffer_type = mysql_from_pgtyp(type);
193201

@@ -269,6 +277,7 @@ mysql_bind_sql_var(Oid type, int attnum, Datum value, MYSQL_BIND *binds,
269277
case VARCHAROID:
270278
case TEXTOID:
271279
case JSONOID:
280+
case ANYENUMOID:
272281
{
273282
char *outputString = NULL;
274283
Oid outputFunctionId = InvalidOid;

sql/select.sql

Lines changed: 31 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -260,6 +260,36 @@ SELECT t1.c1, t2.c1
260260
DELETE FROM f_test_tbl2 WHERE c1 IN (50, 60);
261261
ALTER SERVER mysql_svr OPTIONS (SET use_remote_estimate 'false');
262262

263+
-- FDW-169: Insert/Update/Delete on enum column.
264+
INSERT INTO f_enum_t1
265+
VALUES (1, 'small'), (2, 'medium'), (3, 'medium'), (4, 'small');
266+
SELECT * FROM f_enum_t1 WHERE id = 4;
267+
UPDATE f_enum_t1 SET size = 'large' WHERE id = 4;
268+
SELECT * FROM f_enum_t1 WHERE id = 4;
269+
DELETE FROM f_enum_t1 WHERE size = 'large';
270+
SELECT * FROM f_enum_t1 WHERE id = 4;
271+
272+
-- Negative scenarios for ENUM handling.
273+
-- Test that if we insert the ENUM value which is not present on MySQL side,
274+
-- but present on Postgres side.
275+
DROP FOREIGN TABLE f_enum_t1;
276+
DROP TYPE size_t;
277+
-- Create the type with extra enum values.
278+
CREATE TYPE size_t AS enum('small', 'medium', 'large', 'largest', '');
279+
CREATE FOREIGN TABLE f_enum_t1(id int, size size_t)
280+
SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'enum_t1');
281+
282+
-- If we insert the enum value which is not present on MySQL side then it
283+
-- inserts empty string in ANSI_QUOTES sql_mode, so verify that.
284+
INSERT INTO f_enum_t1 VALUES (4, 'largest');
285+
SELECT * from f_enum_t1;
286+
DELETE FROM f_enum_t1 WHERE size = '';
287+
288+
-- Postgres should throw an error as the value which we are inserting for enum
289+
-- column is not present in enum on Postgres side, no matter whether it is
290+
-- present on MySQL side or not. PG's sanity check itself throws an error.
291+
INSERT INTO f_enum_t1 VALUES (4, 'big');
292+
263293
-- FDW-155: Enum data type can be handled correctly in select statements on
264294
-- foreign table.
265295
SELECT * FROM f_enum_t1 WHERE size = 'medium' ORDER BY id;
@@ -337,6 +367,7 @@ DROP VIEW mul_tbl_view;
337367
DELETE FROM f_test_tbl1;
338368
DELETE FROM f_test_tbl2;
339369
DELETE FROM f_numbers;
370+
DELETE FROM f_enum_t1;
340371
DROP FOREIGN TABLE f_test_tbl1;
341372
DROP FOREIGN TABLE f_test_tbl2;
342373
DROP FOREIGN TABLE f_numbers;

0 commit comments

Comments
 (0)