Commit b1be3074 authored by Fujii Masao's avatar Fujii Masao

postgres_fdw: Add option to control whether to keep connections open.

This commit adds a new option keep_connections that controls
whether postgres_fdw keeps the connections to the foreign server open
so that the subsequent queries can re-use them. This option can only be
specified for a foreign server. The default is on. If set to off,
all connections to the foreign server will be discarded
at the end of transaction. Closed connections will be re-established
when they are necessary by future queries using a foreign table.

This option is useful, for example, when users want to prevent
the connections from eating up the foreign servers connections
capacity.

Author: Bharath Rupireddy
Reviewed-by: Alexey Kondratov, Vignesh C, Fujii Masao
Discussion: https://postgr.es/m/CALj2ACVvrp5=AVp2PupEm+nAC8S4buqR3fJMmaCoc7ftT0aD2A@mail.gmail.com
parent 9c5f67fd
...@@ -59,6 +59,8 @@ typedef struct ConnCacheEntry ...@@ -59,6 +59,8 @@ typedef struct ConnCacheEntry
bool have_error; /* have any subxacts aborted in this xact? */ bool have_error; /* have any subxacts aborted in this xact? */
bool changing_xact_state; /* xact state change in process */ bool changing_xact_state; /* xact state change in process */
bool invalidated; /* true if reconnect is pending */ bool invalidated; /* true if reconnect is pending */
bool keep_connections; /* setting value of keep_connections
* server option */
Oid serverid; /* foreign server OID used to get server name */ Oid serverid; /* foreign server OID used to get server name */
uint32 server_hashvalue; /* hash value of foreign server OID */ uint32 server_hashvalue; /* hash value of foreign server OID */
uint32 mapping_hashvalue; /* hash value of user mapping OID */ uint32 mapping_hashvalue; /* hash value of user mapping OID */
...@@ -286,6 +288,7 @@ static void ...@@ -286,6 +288,7 @@ static void
make_new_connection(ConnCacheEntry *entry, UserMapping *user) make_new_connection(ConnCacheEntry *entry, UserMapping *user)
{ {
ForeignServer *server = GetForeignServer(user->serverid); ForeignServer *server = GetForeignServer(user->serverid);
ListCell *lc;
Assert(entry->conn == NULL); Assert(entry->conn == NULL);
...@@ -304,6 +307,26 @@ make_new_connection(ConnCacheEntry *entry, UserMapping *user) ...@@ -304,6 +307,26 @@ make_new_connection(ConnCacheEntry *entry, UserMapping *user)
ObjectIdGetDatum(user->umid)); ObjectIdGetDatum(user->umid));
memset(&entry->state, 0, sizeof(entry->state)); memset(&entry->state, 0, sizeof(entry->state));
/*
* Determine whether to keep the connection that we're about to make here
* open even after the transaction using it ends, so that the subsequent
* transactions can re-use it.
*
* It's enough to determine this only when making new connection because
* all the connections to the foreign server whose keep_connections option
* is changed will be closed and re-made later.
*
* By default, all the connections to any foreign servers are kept open.
*/
entry->keep_connections = true;
foreach(lc, server->options)
{
DefElem *def = (DefElem *) lfirst(lc);
if (strcmp(def->defname, "keep_connections") == 0)
entry->keep_connections = defGetBoolean(def);
}
/* Now try to make the connection */ /* Now try to make the connection */
entry->conn = connect_pg_server(server, user); entry->conn = connect_pg_server(server, user);
...@@ -970,14 +993,16 @@ pgfdw_xact_callback(XactEvent event, void *arg) ...@@ -970,14 +993,16 @@ pgfdw_xact_callback(XactEvent event, void *arg)
entry->xact_depth = 0; entry->xact_depth = 0;
/* /*
* If the connection isn't in a good idle state or it is marked as * If the connection isn't in a good idle state, it is marked as
* invalid, then discard it to recover. Next GetConnection will open a * invalid or keep_connections option of its server is disabled, then
* new connection. * discard it to recover. Next GetConnection will open a new
* connection.
*/ */
if (PQstatus(entry->conn) != CONNECTION_OK || if (PQstatus(entry->conn) != CONNECTION_OK ||
PQtransactionStatus(entry->conn) != PQTRANS_IDLE || PQtransactionStatus(entry->conn) != PQTRANS_IDLE ||
entry->changing_xact_state || entry->changing_xact_state ||
entry->invalidated) entry->invalidated ||
!entry->keep_connections)
{ {
elog(DEBUG3, "discarding connection %p", entry->conn); elog(DEBUG3, "discarding connection %p", entry->conn);
disconnect_pg_server(entry); disconnect_pg_server(entry);
......
...@@ -8913,7 +8913,7 @@ DO $d$ ...@@ -8913,7 +8913,7 @@ DO $d$
END; END;
$d$; $d$;
ERROR: invalid option "password" ERROR: invalid option "password"
HINT: Valid options in this context are: service, passfile, channel_binding, connect_timeout, dbname, host, hostaddr, port, options, application_name, keepalives, keepalives_idle, keepalives_interval, keepalives_count, tcp_user_timeout, sslmode, sslcompression, sslcert, sslkey, sslrootcert, sslcrl, sslcrldir, requirepeer, ssl_min_protocol_version, ssl_max_protocol_version, gssencmode, krbsrvname, gsslib, target_session_attrs, use_remote_estimate, fdw_startup_cost, fdw_tuple_cost, extensions, updatable, fetch_size, batch_size, async_capable HINT: Valid options in this context are: service, passfile, channel_binding, connect_timeout, dbname, host, hostaddr, port, options, application_name, keepalives, keepalives_idle, keepalives_interval, keepalives_count, tcp_user_timeout, sslmode, sslcompression, sslcert, sslkey, sslrootcert, sslcrl, sslcrldir, requirepeer, ssl_min_protocol_version, ssl_max_protocol_version, gssencmode, krbsrvname, gsslib, target_session_attrs, use_remote_estimate, fdw_startup_cost, fdw_tuple_cost, extensions, updatable, fetch_size, batch_size, async_capable, keep_connections
CONTEXT: SQL statement "ALTER SERVER loopback_nopw OPTIONS (ADD password 'dummypw')" CONTEXT: SQL statement "ALTER SERVER loopback_nopw OPTIONS (ADD password 'dummypw')"
PL/pgSQL function inline_code_block line 3 at EXECUTE PL/pgSQL function inline_code_block line 3 at EXECUTE
-- If we add a password for our user mapping instead, we should get a different -- If we add a password for our user mapping instead, we should get a different
...@@ -9249,6 +9249,27 @@ DROP USER MAPPING FOR regress_multi_conn_user2 SERVER loopback; ...@@ -9249,6 +9249,27 @@ DROP USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
DROP ROLE regress_multi_conn_user1; DROP ROLE regress_multi_conn_user1;
DROP ROLE regress_multi_conn_user2; DROP ROLE regress_multi_conn_user2;
-- =================================================================== -- ===================================================================
-- Test foreign server level option keep_connections
-- ===================================================================
-- By default, the connections associated with foreign server are cached i.e.
-- keep_connections option is on. Set it to off.
ALTER SERVER loopback OPTIONS (keep_connections 'off');
-- connection to loopback server is closed at the end of xact
-- as keep_connections was set to off.
SELECT 1 FROM ft1 LIMIT 1;
?column?
----------
1
(1 row)
-- No cached connections, so no records should be output.
SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
server_name
-------------
(0 rows)
ALTER SERVER loopback OPTIONS (SET keep_connections 'on');
-- ===================================================================
-- batch insert -- batch insert
-- =================================================================== -- ===================================================================
BEGIN; BEGIN;
......
...@@ -108,7 +108,8 @@ postgres_fdw_validator(PG_FUNCTION_ARGS) ...@@ -108,7 +108,8 @@ postgres_fdw_validator(PG_FUNCTION_ARGS)
*/ */
if (strcmp(def->defname, "use_remote_estimate") == 0 || if (strcmp(def->defname, "use_remote_estimate") == 0 ||
strcmp(def->defname, "updatable") == 0 || strcmp(def->defname, "updatable") == 0 ||
strcmp(def->defname, "async_capable") == 0) strcmp(def->defname, "async_capable") == 0 ||
strcmp(def->defname, "keep_connections") == 0)
{ {
/* these accept only boolean values */ /* these accept only boolean values */
(void) defGetBoolean(def); (void) defGetBoolean(def);
...@@ -221,6 +222,7 @@ InitPgFdwOptions(void) ...@@ -221,6 +222,7 @@ InitPgFdwOptions(void)
/* async_capable is available on both server and table */ /* async_capable is available on both server and table */
{"async_capable", ForeignServerRelationId, false}, {"async_capable", ForeignServerRelationId, false},
{"async_capable", ForeignTableRelationId, false}, {"async_capable", ForeignTableRelationId, false},
{"keep_connections", ForeignServerRelationId, false},
{"password_required", UserMappingRelationId, false}, {"password_required", UserMappingRelationId, false},
/* /*
......
...@@ -2821,6 +2821,19 @@ DROP USER MAPPING FOR regress_multi_conn_user2 SERVER loopback; ...@@ -2821,6 +2821,19 @@ DROP USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
DROP ROLE regress_multi_conn_user1; DROP ROLE regress_multi_conn_user1;
DROP ROLE regress_multi_conn_user2; DROP ROLE regress_multi_conn_user2;
-- ===================================================================
-- Test foreign server level option keep_connections
-- ===================================================================
-- By default, the connections associated with foreign server are cached i.e.
-- keep_connections option is on. Set it to off.
ALTER SERVER loopback OPTIONS (keep_connections 'off');
-- connection to loopback server is closed at the end of xact
-- as keep_connections was set to off.
SELECT 1 FROM ft1 LIMIT 1;
-- No cached connections, so no records should be output.
SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
ALTER SERVER loopback OPTIONS (SET keep_connections 'on');
-- =================================================================== -- ===================================================================
-- batch insert -- batch insert
-- =================================================================== -- ===================================================================
......
...@@ -518,6 +518,33 @@ OPTIONS (ADD password_required 'false'); ...@@ -518,6 +518,33 @@ OPTIONS (ADD password_required 'false');
</para> </para>
</sect3> </sect3>
<sect3>
<title>Connection Management Options</title>
<para>
By default all the open connections that <filename>postgres_fdw</filename>
established to the foreign servers are kept in local session for re-use.
</para>
<variablelist>
<varlistentry>
<term><literal>keep_connections</literal></term>
<listitem>
<para>
This option controls whether <filename>postgres_fdw</filename> keeps
the connections to the foreign server open so that the subsequent
queries can re-use them. It can only be specified for a foreign server.
The default is <literal>on</literal>. If set to <literal>off</literal>,
all connections to this foreign server will be discarded at the end of
transaction.
</para>
</listitem>
</varlistentry>
</variablelist>
</sect3>
</sect2> </sect2>
<sect2> <sect2>
...@@ -605,8 +632,10 @@ postgres=# SELECT postgres_fdw_disconnect_all(); ...@@ -605,8 +632,10 @@ postgres=# SELECT postgres_fdw_disconnect_all();
<para> <para>
<filename>postgres_fdw</filename> establishes a connection to a <filename>postgres_fdw</filename> establishes a connection to a
foreign server during the first query that uses a foreign table foreign server during the first query that uses a foreign table
associated with the foreign server. This connection is kept and associated with the foreign server. By default this connection
re-used for subsequent queries in the same session. However, if is kept and re-used for subsequent queries in the same session.
This behavior can be controlled using
<literal>keep_connections</literal> option for a foreign server. If
multiple user identities (user mappings) are used to access the foreign multiple user identities (user mappings) are used to access the foreign
server, a connection is established for each user mapping. server, a connection is established for each user mapping.
</para> </para>
...@@ -622,8 +651,10 @@ postgres=# SELECT postgres_fdw_disconnect_all(); ...@@ -622,8 +651,10 @@ postgres=# SELECT postgres_fdw_disconnect_all();
<para> <para>
Once a connection to a foreign server has been established, Once a connection to a foreign server has been established,
it's usually kept until the local or corresponding remote it's by default kept until the local or corresponding remote
session exits. To disconnect a connection explicitly, session exits. To disconnect a connection explicitly,
<literal>keep_connections</literal> option for a foreign server
may be disabled, or
<function>postgres_fdw_disconnect</function> and <function>postgres_fdw_disconnect</function> and
<function>postgres_fdw_disconnect_all</function> functions <function>postgres_fdw_disconnect_all</function> functions
may be used. For example, these are useful to close may be used. For example, these are useful to close
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment