Skip to content

Commit 7b81a18

Browse files
committed
Fix ReScanForeignScan API to make the parameterized query work
correctly. Sub-select or correlated queries that use a parameterized plan uses ReScanForeignScan API. However, this API is not correctly rescanning the data. In the case of parameters, we need to bind the new param values after processing them and need to re-execute the query. The patch does the same. In passing, refactor some code in this area and rename a few functions and variables to match the context. Reported on GitHub through issues #172 by JackWolfskind and #201 by lukesilvia. FDW-157, Suraj Kharage, reviewed by Jeevan Ladhe.
1 parent 83405fc commit 7b81a18

File tree

4 files changed

+133
-27
lines changed

4 files changed

+133
-27
lines changed

expected/select.out

Lines changed: 78 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -944,9 +944,86 @@ SELECT * FROM enum_t1 ORDER BY id;
944944
(3 rows)
945945

946946
DROP FOREIGN TABLE enum_t1;
947+
-- Parameterized queries should work correctly.
948+
EXPLAIN (VERBOSE, COSTS OFF)
949+
SELECT c1, c2 FROM f_test_tbl1
950+
WHERE c8 = (SELECT c1 FROM f_test_tbl2 WHERE c1 = (SELECT 20))
951+
ORDER BY c1;
952+
QUERY PLAN
953+
-------------------------------------------------------------------------------------------------
954+
Sort
955+
Output: f_test_tbl1.c1, f_test_tbl1.c2
956+
Sort Key: f_test_tbl1.c1
957+
InitPlan 2 (returns $1)
958+
-> Foreign Scan on public.f_test_tbl2
959+
Output: f_test_tbl2.c1
960+
Local server startup cost: 10
961+
Remote query: SELECT `c1` FROM `mysql_fdw_regress`.`test_tbl2` WHERE ((`c1` = ?))
962+
InitPlan 1 (returns $0)
963+
-> Result
964+
Output: 20
965+
-> Foreign Scan on public.f_test_tbl1
966+
Output: f_test_tbl1.c1, f_test_tbl1.c2
967+
Local server startup cost: 10
968+
Remote query: SELECT `c1`, `c2` FROM `mysql_fdw_regress`.`test_tbl1` WHERE ((`c8` = ?))
969+
(15 rows)
970+
971+
SELECT c1, c2 FROM f_test_tbl1
972+
WHERE c8 = (SELECT c1 FROM f_test_tbl2 WHERE c1 = (SELECT 20))
973+
ORDER BY c1;
974+
c1 | c2
975+
------+-------
976+
100 | EMP1
977+
400 | EMP4
978+
800 | EMP8
979+
1100 | EMP11
980+
1300 | EMP13
981+
(5 rows)
982+
983+
SELECT * FROM f_test_tbl1
984+
WHERE c8 NOT IN (SELECT c1 FROM f_test_tbl2 WHERE c1 = (SELECT 20))
985+
ORDER BY c1;
986+
c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
987+
------+-------+----------+-----+------------+------------+------+----
988+
200 | EMP2 | SALESMAN | 600 | 1981-02-20 | 1600.00000 | 300 | 30
989+
300 | EMP3 | SALESMAN | 600 | 1981-02-22 | 1250.00000 | 500 | 30
990+
500 | EMP5 | SALESMAN | 600 | 1981-09-28 | 1250.00000 | 1400 | 30
991+
600 | EMP6 | MANAGER | 900 | 1981-05-01 | 2850.00000 | | 30
992+
700 | EMP7 | MANAGER | 900 | 1981-06-09 | 2450.45000 | | 10
993+
900 | EMP9 | HEAD | | 1981-11-17 | 5000.00000 | | 10
994+
1000 | EMP10 | SALESMAN | 600 | 1980-09-08 | 1500.00000 | 0 | 30
995+
1200 | EMP12 | ADMIN | 600 | 1981-12-03 | 950.00000 | | 30
996+
1400 | EMP14 | ADMIN | 700 | 1982-01-23 | 1300.00000 | | 10
997+
(9 rows)
998+
999+
-- Check parameterized queries with text/varchar column, should not crash.
1000+
CREATE FOREIGN TABLE f_test_tbl3 (c1 INTEGER, c2 text, c3 text)
1001+
SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'test_tbl2');
1002+
CREATE TABLE local_t1 (c1 INTEGER, c2 text);
1003+
INSERT INTO local_t1 VALUES (1, 'SALES');
1004+
SELECT c1, c2 FROM f_test_tbl3 WHERE c3 = (SELECT 'PUNE'::text) ORDER BY c1;
1005+
c1 | c2
1006+
----+-------------
1007+
10 | DEVELOPMENT
1008+
(1 row)
1009+
1010+
SELECT c1, c2 FROM f_test_tbl2 WHERE c3 = (SELECT 'PUNE'::varchar) ORDER BY c1;
1011+
c1 | c2
1012+
----+-------------
1013+
10 | DEVELOPMENT
1014+
(1 row)
1015+
1016+
SELECT * FROM local_t1 lt1 WHERE lt1.c1 =
1017+
(SELECT count(*) FROM f_test_tbl3 ft1 WHERE ft1.c2 = lt1.c2) ORDER BY lt1.c1;
1018+
c1 | c2
1019+
----+-------
1020+
1 | SALES
1021+
(1 row)
1022+
9471023
-- Cleanup
9481024
DROP TABLE l_test_tbl1;
9491025
DROP TABLE l_test_tbl2;
1026+
DROP TABLE local_t1;
9501027
DROP VIEW smpl_vw;
9511028
DROP VIEW comp_vw;
9521029
DROP VIEW ttest_tbl1_vw;
@@ -959,6 +1036,7 @@ DROP FOREIGN TABLE f_test_tbl2;
9591036
DROP FOREIGN TABLE f_numbers;
9601037
DROP FOREIGN TABLE f_mysql_test;
9611038
DROP FOREIGN TABLE f_enum_t1;
1039+
DROP FOREIGN TABLE f_test_tbl3;
9621040
DROP TYPE size_t;
9631041
DROP FUNCTION test_param_where();
9641042
DROP FUNCTION test_param_where2(int, text);

