From 32151be328ef67cc85f65e35c9c73506ffc84e36 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Wed, 23 Oct 2019 18:07:21 +0200 Subject: [PATCH 01/10] Skeleton for a set-returning-function (SRF) --- contrib/postgres_fdw/Makefile | 2 +- .../postgres_fdw/postgres_fdw--1.0--1.1.sql | 7 +++ contrib/postgres_fdw/postgres_fdw--1.1.sql | 21 +++++++++ contrib/postgres_fdw/postgres_fdw.c | 44 +++++++++++++++++++ contrib/postgres_fdw/postgres_fdw.control | 2 +- 5 files changed, 74 insertions(+), 2 deletions(-) create mode 100644 contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1.sql diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile index 85394b4f1f0f6..85a4ecb9007ef 100644 --- a/contrib/postgres_fdw/Makefile +++ b/contrib/postgres_fdw/Makefile @@ -8,7 +8,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir) SHLIB_LINK_INTERNAL = $(libpq) EXTENSION = postgres_fdw -DATA = postgres_fdw--1.0.sql +DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1.sql REGRESS = postgres_fdw diff --git a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql new file mode 100644 index 0000000000000..15a7c83519bbb --- /dev/null +++ b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql @@ -0,0 +1,7 @@ +-- complain if script is sourced in psql, rather than via CREATE EXTENSION +\echo Use "CREATE EXTENSION postgres_fdw" to load this file. \quit + +CREATE FUNCTION postgres_fdw_query(server name, sql text) +RETURNS SETOF record +AS 'MODULE_PATHNAME' +LANGUAGE C STRICT; diff --git a/contrib/postgres_fdw/postgres_fdw--1.1.sql b/contrib/postgres_fdw/postgres_fdw--1.1.sql new file mode 100644 index 0000000000000..1f4dd1f32b131 --- /dev/null +++ b/contrib/postgres_fdw/postgres_fdw--1.1.sql @@ -0,0 +1,21 @@ +-- complain if script is sourced in psql, rather than via CREATE EXTENSION +\echo Use "CREATE EXTENSION postgres_fdw" to load this file. \quit + +CREATE FUNCTION postgres_fdw_handler() +RETURNS fdw_handler +AS 'MODULE_PATHNAME' +LANGUAGE C STRICT; + +CREATE FUNCTION postgres_fdw_validator(text[], oid) +RETURNS void +AS 'MODULE_PATHNAME' +LANGUAGE C STRICT; + +CREATE FUNCTION postgres_fdw_query(server name, sql text) +RETURNS SETOF record +AS 'MODULE_PATHNAME' +LANGUAGE C STRICT; + +CREATE FOREIGN DATA WRAPPER postgres_fdw + HANDLER postgres_fdw_handler + VALIDATOR postgres_fdw_validator; diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c index 025f922b4c670..caebef8d6275f 100644 --- a/contrib/postgres_fdw/postgres_fdw.c +++ b/contrib/postgres_fdw/postgres_fdw.c @@ -5900,3 +5900,47 @@ find_em_expr_for_rel(EquivalenceClass *ec, RelOptInfo *rel) /* We didn't find any suitable equivalence class expression */ return NULL; } + + + +PG_FUNCTION_INFO_V1(postgres_fdw_query); + +Datum +postgres_fdw_query(PG_FUNCTION_ARGS) +{ + FuncCallContext *funcctx; + + if (SRF_IS_FIRSTCALL()) + { + MemoryContext oldcontext; + + funcctx = SRF_FIRSTCALL_INIT(); + oldcontext = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx); + /* One-time setup code appears here: */ + /* user code */ + /* if returning composite */ + /* build TupleDesc, and perhaps AttInMetadata */ + /* endif returning composite */ + /* user code */ + MemoryContextSwitchTo(oldcontext); + } + + /* Each-time setup code appears here: */ + //user code + funcctx = SRF_PERCALL_SETUP(); + + /* this is just one way we might test whether we are done: */ + /* if (funcctx->call_cntr < funcctx->max_calls) */ + /* { */ + /* /\* Here we want to return another item: *\/ */ + /* user code */ + /* obtain result Datum */ + /* SRF_RETURN_NEXT(funcctx, result); */ + /* } */ + /* else */ + { + /* Here we are done returning items and just need to clean up: */ + //user code + SRF_RETURN_DONE(funcctx); + } +} diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control index f9ed490752b0a..d489382064cfb 100644 --- a/contrib/postgres_fdw/postgres_fdw.control +++ b/contrib/postgres_fdw/postgres_fdw.control @@ -1,5 +1,5 @@ # postgres_fdw extension comment = 'foreign-data wrapper for remote PostgreSQL servers' -default_version = '1.0' +default_version = '1.1' module_pathname = '$libdir/postgres_fdw' relocatable = true From 150a47d2da9127db78779d9e7640f63f573758be Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Wed, 23 Oct 2019 18:39:10 +0200 Subject: [PATCH 02/10] Retrieve input args and spit debug traces --- contrib/postgres_fdw/postgres_fdw.c | 11 ++++++++++- 1 file changed, 10 insertions(+), 1 deletion(-) diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c index caebef8d6275f..174b6afc86e78 100644 --- a/contrib/postgres_fdw/postgres_fdw.c +++ b/contrib/postgres_fdw/postgres_fdw.c @@ -5909,6 +5909,8 @@ Datum postgres_fdw_query(PG_FUNCTION_ARGS) { FuncCallContext *funcctx; + Name server; + text *sql; if (SRF_IS_FIRSTCALL()) { @@ -5917,7 +5919,14 @@ postgres_fdw_query(PG_FUNCTION_ARGS) funcctx = SRF_FIRSTCALL_INIT(); oldcontext = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx); /* One-time setup code appears here: */ - /* user code */ + + // get input args + server = PG_GETARG_NAME(0); + sql = PG_GETARG_TEXT_P(1); + + elog(DEBUG3, "server = %s", NameStr(*server)); + elog(DEBUG3, "sql = %s", text_to_cstring(sql)); + /* if returning composite */ /* build TupleDesc, and perhaps AttInMetadata */ /* endif returning composite */ From 7512f9066a8f52e586291b9e0af8f935242be442 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Thu, 24 Oct 2019 10:19:14 +0200 Subject: [PATCH 03/10] Get a connection to the foreign server --- contrib/postgres_fdw/postgres_fdw.c | 23 +++++++++++++++++++---- 1 file changed, 19 insertions(+), 4 deletions(-) diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c index 174b6afc86e78..5b004bfa18ae6 100644 --- a/contrib/postgres_fdw/postgres_fdw.c +++ b/contrib/postgres_fdw/postgres_fdw.c @@ -5908,9 +5908,13 @@ PG_FUNCTION_INFO_V1(postgres_fdw_query); Datum postgres_fdw_query(PG_FUNCTION_ARGS) { - FuncCallContext *funcctx; - Name server; - text *sql; + FuncCallContext *funcctx; + Name server; + text *sql; + Oid userid; + PGconn *conn; + UserMapping *user_mapping; + ForeignServer *foreign_server; if (SRF_IS_FIRSTCALL()) { @@ -5920,13 +5924,24 @@ postgres_fdw_query(PG_FUNCTION_ARGS) oldcontext = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx); /* One-time setup code appears here: */ - // get input args + // Get input args server = PG_GETARG_NAME(0); sql = PG_GETARG_TEXT_P(1); elog(DEBUG3, "server = %s", NameStr(*server)); elog(DEBUG3, "sql = %s", text_to_cstring(sql)); + // Get a connection to the server with the current user + userid = GetUserId(); + foreign_server = GetForeignServerByName(NameStr(*server), false); + user_mapping = GetUserMapping(userid, foreign_server->serverid); + conn = GetConnection(user_mapping, false); + + // TODO: Execute the sql query + + ReleaseConnection(conn); + + /* if returning composite */ /* build TupleDesc, and perhaps AttInMetadata */ /* endif returning composite */ From 74e08f8c6d715d9199414ec71f01bc733145d85e Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Thu, 24 Oct 2019 10:43:31 +0200 Subject: [PATCH 04/10] Execute the query on the conn to the foreign server --- contrib/postgres_fdw/postgres_fdw.c | 36 ++++++++++++++++++++++------- 1 file changed, 28 insertions(+), 8 deletions(-) diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c index 5b004bfa18ae6..a3fead6782ed1 100644 --- a/contrib/postgres_fdw/postgres_fdw.c +++ b/contrib/postgres_fdw/postgres_fdw.c @@ -5909,12 +5909,15 @@ Datum postgres_fdw_query(PG_FUNCTION_ARGS) { FuncCallContext *funcctx; - Name server; - text *sql; + Name server_name; + text *sql_text; + char *server; + char *sql; Oid userid; PGconn *conn; UserMapping *user_mapping; ForeignServer *foreign_server; + PGresult *res = NULL; if (SRF_IS_FIRSTCALL()) { @@ -5925,19 +5928,36 @@ postgres_fdw_query(PG_FUNCTION_ARGS) /* One-time setup code appears here: */ // Get input args - server = PG_GETARG_NAME(0); - sql = PG_GETARG_TEXT_P(1); + server_name = PG_GETARG_NAME(0); + sql_text = PG_GETARG_TEXT_P(1); - elog(DEBUG3, "server = %s", NameStr(*server)); - elog(DEBUG3, "sql = %s", text_to_cstring(sql)); + server = NameStr(*server_name); + sql = text_to_cstring(sql_text); + + elog(DEBUG3, "server = %s", server); + elog(DEBUG3, "sql = %s", sql); // Get a connection to the server with the current user userid = GetUserId(); - foreign_server = GetForeignServerByName(NameStr(*server), false); + foreign_server = GetForeignServerByName(server, false); user_mapping = GetUserMapping(userid, foreign_server->serverid); conn = GetConnection(user_mapping, false); - // TODO: Execute the sql query + // Execute the sql query + PG_TRY(); + { + res = pgfdw_exec_query(conn, sql); + if (PQresultStatus(res) != PGRES_TUPLES_OK) + pgfdw_report_error(ERROR, res, conn, false, sql); + + } + PG_CATCH(); + { + if (res) + PQclear(res); + PG_RE_THROW(); + } + PG_END_TRY(); ReleaseConnection(conn); From 5ccc601ca6cd150641ab75d23794edc090ae2600 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Thu, 24 Oct 2019 16:58:39 +0200 Subject: [PATCH 05/10] Check remote query results match function expectations (from dblink) --- contrib/postgres_fdw/postgres_fdw.c | 38 ++++++++++++++++++++++++++++- 1 file changed, 37 insertions(+), 1 deletion(-) diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c index a3fead6782ed1..be5ae020efd0a 100644 --- a/contrib/postgres_fdw/postgres_fdw.c +++ b/contrib/postgres_fdw/postgres_fdw.c @@ -5918,6 +5918,9 @@ postgres_fdw_query(PG_FUNCTION_ARGS) UserMapping *user_mapping; ForeignServer *foreign_server; PGresult *res = NULL; + TupleDesc tupdesc; + int ntuples; + int nfields; if (SRF_IS_FIRSTCALL()) { @@ -5929,7 +5932,7 @@ postgres_fdw_query(PG_FUNCTION_ARGS) // Get input args server_name = PG_GETARG_NAME(0); - sql_text = PG_GETARG_TEXT_P(1); + sql_text = PG_GETARG_TEXT_PP(1); server = NameStr(*server_name); sql = text_to_cstring(sql_text); @@ -5947,9 +5950,42 @@ postgres_fdw_query(PG_FUNCTION_ARGS) PG_TRY(); { res = pgfdw_exec_query(conn, sql); + nfields = PQnfields(res); if (PQresultStatus(res) != PGRES_TUPLES_OK) pgfdw_report_error(ERROR, res, conn, false, sql); + /* get a tuple descriptor for our result type */ + switch (get_call_result_type(fcinfo, NULL, &tupdesc)) + { + case TYPEFUNC_COMPOSITE: + /* success */ + break; + case TYPEFUNC_RECORD: + /* failed to determine actual type of RECORD */ + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("function returning record called in context " + "that cannot accept type record"))); + break; + default: + /* result type isn't composite */ + elog(ERROR, "return type must be a row type"); + break; + } + + /* make sure we have a persistent copy of the tupdesc */ + tupdesc = CreateTupleDescCopy(tupdesc); + ntuples = PQntuples(res); + nfields = PQnfields(res); + + /* check result and tuple descriptor have the same number of columns */ + if (nfields != tupdesc->natts) + ereport(ERROR, + (errcode(ERRCODE_DATATYPE_MISMATCH), + errmsg("remote query result rowtype does not match " + "the specified FROM clause rowtype"))); + + } PG_CATCH(); { From 567f7b3da7cdd7b787168e3d1631772f77bb1785 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Thu, 24 Oct 2019 17:25:18 +0200 Subject: [PATCH 06/10] Create a tuple store to return the result returned by libpq Remove SRF calls, which make actually harder to manage memory contexts, depending on the approach we take. Copy some patterns and code from dblink to achieve what we want: get an appropriate TupleDesc and TupleStore to store what we get from a sync call through libpq. --- contrib/postgres_fdw/postgres_fdw.c | 211 +++++++++++++++++----------- 1 file changed, 127 insertions(+), 84 deletions(-) diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c index be5ae020efd0a..a8689fe5916d1 100644 --- a/contrib/postgres_fdw/postgres_fdw.c +++ b/contrib/postgres_fdw/postgres_fdw.c @@ -5903,12 +5903,14 @@ find_em_expr_for_rel(EquivalenceClass *ec, RelOptInfo *rel) +static void prepTuplestoreResult(FunctionCallInfo fcinfo); + PG_FUNCTION_INFO_V1(postgres_fdw_query); Datum postgres_fdw_query(PG_FUNCTION_ARGS) { - FuncCallContext *funcctx; + ReturnSetInfo *rsinfo; Name server_name; text *sql_text; char *server; @@ -5922,105 +5924,146 @@ postgres_fdw_query(PG_FUNCTION_ARGS) int ntuples; int nfields; - if (SRF_IS_FIRSTCALL()) - { - MemoryContext oldcontext; + prepTuplestoreResult(fcinfo); + rsinfo = (ReturnSetInfo *) fcinfo->resultinfo; + /* One-time setup code appears here: */ - funcctx = SRF_FIRSTCALL_INIT(); - oldcontext = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx); - /* One-time setup code appears here: */ + // Get input args + server_name = PG_GETARG_NAME(0); + sql_text = PG_GETARG_TEXT_PP(1); - // Get input args - server_name = PG_GETARG_NAME(0); - sql_text = PG_GETARG_TEXT_PP(1); + server = NameStr(*server_name); + sql = text_to_cstring(sql_text); - server = NameStr(*server_name); - sql = text_to_cstring(sql_text); + elog(DEBUG3, "server = %s", server); + elog(DEBUG3, "sql = %s", sql); - elog(DEBUG3, "server = %s", server); - elog(DEBUG3, "sql = %s", sql); + // Get a connection to the server with the current user + userid = GetUserId(); + foreign_server = GetForeignServerByName(server, false); + user_mapping = GetUserMapping(userid, foreign_server->serverid); + conn = GetConnection(user_mapping, false); - // Get a connection to the server with the current user - userid = GetUserId(); - foreign_server = GetForeignServerByName(server, false); - user_mapping = GetUserMapping(userid, foreign_server->serverid); - conn = GetConnection(user_mapping, false); + // Execute the sql query + PG_TRY(); + { + res = pgfdw_exec_query(conn, sql); + nfields = PQnfields(res); + if (PQresultStatus(res) != PGRES_TUPLES_OK) + pgfdw_report_error(ERROR, res, conn, false, sql); - // Execute the sql query - PG_TRY(); + /* get a tuple descriptor for our result type */ + switch (get_call_result_type(fcinfo, NULL, &tupdesc)) { - res = pgfdw_exec_query(conn, sql); - nfields = PQnfields(res); - if (PQresultStatus(res) != PGRES_TUPLES_OK) - pgfdw_report_error(ERROR, res, conn, false, sql); + case TYPEFUNC_COMPOSITE: + /* success */ + break; + case TYPEFUNC_RECORD: + /* failed to determine actual type of RECORD */ + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("function returning record called in context " + "that cannot accept type record"))); + break; + default: + /* result type isn't composite */ + elog(ERROR, "return type must be a row type"); + break; + } - /* get a tuple descriptor for our result type */ - switch (get_call_result_type(fcinfo, NULL, &tupdesc)) - { - case TYPEFUNC_COMPOSITE: - /* success */ - break; - case TYPEFUNC_RECORD: - /* failed to determine actual type of RECORD */ - ereport(ERROR, - (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("function returning record called in context " - "that cannot accept type record"))); - break; - default: - /* result type isn't composite */ - elog(ERROR, "return type must be a row type"); - break; - } + /* make sure we have a persistent copy of the tupdesc */ + tupdesc = CreateTupleDescCopy(tupdesc); + ntuples = PQntuples(res); + nfields = PQnfields(res); - /* make sure we have a persistent copy of the tupdesc */ - tupdesc = CreateTupleDescCopy(tupdesc); - ntuples = PQntuples(res); - nfields = PQnfields(res); + /* check result and tuple descriptor have the same number of columns */ + if (nfields != tupdesc->natts) + ereport(ERROR, + (errcode(ERRCODE_DATATYPE_MISMATCH), + errmsg("remote query result rowtype does not match " + "the specified FROM clause rowtype"))); - /* check result and tuple descriptor have the same number of columns */ - if (nfields != tupdesc->natts) - ereport(ERROR, - (errcode(ERRCODE_DATATYPE_MISMATCH), - errmsg("remote query result rowtype does not match " - "the specified FROM clause rowtype"))); + if (ntuples > 0) + { + AttInMetadata *attinmeta; + Tuplestorestate *tupstore; + MemoryContext oldcontext; + int row; + char **values; + attinmeta = TupleDescGetAttInMetadata(tupdesc); - } - PG_CATCH(); - { - if (res) - PQclear(res); - PG_RE_THROW(); - } - PG_END_TRY(); + oldcontext = MemoryContextSwitchTo( + rsinfo->econtext->ecxt_per_query_memory); + tupstore = tuplestore_begin_heap(true, false, work_mem); + rsinfo->setResult = tupstore; + rsinfo->setDesc = tupdesc; + MemoryContextSwitchTo(oldcontext); - ReleaseConnection(conn); + values = (char **) palloc(nfields * sizeof(char *)); + + /* put all tuples into the tuplestore */ + for (row = 0; row < ntuples; row++) + { + HeapTuple tuple; + int i; + for (i = 0; i < nfields; i++) + { + if (PQgetisnull(res, row, i)) + values[i] = NULL; + else + values[i] = PQgetvalue(res, row, i); + } - /* if returning composite */ - /* build TupleDesc, and perhaps AttInMetadata */ - /* endif returning composite */ - /* user code */ - MemoryContextSwitchTo(oldcontext); - } + /* build the tuple and put it into the tuplestore. */ + tuple = BuildTupleFromCStrings(attinmeta, values); + tuplestore_puttuple(tupstore, tuple); + } + + /* clean up and return the tuplestore */ + tuplestore_donestoring(tupstore); + } - /* Each-time setup code appears here: */ - //user code - funcctx = SRF_PERCALL_SETUP(); - - /* this is just one way we might test whether we are done: */ - /* if (funcctx->call_cntr < funcctx->max_calls) */ - /* { */ - /* /\* Here we want to return another item: *\/ */ - /* user code */ - /* obtain result Datum */ - /* SRF_RETURN_NEXT(funcctx, result); */ - /* } */ - /* else */ + PQclear(res); + } + PG_CATCH(); { - /* Here we are done returning items and just need to clean up: */ - //user code - SRF_RETURN_DONE(funcctx); + if (res) + PQclear(res); + PG_RE_THROW(); } + PG_END_TRY(); + + ReleaseConnection(conn); + return (Datum) 0; +} + +/* + * Verify function caller can handle a tuplestore result, and set up for that. + * + * Note: if the caller returns without actually creating a tuplestore, the + * executor will treat the function result as an empty set. + */ +static void +prepTuplestoreResult(FunctionCallInfo fcinfo) +{ + ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo; + + /* check to see if query supports us returning a tuplestore */ + if (rsinfo == NULL || !IsA(rsinfo, ReturnSetInfo)) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("set-valued function called in context that cannot accept a set"))); + if (!(rsinfo->allowedModes & SFRM_Materialize)) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("materialize mode required, but it is not allowed in this context"))); + + /* let the executor know we're sending back a tuplestore */ + rsinfo->returnMode = SFRM_Materialize; + + /* caller must fill these to return a non-empty result */ + rsinfo->setResult = NULL; + rsinfo->setDesc = NULL; } From e6930aa9795ac9be277a6bffb84e355233fe60ea Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Fri, 25 Oct 2019 11:36:36 +0200 Subject: [PATCH 07/10] Add tests for postgres_fdw_query --- .../postgres_fdw/expected/postgres_fdw.out | 57 +++++++++++++++++++ contrib/postgres_fdw/sql/postgres_fdw.sql | 28 +++++++++ 2 files changed, 85 insertions(+) diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out index 88dbaa2493f8a..c83d7271929c8 100644 --- a/contrib/postgres_fdw/expected/postgres_fdw.out +++ b/contrib/postgres_fdw/expected/postgres_fdw.out @@ -8801,3 +8801,60 @@ SELECT b, avg(a), max(a), count(*) FROM pagg_tab GROUP BY b HAVING sum(a) < 700 -- Clean-up RESET enable_partitionwise_aggregate; +-- =================================================================== +-- test postgres_fdw_query(server name, sql text) +-- =================================================================== +-- Most simple SELECT through postgres_fdw_query +SELECT * FROM postgres_fdw_query('loopback', 'SELECT 42') AS t(i int); + i +---- + 42 +(1 row) + +-- Select the effective role configured in the user mapping +SELECT * FROM postgres_fdw_query('loopback', 'SELECT current_user') + AS t(role_name name); + role_name +----------- + postgres +(1 row) + +-- Select schemas owned by the role configured in the user mapping +SELECT * FROM postgres_fdw_query('loopback', $$SELECT s.nspname + FROM pg_catalog.pg_namespace s + JOIN pg_catalog.pg_user u ON u.usesysid = s.nspowner + WHERE u.usename = current_user + ORDER BY s.nspname$$ +) AS schemas(schema_name name); + schema_name +-------------------- + S 1 + import_dest1 + import_dest2 + import_dest3 + import_dest4 + import_dest5 + import_source + information_schema + pg_catalog + pg_temp_1 + pg_toast + pg_toast_temp_1 + public +(13 rows) + +-- Select tables and views in a given foreign schema that the role +-- configured in the user mapping has access to +SELECT * FROM postgres_fdw_query('loopback', $$SELECT table_name, table_type + FROM information_schema.tables + WHERE table_schema = 'S 1' + ORDER BY table_name$$ +) AS schemas(table_name text, table_type text); + table_name | table_type +------------+------------ + T 1 | BASE TABLE + T 2 | BASE TABLE + T 3 | BASE TABLE + T 4 | BASE TABLE +(4 rows) + diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql index a87c57df7bf08..8e79ee205f182 100644 --- a/contrib/postgres_fdw/sql/postgres_fdw.sql +++ b/contrib/postgres_fdw/sql/postgres_fdw.sql @@ -2407,3 +2407,31 @@ SELECT b, avg(a), max(a), count(*) FROM pagg_tab GROUP BY b HAVING sum(a) < 700 -- Clean-up RESET enable_partitionwise_aggregate; + + +-- =================================================================== +-- test postgres_fdw_query(server name, sql text) +-- =================================================================== + +-- Most simple SELECT through postgres_fdw_query +SELECT * FROM postgres_fdw_query('loopback', 'SELECT 42') AS t(i int); + +-- Select the effective role configured in the user mapping +SELECT * FROM postgres_fdw_query('loopback', 'SELECT current_user') + AS t(role_name name); + +-- Select schemas owned by the role configured in the user mapping +SELECT * FROM postgres_fdw_query('loopback', $$SELECT s.nspname + FROM pg_catalog.pg_namespace s + JOIN pg_catalog.pg_user u ON u.usesysid = s.nspowner + WHERE u.usename = current_user + ORDER BY s.nspname$$ +) AS schemas(schema_name name); + +-- Select tables and views in a given foreign schema that the role +-- configured in the user mapping has access to +SELECT * FROM postgres_fdw_query('loopback', $$SELECT table_name, table_type + FROM information_schema.tables + WHERE table_schema = 'S 1' + ORDER BY table_name$$ +) AS schemas(table_name text, table_type text); From 6dbab1af2aa9dc5a983963d904a24008f0e0641b Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Mon, 28 Oct 2019 12:56:28 +0100 Subject: [PATCH 08/10] Remove test that depends on how it is executed I managed to reproduce the test failure in our CI: ``` $ make check-world ... ============== running regression test queries ============== test postgres_fdw ... FAILED ============== shutting down postmaster ============== ====================== 1 of 1 tests failed. ====================== The differences that caused some tests to fail can be viewed in the file "/home/rtorre/src/postgres/pg11_build/contrib/postgres_fdw/regression.diffs". A copy of the test summary that you see above is saved in the file "/home/rtorre/src/postgres/pg11_build/contrib/postgres_fdw/regression.out". /home/rtorre/src/postgres/pg11_build/../src/makefiles/pgxs.mk:412: recipe for target 'check' failed make[2]: *** [check] Error 1 make[2]: Leaving directory '/home/rtorre/src/postgres/pg11_build/contrib/postgres_fdw' Makefile:93: recipe for target 'check-postgres_fdw-recurse' failed make[1]: *** [check-postgres_fdw-recurse] Error 2 make[1]: Leaving directory '/home/rtorre/src/postgres/pg11_build/contrib' GNUmakefile:70: recipe for target 'check-world-contrib-recurse' failed make: *** [check-world-contrib-recurse] Error 2 ``` By looking at the diffs: ``` $ cat /home/rtorre/src/postgres/pg11_build/contrib/postgres_fdw/regression.diffs *** /home/rtorre/src/postgres/pg11_build/../contrib/postgres_fdw/expected/postgres_fdw.out 2019-10-25 15:12:57.866375535 +0200 --- /home/rtorre/src/postgres/pg11_build/contrib/postgres_fdw/results/postgres_fdw.out 2019-10-28 12:41:04.876038961 +0100 *************** *** 8816,8822 **** AS t(role_name name); role_name ----------- ! postgres (1 row) -- Select schemas owned by the role configured in the user mapping --- 8816,8822 ---- AS t(role_name name); role_name ----------- ! rtorre (1 row) -- Select schemas owned by the role configured in the user mapping ====================================================================== ``` but when it is executed from the contrib/postgres_fdw dir, it works as expeted (note in my env there's a PGUSER=postgres variable): ``` $ pwd /home/rtorre/src/postgres/pg11_build/contrib/postgres_fdw $ make clean all install installcheck ... ============== dropping database "contrib_regression" ============== DROP DATABASE ============== creating database "contrib_regression" ============== CREATE DATABASE ALTER DATABASE ============== running regression test queries ============== test postgres_fdw ... ok ===================== All 1 tests passed. ===================== ``` I'd rather remove this environment-dependent test (on CURRENT_USER) than review all makefiles and possible configurations. --- contrib/postgres_fdw/expected/postgres_fdw.out | 8 -------- contrib/postgres_fdw/sql/postgres_fdw.sql | 4 ---- 2 files changed, 12 deletions(-) diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out index c83d7271929c8..eb4a65afd7f19 100644 --- a/contrib/postgres_fdw/expected/postgres_fdw.out +++ b/contrib/postgres_fdw/expected/postgres_fdw.out @@ -8811,14 +8811,6 @@ SELECT * FROM postgres_fdw_query('loopback', 'SELECT 42') AS t(i int); 42 (1 row) --- Select the effective role configured in the user mapping -SELECT * FROM postgres_fdw_query('loopback', 'SELECT current_user') - AS t(role_name name); - role_name ------------ - postgres -(1 row) - -- Select schemas owned by the role configured in the user mapping SELECT * FROM postgres_fdw_query('loopback', $$SELECT s.nspname FROM pg_catalog.pg_namespace s diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql index 8e79ee205f182..4deebcb25cacc 100644 --- a/contrib/postgres_fdw/sql/postgres_fdw.sql +++ b/contrib/postgres_fdw/sql/postgres_fdw.sql @@ -2416,10 +2416,6 @@ RESET enable_partitionwise_aggregate; -- Most simple SELECT through postgres_fdw_query SELECT * FROM postgres_fdw_query('loopback', 'SELECT 42') AS t(i int); --- Select the effective role configured in the user mapping -SELECT * FROM postgres_fdw_query('loopback', 'SELECT current_user') - AS t(role_name name); - -- Select schemas owned by the role configured in the user mapping SELECT * FROM postgres_fdw_query('loopback', $$SELECT s.nspname FROM pg_catalog.pg_namespace s From 04d8d0f1c8829aea2e9d657f6b8bab2709b170b7 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 5 Nov 2019 16:03:10 +0100 Subject: [PATCH 09/10] Add support for commands Previously it could actually send commands, but since it wasn't really getting tuples, it failed with an empty error message. --- .../postgres_fdw/expected/postgres_fdw.out | 20 +++++ contrib/postgres_fdw/postgres_fdw.c | 88 +++++++++++++------ contrib/postgres_fdw/sql/postgres_fdw.sql | 6 ++ 3 files changed, 85 insertions(+), 29 deletions(-) diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out index eb4a65afd7f19..2219235731e82 100644 --- a/contrib/postgres_fdw/expected/postgres_fdw.out +++ b/contrib/postgres_fdw/expected/postgres_fdw.out @@ -8850,3 +8850,23 @@ SELECT * FROM postgres_fdw_query('loopback', $$SELECT table_name, table_type T 4 | BASE TABLE (4 rows) +-- Test we can send commands (e.g: prepared statements) +SELECT * FROM postgres_fdw_query('loopback', $$PREPARE fooplan (int) AS +SELECT $1 + 42$$) AS t(res text); + res +--------- + PREPARE +(1 row) + +SELECT * FROM postgres_fdw_query('loopback', 'EXECUTE fooplan (1)') AS t(i int); + i +---- + 43 +(1 row) + +SELECT * FROM postgres_fdw_query('loopback', 'DEALLOCATE fooplan') AS t(res text); + res +------------ + DEALLOCATE +(1 row) + diff --git a/contrib/postgres_fdw/postgres_fdw.c b/contrib/postgres_fdw/postgres_fdw.c index a8689fe5916d1..ea88da92091ce 100644 --- a/contrib/postgres_fdw/postgres_fdw.c +++ b/contrib/postgres_fdw/postgres_fdw.c @@ -5923,6 +5923,7 @@ postgres_fdw_query(PG_FUNCTION_ARGS) TupleDesc tupdesc; int ntuples; int nfields; + bool is_sql_cmd; prepTuplestoreResult(fcinfo); rsinfo = (ReturnSetInfo *) fcinfo->resultinfo; @@ -5948,33 +5949,54 @@ postgres_fdw_query(PG_FUNCTION_ARGS) PG_TRY(); { res = pgfdw_exec_query(conn, sql); - nfields = PQnfields(res); - if (PQresultStatus(res) != PGRES_TUPLES_OK) - pgfdw_report_error(ERROR, res, conn, false, sql); - /* get a tuple descriptor for our result type */ - switch (get_call_result_type(fcinfo, NULL, &tupdesc)) + if (PQresultStatus(res) == PGRES_COMMAND_OK) { - case TYPEFUNC_COMPOSITE: - /* success */ - break; - case TYPEFUNC_RECORD: - /* failed to determine actual type of RECORD */ - ereport(ERROR, - (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), - errmsg("function returning record called in context " - "that cannot accept type record"))); - break; - default: - /* result type isn't composite */ - elog(ERROR, "return type must be a row type"); - break; + is_sql_cmd = true; + + /* + * need a tuple descriptor representing one TEXT column to return + * the command status string as our result tuple + */ + tupdesc = CreateTemplateTupleDesc(1, false); + TupleDescInitEntry(tupdesc, (AttrNumber) 1, "status", + TEXTOID, -1, 0); + ntuples = 1; + nfields = 1; } + else + { + is_sql_cmd = false; + + if (PQresultStatus(res) != PGRES_TUPLES_OK) + pgfdw_report_error(ERROR, res, conn, false, sql); - /* make sure we have a persistent copy of the tupdesc */ - tupdesc = CreateTupleDescCopy(tupdesc); - ntuples = PQntuples(res); - nfields = PQnfields(res); + nfields = PQnfields(res); + + /* get a tuple descriptor for our result type */ + switch (get_call_result_type(fcinfo, NULL, &tupdesc)) + { + case TYPEFUNC_COMPOSITE: + /* success */ + break; + case TYPEFUNC_RECORD: + /* failed to determine actual type of RECORD */ + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("function returning record called in context " + "that cannot accept type record"))); + break; + default: + /* result type isn't composite */ + elog(ERROR, "return type must be a row type"); + break; + } + + /* make sure we have a persistent copy of the tupdesc */ + tupdesc = CreateTupleDescCopy(tupdesc); + ntuples = PQntuples(res); + nfields = PQnfields(res); + } /* check result and tuple descriptor have the same number of columns */ if (nfields != tupdesc->natts) @@ -6006,14 +6028,22 @@ postgres_fdw_query(PG_FUNCTION_ARGS) for (row = 0; row < ntuples; row++) { HeapTuple tuple; - int i; - for (i = 0; i < nfields; i++) + if (is_sql_cmd) + { + values[0] = PQcmdStatus(res); + } + else { - if (PQgetisnull(res, row, i)) - values[i] = NULL; - else - values[i] = PQgetvalue(res, row, i); + int i; + + for (i = 0; i < nfields; i++) + { + if (PQgetisnull(res, row, i)) + values[i] = NULL; + else + values[i] = PQgetvalue(res, row, i); + } } /* build the tuple and put it into the tuplestore. */ diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql index 4deebcb25cacc..d62fc229f6d09 100644 --- a/contrib/postgres_fdw/sql/postgres_fdw.sql +++ b/contrib/postgres_fdw/sql/postgres_fdw.sql @@ -2431,3 +2431,9 @@ SELECT * FROM postgres_fdw_query('loopback', $$SELECT table_name, table_type WHERE table_schema = 'S 1' ORDER BY table_name$$ ) AS schemas(table_name text, table_type text); + +-- Test we can send commands (e.g: prepared statements) +SELECT * FROM postgres_fdw_query('loopback', $$PREPARE fooplan (int) AS +SELECT $1 + 42$$) AS t(res text); +SELECT * FROM postgres_fdw_query('loopback', 'EXECUTE fooplan (1)') AS t(i int); +SELECT * FROM postgres_fdw_query('loopback', 'DEALLOCATE fooplan') AS t(res text); From 77e34f48f175f6eecdc2595d79258bd3625ba7a0 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 5 Nov 2019 16:50:23 +0100 Subject: [PATCH 10/10] Documentation for postgres_fdw_query --- doc/src/sgml/postgres-fdw.sgml | 183 ++++++++++++++++++++++++++++++++- 1 file changed, 181 insertions(+), 2 deletions(-) diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml index 737336f651f37..c3bc002d24d5f 100644 --- a/doc/src/sgml/postgres-fdw.sgml +++ b/doc/src/sgml/postgres-fdw.sgml @@ -443,7 +443,7 @@ - + Connection Management @@ -528,7 +528,7 @@ - + Remote Query Execution Environment @@ -584,6 +584,185 @@ + + Remote Execution of Arbitrary Queries + + + In some instances it may be useful to ship queries to a remote server not + depending upon the local planning on a foreign table. To that end, can be used. + + + Mind that it is the user's responsibility to ensure + session state is not affected by queries sent through + postgres_fdw_query() to the remote server. + + + + + postgres-fdw + + + + postgres_fdw_query + 3 + + + + postgres_fdw_query + executes a query in a foreign server + + + + +postgres_fdw_query(server name, sql text) returns setof record + + + + + Description + + + postgres_fdw_query executes a query (usually a SELECT, + but it can be any SQL statement that returns rows) in a foreign server. + + + + + Arguments + + + + server + + + Name of the foreign server to use, defined with + CREATE SERVER and accessed with the applicable user + mapping. + + + + + + sql + + + The SQL query that you wish to execute in the foreign server, + for example SELECT * FROM foo. + + + + + + + + Return Value + + + The function returns the row(s) produced by the query. Since + postgres_fdw_query can be used with any query, it is + declared to return record, rather than specifying any + particular set of columns. This means that you must specify the expected + set of columns in the calling query — otherwise + PostgreSQL would not know what to expect. Here + is an example: + + +SELECT * FROM postgres_fdw_query('foreign_server', $$SELECT table_name, +table_type + FROM information_schema.tables + WHERE table_schema = 'public' + ORDER BY table_name$$ +) AS schemas(table_name text, table_type text); + + + The alias part of the FROM clause must + specify the column names and types that the function will return. + + + + + Caveats + + + The function postgres_fdw_query does not perform any + checks on the input sql. + + + + It also has the potential to change the state of the remote session. In + particular, it is recommended not to change + session-level settings and avoid using prepared statements prefixed with + pgsql_fdw_prep_. Otherwise it can interfere with the + regular functioning of postgres_fdw. It it is the + caller's responsibility not to interfere the session state managed by + postgres_fdw. + + + + Please see and to understand how + connections and sessions are managed by postgres_fdw. + + + + As an alternative, the older module offers + similar functionality and sessions are managed independently from + postgres_fdw. + + + + + + Examples + + +-- Simple query +SELECT * FROM postgres_fdw_query('loopback', 'SELECT 42') AS t(i int); + i +---- + 42 +(1 row) + +-- Retrieve info from the foreign information_schema +SELECT * FROM postgres_fdw_query('loopback', $$SELECT table_name, table_type + FROM information_schema.tables + WHERE table_schema = 'S 1' + ORDER BY table_name$$ +) AS schemas(table_name text, table_type text); + table_name | table_type +------------+------------ + T 1 | BASE TABLE + T 2 | BASE TABLE + T 3 | BASE TABLE + T 4 | BASE TABLE +(4 rows) + +-- Prepared statements +SELECT * FROM postgres_fdw_query('loopback', $$PREPARE fooplan (int) AS +SELECT $1 + 42$$) AS t(res text); + res +--------- + PREPARE +(1 row) + +SELECT * FROM postgres_fdw_query('loopback', 'EXECUTE fooplan (1)') AS t(i int); + i +---- + 43 +(1 row) + +SELECT * FROM postgres_fdw_query('loopback', 'DEALLOCATE fooplan') AS t(res text); + res +------------ + DEALLOCATE +(1 row) + + + + + + Cross-Version Compatibility