mysql_fdw.c

Lines changed: 27 additions & 26 deletions
Original file line numberDiff line numberDiff line change
@@ -207,7 +207,7 @@ static void process_query_params(ExprContext *econtext,
207207
MYSQL_BIND **mysql_bind_buf,
208208
Oid *param_types);
209209

210-
static void create_cursor(ForeignScanState *node);
210+
static void bind_stmt_params_and_exec(ForeignScanState *node);
211211

212212
void *mysql_dll_handle = NULL;
213213
static int wait_timeout = WAIT_TIMEOUT;
@@ -475,7 +475,7 @@ mysqlBeginForeignScan(ForeignScanState *node, int eflags)
475475
festate->query = strVal(list_nth(fsplan->fdw_private, 0));
476476
festate->retrieved_attrs = list_nth(fsplan->fdw_private, 1);
477477
festate->conn = conn;
478-
festate->cursor_exists = false;
478+
festate->query_executed = false;
479479

480480
#if PG_VERSION_NUM >= 110000
481481
festate->temp_cxt = AllocSetContextCreate(estate->es_query_cxt,
@@ -530,13 +530,6 @@ mysqlBeginForeignScan(ForeignScanState *node, int eflags)
530530
&festate->param_values,
531531
&festate->param_types);
532532

533-
/*
534-
* If this is the first call after Begin or ReScan, we need to create the
535-
* cursor on the remote side.
536-
*/
537-
if (!festate->cursor_exists)
538-
create_cursor(node);
539-
540533
/* int column_count = mysql_num_fields(festate->meta); */
541534

542535
/* Set the statement as cursor type */
@@ -579,13 +572,6 @@ mysqlBeginForeignScan(ForeignScanState *node, int eflags)
579572
/* Bind the results pointers for the prepare statements */
580573
if (mysql_stmt_bind_result(festate->stmt, festate->table->mysql_bind) != 0)
581574
mysql_stmt_error_print(festate, "failed to bind the MySQL query");
582-
583-
/*
584-
* Finally execute the query and result will be placed in the array we
585-
* already bind
586-
*/
587-
if (mysql_stmt_execute(festate->stmt) != 0)
588-
mysql_stmt_error_print(festate, "failed to execute the MySQL query");
589575
}
590576

591577
/*
@@ -608,6 +594,13 @@ mysqlIterateForeignScan(ForeignScanState *node)
608594

609595
ExecClearTuple(tupleSlot);
610596

597+
/*
598+
* If this is the first call after Begin or ReScan, we need to bind the
599+
* params and execute the query.
600+
*/
601+
if (!festate->query_executed)
602+
bind_stmt_params_and_exec(node);
603+
611604
attid = 0;
612605
rc = mysql_stmt_fetch(festate->stmt);
613606
if (rc == 0)
@@ -723,12 +716,12 @@ mysqlReScanForeignScan(ForeignScanState *node)
723716
{
724717
MySQLFdwExecState *festate = (MySQLFdwExecState *) node->fdw_state;
725718

726-
/* If we haven't created the cursor yet, nothing to do. */
727-
if (!festate->cursor_exists)
728-
return;
719+
/*
720+
* Set the query_executed flag to false so that the query will be executed
721+
* in mysqlIterateForeignScan().
722+
*/
723+
festate->query_executed = false;
729724

730-
if (mysql_stmt_execute(festate->stmt) != 0)
731-
mysql_stmt_error_print(festate, "failed to execute the MySQL query");
732725
}
733726

734727
/*
@@ -1908,10 +1901,11 @@ process_query_params(ExprContext *econtext,
19081901
}
19091902

19101903
/*
1911-
* Create cursor for node's query with current parameter values.
1904+
* Process the query params and bind the same with the statement, if any.
1905+
* Also, execute the statement.
19121906
*/
19131907
static void
1914-
create_cursor(ForeignScanState *node)
1908+
bind_stmt_params_and_exec(ForeignScanState *node)
19151909
{
19161910
MySQLFdwExecState *festate = (MySQLFdwExecState *) node->fdw_state;
19171911
ExprContext *econtext = node->ss.ps.ps_ExprContext;
@@ -1941,11 +1935,18 @@ create_cursor(ForeignScanState *node)
19411935

19421936
mysql_stmt_bind_param(festate->stmt, mysql_bind_buffer);
19431937

1944-
/* Mark the cursor as created, and show no tuples have been retrieved */
1945-
festate->cursor_exists = true;
1946-
19471938
MemoryContextSwitchTo(oldcontext);
19481939
}
1940+
1941+
/*
1942+
* Finally, execute the query. The result will be placed in the array we
1943+
* already bind.
1944+
*/
1945+
if (mysql_stmt_execute(festate->stmt) != 0)
1946+
mysql_stmt_error_print(festate, "failed to execute the MySQL query");
1947+
1948+
/* Mark the query as executed */
1949+
festate->query_executed = true;
19491950
}
19501951

19511952
Datum

mysql_fdw.h

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -135,7 +135,7 @@ typedef struct MySQLFdwExecState
135135
char *query; /* Query string */
136136
Relation rel; /* relcache entry for the foreign table */
137137
List *retrieved_attrs; /* list of target attribute numbers */
138-
bool cursor_exists; /* have we created the cursor? */
138+
bool query_executed; /* have we executed the query? */
139139
int numParams; /* number of parameters passed to query */
140140
FmgrInfo *param_flinfo; /* output conversion functions for them */
141141
List *param_exprs; /* executable expressions for param values */

sql/select.sql

Lines changed: 27 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -237,9 +237,35 @@ IMPORT FOREIGN SCHEMA mysql_fdw_regress LIMIT TO (enum_t1) FROM SERVER mysql_svr
237237
SELECT * FROM enum_t1 ORDER BY id;
238238
DROP FOREIGN TABLE enum_t1;
239239

240+
-- Parameterized queries should work correctly.
241+
EXPLAIN (VERBOSE, COSTS OFF)
242+
SELECT c1, c2 FROM f_test_tbl1
243+
WHERE c8 = (SELECT c1 FROM f_test_tbl2 WHERE c1 = (SELECT 20))
244+
ORDER BY c1;
245+
SELECT c1, c2 FROM f_test_tbl1
246+
WHERE c8 = (SELECT c1 FROM f_test_tbl2 WHERE c1 = (SELECT 20))
247+
ORDER BY c1;
248+
249+
SELECT * FROM f_test_tbl1
250+
WHERE c8 NOT IN (SELECT c1 FROM f_test_tbl2 WHERE c1 = (SELECT 20))
251+
ORDER BY c1;
252+
253+
-- Check parameterized queries with text/varchar column, should not crash.
254+
CREATE FOREIGN TABLE f_test_tbl3 (c1 INTEGER, c2 text, c3 text)
255+
SERVER mysql_svr OPTIONS (dbname 'mysql_fdw_regress', table_name 'test_tbl2');
256+
CREATE TABLE local_t1 (c1 INTEGER, c2 text);
257+
INSERT INTO local_t1 VALUES (1, 'SALES');
258+
259+
SELECT c1, c2 FROM f_test_tbl3 WHERE c3 = (SELECT 'PUNE'::text) ORDER BY c1;
260+
SELECT c1, c2 FROM f_test_tbl2 WHERE c3 = (SELECT 'PUNE'::varchar) ORDER BY c1;
261+
262+
SELECT * FROM local_t1 lt1 WHERE lt1.c1 =
263+
(SELECT count(*) FROM f_test_tbl3 ft1 WHERE ft1.c2 = lt1.c2) ORDER BY lt1.c1;
264+
240265
-- Cleanup
241266
DROP TABLE l_test_tbl1;
242267
DROP TABLE l_test_tbl2;
268+
DROP TABLE local_t1;
243269
DROP VIEW smpl_vw;
244270
DROP VIEW comp_vw;
245271
DROP VIEW ttest_tbl1_vw;
@@ -252,6 +278,7 @@ DROP FOREIGN TABLE f_test_tbl2;
252278
DROP FOREIGN TABLE f_numbers;
253279
DROP FOREIGN TABLE f_mysql_test;
254280
DROP FOREIGN TABLE f_enum_t1;
281+
DROP FOREIGN TABLE f_test_tbl3;
255282
DROP TYPE size_t;
256283
DROP FUNCTION test_param_where();
257284
DROP FUNCTION test_param_where2(int, text);

0 commit comments

Comments
 (0)