[Proposal] Add foreign-server health checks infrastructure
Dear Hackers,
I want to propose the feature that checks the health of foreign servers.
As a first step I want to add an infrastructure for periodical checking to PostgreSQL core.
Currently this is the WIP, it does not contain docs.
## Background
Currently there is no way to check the status of an foreign server in PostgreSQL.
If an foreign server's postmaster goes down, or if the network between servers is lost,
the backend process will only detect these when it uses the connection corresponding to that foreign server.
Consider a workload that updates data on an foreign server only at the beginning of a transaction,
and runs a lot of local SQLs. Even if the network is disconnected immediately after accessing the foreign server,
the backend process will continue to execute local SQLs without realizing it.
The process will eventually finish to execute SQLs and try to commit.
Only then will it realize that the foreign server cannot be connect and will abort the transaction.
This situation should be detected as soon as possible
because it is impossible to commit a transaction when the foreign server goes down.
This can be more of a problem if you have system-wide downtime requirements.
That's why I want to implement the health-check feature to postgres.
## Design
In general, PostgreSQL can have a variety of RDBMSs as foreign servers,
so the core cannot support all of them.
Therefore, I propose a method to leave the monitoring of the foreign server to each FDW extensions
and register it as a callback function on the body side.
The attached patch adds this monitoring infrastructure to core.
Within the callback functions, it is expected
that each FDWs will check the state of the connection they hold and call ereport (ERROR)
if it cannot connect to someone.
Of course, you can also have the callback function return false.
There is no particular reason to choose the current method.
Callback functions will be called periodically.
## Implementation
This patch introduces a new timeout and a new GUC parameter. GUC controls the timeout interval.
The timeout takes effect when the callback function is first registered,
before each SQL command is executed, and at the end of the timeout.
This implementation is based on the client_connection_check_interval and other timeouts.
## Further work
As the next step I have a plan to implement the callback function to postgres_fdw.
I already made a PoC, but it deeply depends on the following thread:
https://commitfest.postgresql.org/35/3098/
I also want you to review the postgres_fdw part,
but I think it should not be attached because cfbot cannot understand such a dependency
and will throw build error. Do you know how to deal with them in this case?
Your comments and suggestions are very welcome.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v01_add_checking_infrastracture.patchapplication/octet-stream; name=v01_add_checking_infrastracture.patchDownload
diff --git a/src/backend/commands/copyfromparse.c b/src/backend/commands/copyfromparse.c
index aac10165ec..0c4d61a34c 100644
--- a/src/backend/commands/copyfromparse.c
+++ b/src/backend/commands/copyfromparse.c
@@ -269,6 +269,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
readmessage:
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
mtype = pq_getbyte();
if (mtype == EOF)
@@ -300,6 +301,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
ereport(ERROR,
(errcode(ERRCODE_CONNECTION_FAILURE),
errmsg("unexpected EOF on client connection with an open transaction")));
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
/* ... and process it */
switch (mtype)
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index e07cc57431..eb9c4f3f05 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -26,7 +26,11 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
+/* for checking remote servers */
+int remote_servers_connection_check_interval = 0;
+static CheckingRemoteServersCallbackItem *fdw_callbacks = NULL;
/*
* GetForeignDataWrapper - look up the foreign-data wrapper by OID.
@@ -836,3 +840,51 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
}
return NULL;
}
+
+/*
+ * Register callbacks for checking remote servers.
+ *
+ * This function is intended for use by FDW extensions.
+ * The checking timeout will be fired after registering the first callback.
+ */
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+ /* should we start checking timeout? */
+ bool first_exec = HaveCheckingRemoteServersCallbacks();
+
+ item = (CheckingRemoteServersCallbackItem *)
+ MemoryContextAlloc(TopMemoryContext, sizeof(CheckingRemoteServersCallbackItem));
+ item->callback = callback;
+ item->arg = arg;
+ item->next = fdw_callbacks;
+ fdw_callbacks = item;
+
+ if (first_exec && remote_servers_connection_check_interval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT, remote_servers_connection_check_interval);
+}
+
+
+/*
+ * Call callbacks for checking remote servers.
+ *
+ * Note that this function will not return anything.
+ * Callback functions must throw ereport(ERROR) if disconnection has been detected.
+ */
+void
+CallCheckingRemoteServersCallbacks(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+ for (item = fdw_callbacks; item; item = item->next)
+ item->callback(item->arg);
+}
+
+/*
+ * Check whether any callbacks has been registered.
+ */
+bool
+HaveCheckingRemoteServersCallbacks(void)
+{
+ return fdw_callbacks != NULL;
+}
diff --git a/src/backend/libpq/pqcomm.c b/src/backend/libpq/pqcomm.c
index 89a5f901aa..31e39b6cbf 100644
--- a/src/backend/libpq/pqcomm.c
+++ b/src/backend/libpq/pqcomm.c
@@ -1159,7 +1159,6 @@ pq_startmsgread(void)
ereport(FATAL,
(errcode(ERRCODE_PROTOCOL_VIOLATION),
errmsg("terminating connection because protocol synchronization was lost")));
-
PqCommReadingMsg = true;
}
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 0775abe35d..d7890b5307 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -43,6 +43,7 @@
#include "commands/async.h"
#include "commands/prepare.h"
#include "executor/spi.h"
+#include "foreign/foreign.h"
#include "jit/jit.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@@ -349,6 +350,7 @@ SocketBackend(StringInfo inBuf)
* Get message type code from the frontend.
*/
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
qtype = pq_getbyte();
@@ -455,6 +457,7 @@ SocketBackend(StringInfo inBuf)
*/
if (pq_getmessage(inBuf, maxmsglen))
return EOF; /* suitable message already logged */
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
return qtype;
@@ -2708,6 +2711,13 @@ start_xact_command(void)
!get_timeout_active(CLIENT_CONNECTION_CHECK_TIMEOUT))
enable_timeout_after(CLIENT_CONNECTION_CHECK_TIMEOUT,
client_connection_check_interval);
+ if (remote_servers_connection_check_interval > 0 &&
+ IsUnderPostmaster &&
+ MyProcPort &&
+ HaveCheckingRemoteServersCallbacks() &&
+ !get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
}
static void
@@ -3213,6 +3223,24 @@ ProcessInterrupts(void)
}
}
+ if (CheckingRemoteServersTimeoutPending && CheckingRemoteServersHoldoffCount != 0)
+ {
+ /*
+ * Skip checking foreign servers while reading messages.
+ */
+ InterruptPending = true;
+ }
+ else if (CheckingRemoteServersTimeoutPending)
+ {
+ CheckingRemoteServersTimeoutPending = false;
+
+ CallCheckingRemoteServersCallbacks();
+
+ if (remote_servers_connection_check_interval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+ }
+
if (ClientConnectionLost)
{
QueryCancelPending = false; /* lost connection trumps QueryCancel */
diff --git a/src/backend/utils/init/globals.c b/src/backend/utils/init/globals.c
index 381d9e548d..15b0c2727b 100644
--- a/src/backend/utils/init/globals.c
+++ b/src/backend/utils/init/globals.c
@@ -36,9 +36,11 @@ volatile sig_atomic_t IdleInTransactionSessionTimeoutPending = false;
volatile sig_atomic_t IdleSessionTimeoutPending = false;
volatile sig_atomic_t ProcSignalBarrierPending = false;
volatile sig_atomic_t LogMemoryContextPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
volatile uint32 InterruptHoldoffCount = 0;
volatile uint32 QueryCancelHoldoffCount = 0;
volatile uint32 CritSectionCount = 0;
+volatile uint32 CheckingRemoteServersHoldoffCount = 0;
int MyProcPid;
pg_time_t MyStartTime;
diff --git a/src/backend/utils/init/postinit.c b/src/backend/utils/init/postinit.c
index 78bc64671e..fcf5d24248 100644
--- a/src/backend/utils/init/postinit.c
+++ b/src/backend/utils/init/postinit.c
@@ -73,6 +73,7 @@ static void LockTimeoutHandler(void);
static void IdleInTransactionSessionTimeoutHandler(void);
static void IdleSessionTimeoutHandler(void);
static void ClientCheckTimeoutHandler(void);
+static void CheckingRemoteServersTimeoutHandler(void);
static bool ThereIsAtLeastOneRole(void);
static void process_startup_options(Port *port, bool am_superuser);
static void process_settings(Oid databaseid, Oid roleid);
@@ -615,6 +616,7 @@ InitPostgres(const char *in_dbname, Oid dboid, const char *username,
IdleInTransactionSessionTimeoutHandler);
RegisterTimeout(IDLE_SESSION_TIMEOUT, IdleSessionTimeoutHandler);
RegisterTimeout(CLIENT_CONNECTION_CHECK_TIMEOUT, ClientCheckTimeoutHandler);
+ RegisterTimeout(CHECKING_REMOTE_SERVERS_TIMEOUT, CheckingRemoteServersTimeoutHandler);
}
/*
@@ -1245,6 +1247,14 @@ ClientCheckTimeoutHandler(void)
SetLatch(MyLatch);
}
+static void
+CheckingRemoteServersTimeoutHandler(void)
+{
+ CheckingRemoteServersTimeoutPending = true;
+ InterruptPending = true;
+ SetLatch(MyLatch);
+}
+
/*
* Returns true if at least one role is defined in this database cluster.
*/
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index e91d5a3cfd..24172de7a9 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -51,6 +51,7 @@
#include "commands/vacuum.h"
#include "commands/variable.h"
#include "common/string.h"
+#include "foreign/foreign.h"
#include "funcapi.h"
#include "jit/jit.h"
#include "libpq/auth.h"
@@ -105,6 +106,7 @@
#include "utils/queryjumble.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/timeout.h"
#include "utils/tzparser.h"
#include "utils/inval.h"
#include "utils/varlena.h"
@@ -3583,6 +3585,17 @@ static struct config_int ConfigureNamesInt[] =
NULL, NULL, NULL
},
+
+ {
+ {"remote_servers_connection_check_interval", PGC_USERSET, CONN_AUTH_SETTINGS,
+ gettext_noop("Sets the time interval between checks for disconnection of remote servers."),
+ NULL,
+ GUC_UNIT_MS
+ },
+ &remote_servers_connection_check_interval,
+ 0, 0, INT_MAX,
+ },
+
/* End-of-list marker */
{
{NULL, 0, 0, NULL, NULL}, NULL, 0, 0, 0, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 1cbc9feeb6..9b70761d9c 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -90,6 +90,10 @@
# disconnection while running queries;
# 0 for never
+#remote_servers_connection_check_interval = 0 # time between time between checks for
+ # foreign server disconnection;
+ # 0 for never
+
# - Authentication -
#authentication_timeout = 1min # 1s-600s
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 8169eb76b1..98f59c1153 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -81,4 +81,20 @@ extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum);
extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok);
extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);
+
+/* functions and variables for fdw checking. */
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+typedef struct CheckingRemoteServersCallbackItem
+{
+ struct CheckingRemoteServersCallbackItem *next;
+ CheckingRemoteServersCallback callback;
+ void *arg;
+} CheckingRemoteServersCallbackItem;
+
+extern void RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg);
+extern void CallCheckingRemoteServersCallbacks(void);
+extern bool HaveCheckingRemoteServersCallbacks(void);
+
+extern int remote_servers_connection_check_interval;
+
#endif /* FOREIGN_H */
diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h
index 90a3016065..377fc68aaa 100644
--- a/src/include/miscadmin.h
+++ b/src/include/miscadmin.h
@@ -98,10 +98,13 @@ extern PGDLLIMPORT volatile sig_atomic_t LogMemoryContextPending;
extern PGDLLIMPORT volatile sig_atomic_t CheckClientConnectionPending;
extern PGDLLIMPORT volatile sig_atomic_t ClientConnectionLost;
+extern PGDLLIMPORT volatile sig_atomic_t CheckingRemoteServersTimeoutPending;
+
/* these are marked volatile because they are examined by signal handlers: */
extern PGDLLIMPORT volatile uint32 InterruptHoldoffCount;
extern PGDLLIMPORT volatile uint32 QueryCancelHoldoffCount;
extern PGDLLIMPORT volatile uint32 CritSectionCount;
+extern PGDLLIMPORT volatile uint32 CheckingRemoteServersHoldoffCount;
/* in tcop/postgres.c */
extern void ProcessInterrupts(void);
@@ -126,7 +129,7 @@ do { \
/* Is ProcessInterrupts() guaranteed to clear InterruptPending? */
#define INTERRUPTS_CAN_BE_PROCESSED() \
(InterruptHoldoffCount == 0 && CritSectionCount == 0 && \
- QueryCancelHoldoffCount == 0)
+ QueryCancelHoldoffCount == 0 && CheckingRemoteServersHoldoffCount == 0)
#define HOLD_INTERRUPTS() (InterruptHoldoffCount++)
@@ -152,6 +155,13 @@ do { \
CritSectionCount--; \
} while(0)
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS() (CheckingRemoteServersHoldoffCount++)
+
+#define RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS() \
+do { \
+ Assert(CheckingRemoteServersHoldoffCount > 0); \
+ CheckingRemoteServersHoldoffCount--; \
+} while(0)
/*****************************************************************************
* globals.h -- *
diff --git a/src/include/utils/timeout.h b/src/include/utils/timeout.h
index 2cbc5de4d9..ceb6b1c12c 100644
--- a/src/include/utils/timeout.h
+++ b/src/include/utils/timeout.h
@@ -34,6 +34,7 @@ typedef enum TimeoutId
IDLE_SESSION_TIMEOUT,
CLIENT_CONNECTION_CHECK_TIMEOUT,
STARTUP_PROGRESS_TIMEOUT,
+ CHECKING_REMOTE_SERVERS_TIMEOUT,
/* First user-definable timeout reason */
USER_TIMEOUT,
/* Maximum number of timeout reasons */
Hi,
Thank you for the patch!
On 2021-10-30 12:50, kuroda.hayato@fujitsu.com wrote:
## Background
Currently there is no way to check the status of an foreign server in
PostgreSQL.
If an foreign server's postmaster goes down, or if the network between
servers is lost,
the backend process will only detect these when it uses the connection
corresponding to that foreign server.Consider a workload that updates data on an foreign server only at the
beginning of a transaction,
and runs a lot of local SQLs. Even if the network is disconnected
immediately after accessing the foreign server,
the backend process will continue to execute local SQLs without
realizing it.The process will eventually finish to execute SQLs and try to commit.
Only then will it realize that the foreign server cannot be connect
and will abort the transaction.
This situation should be detected as soon as possible
because it is impossible to commit a transaction when the foreign
server goes down.
This can be more of a problem if you have system-wide downtime
requirements.
That's why I want to implement the health-check feature to postgres.
It's a good idea. I also think such a situation should be avoided.
## Further work
As the next step I have a plan to implement the callback function to
postgres_fdw.
I already made a PoC, but it deeply depends on the following thread:
https://commitfest.postgresql.org/35/3098/I also want you to review the postgres_fdw part,
but I think it should not be attached because cfbot cannot understand
such a dependency
and will throw build error. Do you know how to deal with them in this
case?
I don't know how to deal with them, but I hope you will attach the PoC,
as it may be easier to review.
--
Regards,
--
Shinya Kato
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Kato-san,
Thank you for your interest!
I also want you to review the postgres_fdw part,
but I think it should not be attached because cfbot cannot understand
such a dependency
and will throw build error. Do you know how to deal with them in this
case?I don't know how to deal with them, but I hope you will attach the PoC,
as it may be easier to review.
OK, I attached the PoC along with the dependent patches. Please see the zip file.
add_helth_check_... patch is written by me, and other two patches are
just copied from [1]https://commitfest.postgresql.org/35/3098/.
In the new callback function ConnectionHash is searched sequentially and
WaitEventSetWait() is performed for WL_SOCKET_CLOSED socket event.
This event is added by the dependent ones.
===
How to use
===
I'll explain how to use it briefly.
1. boot two postmaster processes. One is coordinator, and another is worker
2. set remote_servers_connection_check_interval to non-zero value at the coordinator
3. create tables to worker DB-cluster.
4. create foreign server, user mapping, and foreign table to coordinator.
5. connect to coordinator via psql.
6. open a transaction and access to foreing tables.
7. do "pg_ctl stop" command to woker DB-cluser.
8. execute some commands that does not access an foreign table.
9. Finally the following output will be get:
ERROR: Postgres foreign server XXX might be down.
===
Example in some steps
===
3. at worker
```
postgres=# \d
List of relations
Schema | Name | Type | Owner
--------+--------+-------+--------
public | remote | table | hayato
(1 row)
```
4. at coordinator
```
postgres=# select * from pg_foreign_server ;
oid | srvname | srvowner | srvfdw | srvtype | srvversion | srvacl | srvoptions
-------+---------+----------+--------+---------+------------+--------+-----------------------------
16406 | remote | 10 | 16402 | | | | {port=5433,dbname=postgres}
(1 row)
postgres=# select * from pg_user_mapping ;
oid | umuser | umserver | umoptions
-------+--------+----------+---------------
16407 | 10 | 16406 | {user=hayato}
(1 row)
postgres=# \d
List of relations
Schema | Name | Type | Owner
--------+--------+---------------+--------
public | local | table | hayato
public | remote | foreign table | hayato
(2 rows)
```
6-9. at coordinator
```
postgres=# begin;
BEGIN
postgres=*# select * from remote ;
id
----
1
(1 row)
postgres=*# select * from local ;
ERROR: Postgres foreign server remote might be down.
postgres=!#
```
Note that some keepalive settings are needed
if you want to detect cable breakdown events.
In my understanding following parameters are needed as server options:
* keepalives_idle
* keepalives_count
* keepalives_interval
[1]: https://commitfest.postgresql.org/35/3098/
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v01_add_checking_infrastracture.patchapplication/octet-stream; name=v01_add_checking_infrastracture.patchDownload
diff --git a/src/backend/commands/copyfromparse.c b/src/backend/commands/copyfromparse.c
index aac10165ec..0c4d61a34c 100644
--- a/src/backend/commands/copyfromparse.c
+++ b/src/backend/commands/copyfromparse.c
@@ -269,6 +269,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
readmessage:
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
mtype = pq_getbyte();
if (mtype == EOF)
@@ -300,6 +301,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
ereport(ERROR,
(errcode(ERRCODE_CONNECTION_FAILURE),
errmsg("unexpected EOF on client connection with an open transaction")));
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
/* ... and process it */
switch (mtype)
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index e07cc57431..eb9c4f3f05 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -26,7 +26,11 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
+/* for checking remote servers */
+int remote_servers_connection_check_interval = 0;
+static CheckingRemoteServersCallbackItem *fdw_callbacks = NULL;
/*
* GetForeignDataWrapper - look up the foreign-data wrapper by OID.
@@ -836,3 +840,51 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
}
return NULL;
}
+
+/*
+ * Register callbacks for checking remote servers.
+ *
+ * This function is intended for use by FDW extensions.
+ * The checking timeout will be fired after registering the first callback.
+ */
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+ /* should we start checking timeout? */
+ bool first_exec = HaveCheckingRemoteServersCallbacks();
+
+ item = (CheckingRemoteServersCallbackItem *)
+ MemoryContextAlloc(TopMemoryContext, sizeof(CheckingRemoteServersCallbackItem));
+ item->callback = callback;
+ item->arg = arg;
+ item->next = fdw_callbacks;
+ fdw_callbacks = item;
+
+ if (first_exec && remote_servers_connection_check_interval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT, remote_servers_connection_check_interval);
+}
+
+
+/*
+ * Call callbacks for checking remote servers.
+ *
+ * Note that this function will not return anything.
+ * Callback functions must throw ereport(ERROR) if disconnection has been detected.
+ */
+void
+CallCheckingRemoteServersCallbacks(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+ for (item = fdw_callbacks; item; item = item->next)
+ item->callback(item->arg);
+}
+
+/*
+ * Check whether any callbacks has been registered.
+ */
+bool
+HaveCheckingRemoteServersCallbacks(void)
+{
+ return fdw_callbacks != NULL;
+}
diff --git a/src/backend/libpq/pqcomm.c b/src/backend/libpq/pqcomm.c
index 89a5f901aa..31e39b6cbf 100644
--- a/src/backend/libpq/pqcomm.c
+++ b/src/backend/libpq/pqcomm.c
@@ -1159,7 +1159,6 @@ pq_startmsgread(void)
ereport(FATAL,
(errcode(ERRCODE_PROTOCOL_VIOLATION),
errmsg("terminating connection because protocol synchronization was lost")));
-
PqCommReadingMsg = true;
}
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 0775abe35d..d7890b5307 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -43,6 +43,7 @@
#include "commands/async.h"
#include "commands/prepare.h"
#include "executor/spi.h"
+#include "foreign/foreign.h"
#include "jit/jit.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@@ -349,6 +350,7 @@ SocketBackend(StringInfo inBuf)
* Get message type code from the frontend.
*/
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
qtype = pq_getbyte();
@@ -455,6 +457,7 @@ SocketBackend(StringInfo inBuf)
*/
if (pq_getmessage(inBuf, maxmsglen))
return EOF; /* suitable message already logged */
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
return qtype;
@@ -2708,6 +2711,13 @@ start_xact_command(void)
!get_timeout_active(CLIENT_CONNECTION_CHECK_TIMEOUT))
enable_timeout_after(CLIENT_CONNECTION_CHECK_TIMEOUT,
client_connection_check_interval);
+ if (remote_servers_connection_check_interval > 0 &&
+ IsUnderPostmaster &&
+ MyProcPort &&
+ HaveCheckingRemoteServersCallbacks() &&
+ !get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
}
static void
@@ -3213,6 +3223,24 @@ ProcessInterrupts(void)
}
}
+ if (CheckingRemoteServersTimeoutPending && CheckingRemoteServersHoldoffCount != 0)
+ {
+ /*
+ * Skip checking foreign servers while reading messages.
+ */
+ InterruptPending = true;
+ }
+ else if (CheckingRemoteServersTimeoutPending)
+ {
+ CheckingRemoteServersTimeoutPending = false;
+
+ CallCheckingRemoteServersCallbacks();
+
+ if (remote_servers_connection_check_interval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+ }
+
if (ClientConnectionLost)
{
QueryCancelPending = false; /* lost connection trumps QueryCancel */
diff --git a/src/backend/utils/init/globals.c b/src/backend/utils/init/globals.c
index 381d9e548d..15b0c2727b 100644
--- a/src/backend/utils/init/globals.c
+++ b/src/backend/utils/init/globals.c
@@ -36,9 +36,11 @@ volatile sig_atomic_t IdleInTransactionSessionTimeoutPending = false;
volatile sig_atomic_t IdleSessionTimeoutPending = false;
volatile sig_atomic_t ProcSignalBarrierPending = false;
volatile sig_atomic_t LogMemoryContextPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
volatile uint32 InterruptHoldoffCount = 0;
volatile uint32 QueryCancelHoldoffCount = 0;
volatile uint32 CritSectionCount = 0;
+volatile uint32 CheckingRemoteServersHoldoffCount = 0;
int MyProcPid;
pg_time_t MyStartTime;
diff --git a/src/backend/utils/init/postinit.c b/src/backend/utils/init/postinit.c
index 78bc64671e..fcf5d24248 100644
--- a/src/backend/utils/init/postinit.c
+++ b/src/backend/utils/init/postinit.c
@@ -73,6 +73,7 @@ static void LockTimeoutHandler(void);
static void IdleInTransactionSessionTimeoutHandler(void);
static void IdleSessionTimeoutHandler(void);
static void ClientCheckTimeoutHandler(void);
+static void CheckingRemoteServersTimeoutHandler(void);
static bool ThereIsAtLeastOneRole(void);
static void process_startup_options(Port *port, bool am_superuser);
static void process_settings(Oid databaseid, Oid roleid);
@@ -615,6 +616,7 @@ InitPostgres(const char *in_dbname, Oid dboid, const char *username,
IdleInTransactionSessionTimeoutHandler);
RegisterTimeout(IDLE_SESSION_TIMEOUT, IdleSessionTimeoutHandler);
RegisterTimeout(CLIENT_CONNECTION_CHECK_TIMEOUT, ClientCheckTimeoutHandler);
+ RegisterTimeout(CHECKING_REMOTE_SERVERS_TIMEOUT, CheckingRemoteServersTimeoutHandler);
}
/*
@@ -1245,6 +1247,14 @@ ClientCheckTimeoutHandler(void)
SetLatch(MyLatch);
}
+static void
+CheckingRemoteServersTimeoutHandler(void)
+{
+ CheckingRemoteServersTimeoutPending = true;
+ InterruptPending = true;
+ SetLatch(MyLatch);
+}
+
/*
* Returns true if at least one role is defined in this database cluster.
*/
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index e91d5a3cfd..24172de7a9 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -51,6 +51,7 @@
#include "commands/vacuum.h"
#include "commands/variable.h"
#include "common/string.h"
+#include "foreign/foreign.h"
#include "funcapi.h"
#include "jit/jit.h"
#include "libpq/auth.h"
@@ -105,6 +106,7 @@
#include "utils/queryjumble.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/timeout.h"
#include "utils/tzparser.h"
#include "utils/inval.h"
#include "utils/varlena.h"
@@ -3583,6 +3585,17 @@ static struct config_int ConfigureNamesInt[] =
NULL, NULL, NULL
},
+
+ {
+ {"remote_servers_connection_check_interval", PGC_USERSET, CONN_AUTH_SETTINGS,
+ gettext_noop("Sets the time interval between checks for disconnection of remote servers."),
+ NULL,
+ GUC_UNIT_MS
+ },
+ &remote_servers_connection_check_interval,
+ 0, 0, INT_MAX,
+ },
+
/* End-of-list marker */
{
{NULL, 0, 0, NULL, NULL}, NULL, 0, 0, 0, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 1cbc9feeb6..9b70761d9c 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -90,6 +90,10 @@
# disconnection while running queries;
# 0 for never
+#remote_servers_connection_check_interval = 0 # time between time between checks for
+ # foreign server disconnection;
+ # 0 for never
+
# - Authentication -
#authentication_timeout = 1min # 1s-600s
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 8169eb76b1..98f59c1153 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -81,4 +81,20 @@ extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum);
extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok);
extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);
+
+/* functions and variables for fdw checking. */
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+typedef struct CheckingRemoteServersCallbackItem
+{
+ struct CheckingRemoteServersCallbackItem *next;
+ CheckingRemoteServersCallback callback;
+ void *arg;
+} CheckingRemoteServersCallbackItem;
+
+extern void RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg);
+extern void CallCheckingRemoteServersCallbacks(void);
+extern bool HaveCheckingRemoteServersCallbacks(void);
+
+extern int remote_servers_connection_check_interval;
+
#endif /* FOREIGN_H */
diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h
index 90a3016065..377fc68aaa 100644
--- a/src/include/miscadmin.h
+++ b/src/include/miscadmin.h
@@ -98,10 +98,13 @@ extern PGDLLIMPORT volatile sig_atomic_t LogMemoryContextPending;
extern PGDLLIMPORT volatile sig_atomic_t CheckClientConnectionPending;
extern PGDLLIMPORT volatile sig_atomic_t ClientConnectionLost;
+extern PGDLLIMPORT volatile sig_atomic_t CheckingRemoteServersTimeoutPending;
+
/* these are marked volatile because they are examined by signal handlers: */
extern PGDLLIMPORT volatile uint32 InterruptHoldoffCount;
extern PGDLLIMPORT volatile uint32 QueryCancelHoldoffCount;
extern PGDLLIMPORT volatile uint32 CritSectionCount;
+extern PGDLLIMPORT volatile uint32 CheckingRemoteServersHoldoffCount;
/* in tcop/postgres.c */
extern void ProcessInterrupts(void);
@@ -126,7 +129,7 @@ do { \
/* Is ProcessInterrupts() guaranteed to clear InterruptPending? */
#define INTERRUPTS_CAN_BE_PROCESSED() \
(InterruptHoldoffCount == 0 && CritSectionCount == 0 && \
- QueryCancelHoldoffCount == 0)
+ QueryCancelHoldoffCount == 0 && CheckingRemoteServersHoldoffCount == 0)
#define HOLD_INTERRUPTS() (InterruptHoldoffCount++)
@@ -152,6 +155,13 @@ do { \
CritSectionCount--; \
} while(0)
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS() (CheckingRemoteServersHoldoffCount++)
+
+#define RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS() \
+do { \
+ Assert(CheckingRemoteServersHoldoffCount > 0); \
+ CheckingRemoteServersHoldoffCount--; \
+} while(0)
/*****************************************************************************
* globals.h -- *
diff --git a/src/include/utils/timeout.h b/src/include/utils/timeout.h
index 2cbc5de4d9..ceb6b1c12c 100644
--- a/src/include/utils/timeout.h
+++ b/src/include/utils/timeout.h
@@ -34,6 +34,7 @@ typedef enum TimeoutId
IDLE_SESSION_TIMEOUT,
CLIENT_CONNECTION_CHECK_TIMEOUT,
STARTUP_PROGRESS_TIMEOUT,
+ CHECKING_REMOTE_SERVERS_TIMEOUT,
/* First user-definable timeout reason */
USER_TIMEOUT,
/* Maximum number of timeout reasons */
On 2021-11-18 21:43, kuroda.hayato@fujitsu.com wrote:
Dear Kato-san,
Thank you for your interest!
I also want you to review the postgres_fdw part,
but I think it should not be attached because cfbot cannot understand
such a dependency
and will throw build error. Do you know how to deal with them in this
case?I don't know how to deal with them, but I hope you will attach the
PoC,
as it may be easier to review.OK, I attached the PoC along with the dependent patches. Please see
the zip file.
add_helth_check_... patch is written by me, and other two patches are
just copied from [1].
In the new callback function ConnectionHash is searched sequentially
and
WaitEventSetWait() is performed for WL_SOCKET_CLOSED socket event.
This event is added by the dependent ones.
Thank you for sending the patches!
I confirmed that they can be compiled and tested successfully on CentOS
8.
I haven't looked at the core of the code yet, but I took a quick look at
it.
+ {
+ {"remote_servers_connection_check_interval", PGC_USERSET,
CONN_AUTH_SETTINGS,
+ gettext_noop("Sets the time interval between checks for
disconnection of remote servers."),
+ NULL,
+ GUC_UNIT_MS
+ },
+ &remote_servers_connection_check_interval,
+ 0, 0, INT_MAX,
+ },
If you don't use check_hook, assign_hook and show_hook, you should
explicitly write "NULL, NULL, NULL", as show below.
+ {
+ {"remote_servers_connection_check_interval", PGC_USERSET,
CONN_AUTH_SETTINGS,
+ gettext_noop("Sets the time interval between checks for
disconnection of remote servers."),
+ NULL,
+ GUC_UNIT_MS
+ },
+ &remote_servers_connection_check_interval,
+ 0, 0, INT_MAX,
+ NULL, NULL, NULL
+ },
+ ereport(ERROR,
+ errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("Postgres foreign server %s might be down.",
+ server->servername));
According to [1]https://www.postgresql.org/docs/devel/error-style-guide.html, error messages should start with a lowercase letter
and not use a period.
Also, along with the rest of the code, it is a good idea to enclose the
server name in double quotes.
I'll get back to you once I've read all the code.
[1]: https://www.postgresql.org/docs/devel/error-style-guide.html
--
Regards,
--
Shinya Kato
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Kato-san,
Thank you for reviewing!
Thank you for sending the patches!
I confirmed that they can be compiled and tested successfully on CentOS
8.
Thanks!
+ { + {"remote_servers_connection_check_interval", PGC_USERSET, CONN_AUTH_SETTINGS, + gettext_noop("Sets the time interval between checks for disconnection of remote servers."), + NULL, + GUC_UNIT_MS + }, + &remote_servers_connection_check_interval, + 0, 0, INT_MAX, + },If you don't use check_hook, assign_hook and show_hook, you should
explicitly write "NULL, NULL, NULL", as show below.
Yeah I forgot the line. Fixed.
+ ereport(ERROR, + errcode(ERRCODE_CONNECTION_FAILURE), + errmsg("Postgres foreign server %s might be down.", + server->servername));According to [1], error messages should start with a lowercase letter
and not use a period.
Also, along with the rest of the code, it is a good idea to enclose the
server name in double quotes.
I confirmed the postgres error-reporting policy and fixed to follow that.
How do you think?
Attached are the latest version.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v02_add_checking_infrastracture.patchapplication/octet-stream; name=v02_add_checking_infrastracture.patchDownload
diff --git a/src/backend/commands/copyfromparse.c b/src/backend/commands/copyfromparse.c
index aac10165ec..0c4d61a34c 100644
--- a/src/backend/commands/copyfromparse.c
+++ b/src/backend/commands/copyfromparse.c
@@ -269,6 +269,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
readmessage:
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
mtype = pq_getbyte();
if (mtype == EOF)
@@ -300,6 +301,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
ereport(ERROR,
(errcode(ERRCODE_CONNECTION_FAILURE),
errmsg("unexpected EOF on client connection with an open transaction")));
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
/* ... and process it */
switch (mtype)
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index e07cc57431..eb9c4f3f05 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -26,7 +26,11 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
+/* for checking remote servers */
+int remote_servers_connection_check_interval = 0;
+static CheckingRemoteServersCallbackItem *fdw_callbacks = NULL;
/*
* GetForeignDataWrapper - look up the foreign-data wrapper by OID.
@@ -836,3 +840,51 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
}
return NULL;
}
+
+/*
+ * Register callbacks for checking remote servers.
+ *
+ * This function is intended for use by FDW extensions.
+ * The checking timeout will be fired after registering the first callback.
+ */
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+ /* should we start checking timeout? */
+ bool first_exec = HaveCheckingRemoteServersCallbacks();
+
+ item = (CheckingRemoteServersCallbackItem *)
+ MemoryContextAlloc(TopMemoryContext, sizeof(CheckingRemoteServersCallbackItem));
+ item->callback = callback;
+ item->arg = arg;
+ item->next = fdw_callbacks;
+ fdw_callbacks = item;
+
+ if (first_exec && remote_servers_connection_check_interval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT, remote_servers_connection_check_interval);
+}
+
+
+/*
+ * Call callbacks for checking remote servers.
+ *
+ * Note that this function will not return anything.
+ * Callback functions must throw ereport(ERROR) if disconnection has been detected.
+ */
+void
+CallCheckingRemoteServersCallbacks(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+ for (item = fdw_callbacks; item; item = item->next)
+ item->callback(item->arg);
+}
+
+/*
+ * Check whether any callbacks has been registered.
+ */
+bool
+HaveCheckingRemoteServersCallbacks(void)
+{
+ return fdw_callbacks != NULL;
+}
diff --git a/src/backend/libpq/pqcomm.c b/src/backend/libpq/pqcomm.c
index 9ebba025cc..5130a8340b 100644
--- a/src/backend/libpq/pqcomm.c
+++ b/src/backend/libpq/pqcomm.c
@@ -1171,7 +1171,6 @@ pq_startmsgread(void)
ereport(FATAL,
(errcode(ERRCODE_PROTOCOL_VIOLATION),
errmsg("terminating connection because protocol synchronization was lost")));
-
PqCommReadingMsg = true;
}
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 0775abe35d..d7890b5307 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -43,6 +43,7 @@
#include "commands/async.h"
#include "commands/prepare.h"
#include "executor/spi.h"
+#include "foreign/foreign.h"
#include "jit/jit.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@@ -349,6 +350,7 @@ SocketBackend(StringInfo inBuf)
* Get message type code from the frontend.
*/
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
qtype = pq_getbyte();
@@ -455,6 +457,7 @@ SocketBackend(StringInfo inBuf)
*/
if (pq_getmessage(inBuf, maxmsglen))
return EOF; /* suitable message already logged */
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
return qtype;
@@ -2708,6 +2711,13 @@ start_xact_command(void)
!get_timeout_active(CLIENT_CONNECTION_CHECK_TIMEOUT))
enable_timeout_after(CLIENT_CONNECTION_CHECK_TIMEOUT,
client_connection_check_interval);
+ if (remote_servers_connection_check_interval > 0 &&
+ IsUnderPostmaster &&
+ MyProcPort &&
+ HaveCheckingRemoteServersCallbacks() &&
+ !get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
}
static void
@@ -3213,6 +3223,24 @@ ProcessInterrupts(void)
}
}
+ if (CheckingRemoteServersTimeoutPending && CheckingRemoteServersHoldoffCount != 0)
+ {
+ /*
+ * Skip checking foreign servers while reading messages.
+ */
+ InterruptPending = true;
+ }
+ else if (CheckingRemoteServersTimeoutPending)
+ {
+ CheckingRemoteServersTimeoutPending = false;
+
+ CallCheckingRemoteServersCallbacks();
+
+ if (remote_servers_connection_check_interval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+ }
+
if (ClientConnectionLost)
{
QueryCancelPending = false; /* lost connection trumps QueryCancel */
diff --git a/src/backend/utils/init/globals.c b/src/backend/utils/init/globals.c
index 381d9e548d..15b0c2727b 100644
--- a/src/backend/utils/init/globals.c
+++ b/src/backend/utils/init/globals.c
@@ -36,9 +36,11 @@ volatile sig_atomic_t IdleInTransactionSessionTimeoutPending = false;
volatile sig_atomic_t IdleSessionTimeoutPending = false;
volatile sig_atomic_t ProcSignalBarrierPending = false;
volatile sig_atomic_t LogMemoryContextPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
volatile uint32 InterruptHoldoffCount = 0;
volatile uint32 QueryCancelHoldoffCount = 0;
volatile uint32 CritSectionCount = 0;
+volatile uint32 CheckingRemoteServersHoldoffCount = 0;
int MyProcPid;
pg_time_t MyStartTime;
diff --git a/src/backend/utils/init/postinit.c b/src/backend/utils/init/postinit.c
index 646126edee..5962b1e395 100644
--- a/src/backend/utils/init/postinit.c
+++ b/src/backend/utils/init/postinit.c
@@ -73,6 +73,7 @@ static void LockTimeoutHandler(void);
static void IdleInTransactionSessionTimeoutHandler(void);
static void IdleSessionTimeoutHandler(void);
static void ClientCheckTimeoutHandler(void);
+static void CheckingRemoteServersTimeoutHandler(void);
static bool ThereIsAtLeastOneRole(void);
static void process_startup_options(Port *port, bool am_superuser);
static void process_settings(Oid databaseid, Oid roleid);
@@ -621,6 +622,7 @@ InitPostgres(const char *in_dbname, Oid dboid, const char *username,
IdleInTransactionSessionTimeoutHandler);
RegisterTimeout(IDLE_SESSION_TIMEOUT, IdleSessionTimeoutHandler);
RegisterTimeout(CLIENT_CONNECTION_CHECK_TIMEOUT, ClientCheckTimeoutHandler);
+ RegisterTimeout(CHECKING_REMOTE_SERVERS_TIMEOUT, CheckingRemoteServersTimeoutHandler);
}
/*
@@ -1250,6 +1252,14 @@ ClientCheckTimeoutHandler(void)
SetLatch(MyLatch);
}
+static void
+CheckingRemoteServersTimeoutHandler(void)
+{
+ CheckingRemoteServersTimeoutPending = true;
+ InterruptPending = true;
+ SetLatch(MyLatch);
+}
+
/*
* Returns true if at least one role is defined in this database cluster.
*/
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index e91d5a3cfd..1faeb59b87 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -51,6 +51,7 @@
#include "commands/vacuum.h"
#include "commands/variable.h"
#include "common/string.h"
+#include "foreign/foreign.h"
#include "funcapi.h"
#include "jit/jit.h"
#include "libpq/auth.h"
@@ -105,6 +106,7 @@
#include "utils/queryjumble.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/timeout.h"
#include "utils/tzparser.h"
#include "utils/inval.h"
#include "utils/varlena.h"
@@ -3583,6 +3585,18 @@ static struct config_int ConfigureNamesInt[] =
NULL, NULL, NULL
},
+
+ {
+ {"remote_servers_connection_check_interval", PGC_USERSET, CONN_AUTH_SETTINGS,
+ gettext_noop("Sets the time interval between checks for disconnection of remote servers."),
+ NULL,
+ GUC_UNIT_MS
+ },
+ &remote_servers_connection_check_interval,
+ 0, 0, INT_MAX,
+ NULL, NULL, NULL
+ },
+
/* End-of-list marker */
{
{NULL, 0, 0, NULL, NULL}, NULL, 0, 0, 0, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 1cbc9feeb6..9b70761d9c 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -90,6 +90,10 @@
# disconnection while running queries;
# 0 for never
+#remote_servers_connection_check_interval = 0 # time between time between checks for
+ # foreign server disconnection;
+ # 0 for never
+
# - Authentication -
#authentication_timeout = 1min # 1s-600s
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 8169eb76b1..98f59c1153 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -81,4 +81,20 @@ extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum);
extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok);
extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);
+
+/* functions and variables for fdw checking. */
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+typedef struct CheckingRemoteServersCallbackItem
+{
+ struct CheckingRemoteServersCallbackItem *next;
+ CheckingRemoteServersCallback callback;
+ void *arg;
+} CheckingRemoteServersCallbackItem;
+
+extern void RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg);
+extern void CallCheckingRemoteServersCallbacks(void);
+extern bool HaveCheckingRemoteServersCallbacks(void);
+
+extern int remote_servers_connection_check_interval;
+
#endif /* FOREIGN_H */
diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h
index 90a3016065..377fc68aaa 100644
--- a/src/include/miscadmin.h
+++ b/src/include/miscadmin.h
@@ -98,10 +98,13 @@ extern PGDLLIMPORT volatile sig_atomic_t LogMemoryContextPending;
extern PGDLLIMPORT volatile sig_atomic_t CheckClientConnectionPending;
extern PGDLLIMPORT volatile sig_atomic_t ClientConnectionLost;
+extern PGDLLIMPORT volatile sig_atomic_t CheckingRemoteServersTimeoutPending;
+
/* these are marked volatile because they are examined by signal handlers: */
extern PGDLLIMPORT volatile uint32 InterruptHoldoffCount;
extern PGDLLIMPORT volatile uint32 QueryCancelHoldoffCount;
extern PGDLLIMPORT volatile uint32 CritSectionCount;
+extern PGDLLIMPORT volatile uint32 CheckingRemoteServersHoldoffCount;
/* in tcop/postgres.c */
extern void ProcessInterrupts(void);
@@ -126,7 +129,7 @@ do { \
/* Is ProcessInterrupts() guaranteed to clear InterruptPending? */
#define INTERRUPTS_CAN_BE_PROCESSED() \
(InterruptHoldoffCount == 0 && CritSectionCount == 0 && \
- QueryCancelHoldoffCount == 0)
+ QueryCancelHoldoffCount == 0 && CheckingRemoteServersHoldoffCount == 0)
#define HOLD_INTERRUPTS() (InterruptHoldoffCount++)
@@ -152,6 +155,13 @@ do { \
CritSectionCount--; \
} while(0)
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS() (CheckingRemoteServersHoldoffCount++)
+
+#define RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS() \
+do { \
+ Assert(CheckingRemoteServersHoldoffCount > 0); \
+ CheckingRemoteServersHoldoffCount--; \
+} while(0)
/*****************************************************************************
* globals.h -- *
diff --git a/src/include/utils/timeout.h b/src/include/utils/timeout.h
index 2cbc5de4d9..ceb6b1c12c 100644
--- a/src/include/utils/timeout.h
+++ b/src/include/utils/timeout.h
@@ -34,6 +34,7 @@ typedef enum TimeoutId
IDLE_SESSION_TIMEOUT,
CLIENT_CONNECTION_CHECK_TIMEOUT,
STARTUP_PROGRESS_TIMEOUT,
+ CHECKING_REMOTE_SERVERS_TIMEOUT,
/* First user-definable timeout reason */
USER_TIMEOUT,
/* Maximum number of timeout reasons */
v02_add_helth_check_for_postgres_fdw.patchapplication/octet-stream; name=v02_add_helth_check_for_postgres_fdw.patchDownload
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 4aff315b7c..30becdeddb 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -109,6 +109,7 @@ static void pgfdw_abort_cleanup(ConnCacheEntry *entry, const char *sql,
bool toplevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool pgfdw_connection_check_internal(PGconn *conn);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -153,6 +154,7 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
pgfdw_inval_callback, (Datum) 0);
CacheRegisterSyscacheCallback(USERMAPPINGOID,
pgfdw_inval_callback, (Datum) 0);
+ RegisterCheckingRemoteServersCallback(pgfdw_connection_check, NULL);
}
/* Set flag that we did GetConnection during the current transaction */
@@ -1638,3 +1640,66 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+
+/*
+ * Callback function for checking remote servers.
+ *
+ * This function searches the hash table from the beginning
+ * and performs a health-check on each entry.
+ *
+ * Note that this might be expensive because create and wait
+ * eventset many times.
+ */
+void
+pgfdw_connection_check(void *args)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+
+ /* Exit immediately if hash is not initialized. */
+ if (!ConnectionHash)
+ return;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ if (entry->conn == NULL || entry->xact_depth == 0)
+ continue;
+ if (!pgfdw_connection_check_internal(entry->conn))
+ {
+ ForeignServer *server = GetForeignServer(entry->serverid);
+ disconnect_pg_server(entry);
+ ereport(ERROR,
+ errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("foreign server \"%s\"disconnected due to the health-check failure",
+ server->servername),
+ errdetail("Foreign server might be down."),
+ errhint("Please check the server and network health."));
+ }
+ }
+}
+
+/*
+ * helper fucntion for pgfdw_connection_check
+ */
+static bool
+pgfdw_connection_check_internal(PGconn *conn)
+{
+ WaitEventSet *eventset;
+ WaitEvent events;
+
+ eventset = CreateWaitEventSet(CurrentMemoryContext, 1);
+ AddWaitEventToSet(eventset, WL_SOCKET_CLOSED, PQsocket(conn), NULL, NULL);
+
+ WaitEventSetWait(eventset, 0, &events, 1, 0);
+
+ if (events.events & WL_SOCKET_CLOSED)
+ {
+ FreeWaitEventSet(eventset);
+ return false;
+ }
+ FreeWaitEventSet(eventset);
+
+ return true;
+}
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 90b72e9ec5..4630ca05d7 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -151,6 +151,7 @@ extern PGresult *pgfdw_exec_query(PGconn *conn, const char *query,
PgFdwConnState *state);
extern void pgfdw_report_error(int elevel, PGresult *res, PGconn *conn,
bool clear, const char *sql);
+extern void pgfdw_connection_check(void *args);
/* in option.c */
extern int ExtractConnectionOptions(List *defelems,
Dear Kato-san,
I found the missing space, and I added a test.
I'm very happy if you review this.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v03_0001_add_checking_infrastracture.patchapplication/octet-stream; name=v03_0001_add_checking_infrastracture.patchDownload
diff --git a/src/backend/commands/copyfromparse.c b/src/backend/commands/copyfromparse.c
index aac10165ec..0c4d61a34c 100644
--- a/src/backend/commands/copyfromparse.c
+++ b/src/backend/commands/copyfromparse.c
@@ -269,6 +269,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
readmessage:
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
mtype = pq_getbyte();
if (mtype == EOF)
@@ -300,6 +301,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
ereport(ERROR,
(errcode(ERRCODE_CONNECTION_FAILURE),
errmsg("unexpected EOF on client connection with an open transaction")));
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
/* ... and process it */
switch (mtype)
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index e07cc57431..eb9c4f3f05 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -26,7 +26,11 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
+/* for checking remote servers */
+int remote_servers_connection_check_interval = 0;
+static CheckingRemoteServersCallbackItem *fdw_callbacks = NULL;
/*
* GetForeignDataWrapper - look up the foreign-data wrapper by OID.
@@ -836,3 +840,51 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
}
return NULL;
}
+
+/*
+ * Register callbacks for checking remote servers.
+ *
+ * This function is intended for use by FDW extensions.
+ * The checking timeout will be fired after registering the first callback.
+ */
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+ /* should we start checking timeout? */
+ bool first_exec = HaveCheckingRemoteServersCallbacks();
+
+ item = (CheckingRemoteServersCallbackItem *)
+ MemoryContextAlloc(TopMemoryContext, sizeof(CheckingRemoteServersCallbackItem));
+ item->callback = callback;
+ item->arg = arg;
+ item->next = fdw_callbacks;
+ fdw_callbacks = item;
+
+ if (first_exec && remote_servers_connection_check_interval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT, remote_servers_connection_check_interval);
+}
+
+
+/*
+ * Call callbacks for checking remote servers.
+ *
+ * Note that this function will not return anything.
+ * Callback functions must throw ereport(ERROR) if disconnection has been detected.
+ */
+void
+CallCheckingRemoteServersCallbacks(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+ for (item = fdw_callbacks; item; item = item->next)
+ item->callback(item->arg);
+}
+
+/*
+ * Check whether any callbacks has been registered.
+ */
+bool
+HaveCheckingRemoteServersCallbacks(void)
+{
+ return fdw_callbacks != NULL;
+}
diff --git a/src/backend/libpq/pqcomm.c b/src/backend/libpq/pqcomm.c
index 9ebba025cc..5130a8340b 100644
--- a/src/backend/libpq/pqcomm.c
+++ b/src/backend/libpq/pqcomm.c
@@ -1171,7 +1171,6 @@ pq_startmsgread(void)
ereport(FATAL,
(errcode(ERRCODE_PROTOCOL_VIOLATION),
errmsg("terminating connection because protocol synchronization was lost")));
-
PqCommReadingMsg = true;
}
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 0775abe35d..d7890b5307 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -43,6 +43,7 @@
#include "commands/async.h"
#include "commands/prepare.h"
#include "executor/spi.h"
+#include "foreign/foreign.h"
#include "jit/jit.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@@ -349,6 +350,7 @@ SocketBackend(StringInfo inBuf)
* Get message type code from the frontend.
*/
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
qtype = pq_getbyte();
@@ -455,6 +457,7 @@ SocketBackend(StringInfo inBuf)
*/
if (pq_getmessage(inBuf, maxmsglen))
return EOF; /* suitable message already logged */
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
return qtype;
@@ -2708,6 +2711,13 @@ start_xact_command(void)
!get_timeout_active(CLIENT_CONNECTION_CHECK_TIMEOUT))
enable_timeout_after(CLIENT_CONNECTION_CHECK_TIMEOUT,
client_connection_check_interval);
+ if (remote_servers_connection_check_interval > 0 &&
+ IsUnderPostmaster &&
+ MyProcPort &&
+ HaveCheckingRemoteServersCallbacks() &&
+ !get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
}
static void
@@ -3213,6 +3223,24 @@ ProcessInterrupts(void)
}
}
+ if (CheckingRemoteServersTimeoutPending && CheckingRemoteServersHoldoffCount != 0)
+ {
+ /*
+ * Skip checking foreign servers while reading messages.
+ */
+ InterruptPending = true;
+ }
+ else if (CheckingRemoteServersTimeoutPending)
+ {
+ CheckingRemoteServersTimeoutPending = false;
+
+ CallCheckingRemoteServersCallbacks();
+
+ if (remote_servers_connection_check_interval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+ }
+
if (ClientConnectionLost)
{
QueryCancelPending = false; /* lost connection trumps QueryCancel */
diff --git a/src/backend/utils/init/globals.c b/src/backend/utils/init/globals.c
index 381d9e548d..15b0c2727b 100644
--- a/src/backend/utils/init/globals.c
+++ b/src/backend/utils/init/globals.c
@@ -36,9 +36,11 @@ volatile sig_atomic_t IdleInTransactionSessionTimeoutPending = false;
volatile sig_atomic_t IdleSessionTimeoutPending = false;
volatile sig_atomic_t ProcSignalBarrierPending = false;
volatile sig_atomic_t LogMemoryContextPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
volatile uint32 InterruptHoldoffCount = 0;
volatile uint32 QueryCancelHoldoffCount = 0;
volatile uint32 CritSectionCount = 0;
+volatile uint32 CheckingRemoteServersHoldoffCount = 0;
int MyProcPid;
pg_time_t MyStartTime;
diff --git a/src/backend/utils/init/postinit.c b/src/backend/utils/init/postinit.c
index 646126edee..5962b1e395 100644
--- a/src/backend/utils/init/postinit.c
+++ b/src/backend/utils/init/postinit.c
@@ -73,6 +73,7 @@ static void LockTimeoutHandler(void);
static void IdleInTransactionSessionTimeoutHandler(void);
static void IdleSessionTimeoutHandler(void);
static void ClientCheckTimeoutHandler(void);
+static void CheckingRemoteServersTimeoutHandler(void);
static bool ThereIsAtLeastOneRole(void);
static void process_startup_options(Port *port, bool am_superuser);
static void process_settings(Oid databaseid, Oid roleid);
@@ -621,6 +622,7 @@ InitPostgres(const char *in_dbname, Oid dboid, const char *username,
IdleInTransactionSessionTimeoutHandler);
RegisterTimeout(IDLE_SESSION_TIMEOUT, IdleSessionTimeoutHandler);
RegisterTimeout(CLIENT_CONNECTION_CHECK_TIMEOUT, ClientCheckTimeoutHandler);
+ RegisterTimeout(CHECKING_REMOTE_SERVERS_TIMEOUT, CheckingRemoteServersTimeoutHandler);
}
/*
@@ -1250,6 +1252,14 @@ ClientCheckTimeoutHandler(void)
SetLatch(MyLatch);
}
+static void
+CheckingRemoteServersTimeoutHandler(void)
+{
+ CheckingRemoteServersTimeoutPending = true;
+ InterruptPending = true;
+ SetLatch(MyLatch);
+}
+
/*
* Returns true if at least one role is defined in this database cluster.
*/
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index e91d5a3cfd..1faeb59b87 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -51,6 +51,7 @@
#include "commands/vacuum.h"
#include "commands/variable.h"
#include "common/string.h"
+#include "foreign/foreign.h"
#include "funcapi.h"
#include "jit/jit.h"
#include "libpq/auth.h"
@@ -105,6 +106,7 @@
#include "utils/queryjumble.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/timeout.h"
#include "utils/tzparser.h"
#include "utils/inval.h"
#include "utils/varlena.h"
@@ -3583,6 +3585,18 @@ static struct config_int ConfigureNamesInt[] =
NULL, NULL, NULL
},
+
+ {
+ {"remote_servers_connection_check_interval", PGC_USERSET, CONN_AUTH_SETTINGS,
+ gettext_noop("Sets the time interval between checks for disconnection of remote servers."),
+ NULL,
+ GUC_UNIT_MS
+ },
+ &remote_servers_connection_check_interval,
+ 0, 0, INT_MAX,
+ NULL, NULL, NULL
+ },
+
/* End-of-list marker */
{
{NULL, 0, 0, NULL, NULL}, NULL, 0, 0, 0, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 1cbc9feeb6..9b70761d9c 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -90,6 +90,10 @@
# disconnection while running queries;
# 0 for never
+#remote_servers_connection_check_interval = 0 # time between time between checks for
+ # foreign server disconnection;
+ # 0 for never
+
# - Authentication -
#authentication_timeout = 1min # 1s-600s
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 8169eb76b1..98f59c1153 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -81,4 +81,20 @@ extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum);
extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok);
extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);
+
+/* functions and variables for fdw checking. */
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+typedef struct CheckingRemoteServersCallbackItem
+{
+ struct CheckingRemoteServersCallbackItem *next;
+ CheckingRemoteServersCallback callback;
+ void *arg;
+} CheckingRemoteServersCallbackItem;
+
+extern void RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg);
+extern void CallCheckingRemoteServersCallbacks(void);
+extern bool HaveCheckingRemoteServersCallbacks(void);
+
+extern int remote_servers_connection_check_interval;
+
#endif /* FOREIGN_H */
diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h
index 90a3016065..377fc68aaa 100644
--- a/src/include/miscadmin.h
+++ b/src/include/miscadmin.h
@@ -98,10 +98,13 @@ extern PGDLLIMPORT volatile sig_atomic_t LogMemoryContextPending;
extern PGDLLIMPORT volatile sig_atomic_t CheckClientConnectionPending;
extern PGDLLIMPORT volatile sig_atomic_t ClientConnectionLost;
+extern PGDLLIMPORT volatile sig_atomic_t CheckingRemoteServersTimeoutPending;
+
/* these are marked volatile because they are examined by signal handlers: */
extern PGDLLIMPORT volatile uint32 InterruptHoldoffCount;
extern PGDLLIMPORT volatile uint32 QueryCancelHoldoffCount;
extern PGDLLIMPORT volatile uint32 CritSectionCount;
+extern PGDLLIMPORT volatile uint32 CheckingRemoteServersHoldoffCount;
/* in tcop/postgres.c */
extern void ProcessInterrupts(void);
@@ -126,7 +129,7 @@ do { \
/* Is ProcessInterrupts() guaranteed to clear InterruptPending? */
#define INTERRUPTS_CAN_BE_PROCESSED() \
(InterruptHoldoffCount == 0 && CritSectionCount == 0 && \
- QueryCancelHoldoffCount == 0)
+ QueryCancelHoldoffCount == 0 && CheckingRemoteServersHoldoffCount == 0)
#define HOLD_INTERRUPTS() (InterruptHoldoffCount++)
@@ -152,6 +155,13 @@ do { \
CritSectionCount--; \
} while(0)
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS() (CheckingRemoteServersHoldoffCount++)
+
+#define RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS() \
+do { \
+ Assert(CheckingRemoteServersHoldoffCount > 0); \
+ CheckingRemoteServersHoldoffCount--; \
+} while(0)
/*****************************************************************************
* globals.h -- *
diff --git a/src/include/utils/timeout.h b/src/include/utils/timeout.h
index 2cbc5de4d9..ceb6b1c12c 100644
--- a/src/include/utils/timeout.h
+++ b/src/include/utils/timeout.h
@@ -34,6 +34,7 @@ typedef enum TimeoutId
IDLE_SESSION_TIMEOUT,
CLIENT_CONNECTION_CHECK_TIMEOUT,
STARTUP_PROGRESS_TIMEOUT,
+ CHECKING_REMOTE_SERVERS_TIMEOUT,
/* First user-definable timeout reason */
USER_TIMEOUT,
/* Maximum number of timeout reasons */
On Tue, Nov 23, 2021 at 8:57 PM kuroda.hayato@fujitsu.com <
kuroda.hayato@fujitsu.com> wrote:
Dear Kato-san,
Thank you for reviewing!
Thank you for sending the patches!
I confirmed that they can be compiled and tested successfully on CentOS
8.Thanks!
+ { + {"remote_servers_connection_check_interval", PGC_USERSET, CONN_AUTH_SETTINGS, + gettext_noop("Sets the time interval between checks for disconnection of remote servers."), + NULL, + GUC_UNIT_MS + }, + &remote_servers_connection_check_interval, + 0, 0, INT_MAX, + },If you don't use check_hook, assign_hook and show_hook, you should
explicitly write "NULL, NULL, NULL", as show below.Yeah I forgot the line. Fixed.
+ ereport(ERROR, + errcode(ERRCODE_CONNECTION_FAILURE), + errmsg("Postgres foreign server %s might be down.", + server->servername));According to [1], error messages should start with a lowercase letter
and not use a period.
Also, along with the rest of the code, it is a good idea to enclose the
server name in double quotes.I confirmed the postgres error-reporting policy and fixed to follow that.
How do you think?Attached are the latest version.
Best Regards,
Hayato Kuroda
FUJITSU LIMITEDHi,
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS()
(CheckingRemoteServersHoldoffCount++)
The macro contains only one operation. Can the macro be removed (with
`CheckingRemoteServersHoldoffCount++` inlined) ?
+ if (CheckingRemoteServersTimeoutPending &&
CheckingRemoteServersHoldoffCount != 0)
+ {
+ /*
+ * Skip checking foreign servers while reading messages.
+ */
+ InterruptPending = true;
+ }
+ else if (CheckingRemoteServersTimeoutPending)
Would the code be more readable if the above two if blocks be moved inside
one enclosing if block (factoring the common condition)?
+ if (CheckingRemoteServersTimeoutPending)
Cheers
Dear Zhihong,
Thank you for giving comments! I'll post new patches later.
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS() (CheckingRemoteServersHoldoffCount++)
The macro contains only one operation. Can the macro be removed (with `CheckingRemoteServersHoldoffCount++` inlined) ?
Hmm, these HOLD/RESUME macros are followed HOLD_INTERRUPUST() and HOLD_CANCEL_INTERRUPTS():
```
#define HOLD_INTERRUPTS() (InterruptHoldoffCount++)
#define RESUME_INTERRUPTS() \
do { \
Assert(InterruptHoldoffCount > 0); \
InterruptHoldoffCount--; \
} while(0)
#define HOLD_CANCEL_INTERRUPTS() (QueryCancelHoldoffCount++)
#define RESUME_CANCEL_INTERRUPTS() \
do { \
Assert(QueryCancelHoldoffCount > 0); \
QueryCancelHoldoffCount--; \
} while(0)
#define START_CRIT_SECTION() (CritSectionCount++)
#define END_CRIT_SECTION() \
do { \
Assert(CritSectionCount > 0); \
CritSectionCount--; \
} while(0)
```
So I want to keep the current style. Could you tell me if you have any other reasons?
+ if (CheckingRemoteServersTimeoutPending && CheckingRemoteServersHoldoffCount != 0) + { + /* + * Skip checking foreign servers while reading messages. + */ + InterruptPending = true; + } + else if (CheckingRemoteServersTimeoutPending)Would the code be more readable if the above two if blocks be moved inside one enclosing if block (factoring the common condition)?
+ if (CheckingRemoteServersTimeoutPending)
+1. Will fix.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Dear Hackers,
I attached new version that is based from Zhihong's comments.
And I newly attached a doc patch. I think the infrastructure part is no longer WIP.
Could you review them?
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v04_0001_add_checking_infrastracture.patchapplication/octet-stream; name=v04_0001_add_checking_infrastracture.patchDownload
diff --git a/src/backend/commands/copyfromparse.c b/src/backend/commands/copyfromparse.c
index aac10165ec..0c4d61a34c 100644
--- a/src/backend/commands/copyfromparse.c
+++ b/src/backend/commands/copyfromparse.c
@@ -269,6 +269,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
readmessage:
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
mtype = pq_getbyte();
if (mtype == EOF)
@@ -300,6 +301,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
ereport(ERROR,
(errcode(ERRCODE_CONNECTION_FAILURE),
errmsg("unexpected EOF on client connection with an open transaction")));
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
/* ... and process it */
switch (mtype)
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index e07cc57431..eb9c4f3f05 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -26,7 +26,11 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
+/* for checking remote servers */
+int remote_servers_connection_check_interval = 0;
+static CheckingRemoteServersCallbackItem *fdw_callbacks = NULL;
/*
* GetForeignDataWrapper - look up the foreign-data wrapper by OID.
@@ -836,3 +840,51 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
}
return NULL;
}
+
+/*
+ * Register callbacks for checking remote servers.
+ *
+ * This function is intended for use by FDW extensions.
+ * The checking timeout will be fired after registering the first callback.
+ */
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+ /* should we start checking timeout? */
+ bool first_exec = HaveCheckingRemoteServersCallbacks();
+
+ item = (CheckingRemoteServersCallbackItem *)
+ MemoryContextAlloc(TopMemoryContext, sizeof(CheckingRemoteServersCallbackItem));
+ item->callback = callback;
+ item->arg = arg;
+ item->next = fdw_callbacks;
+ fdw_callbacks = item;
+
+ if (first_exec && remote_servers_connection_check_interval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT, remote_servers_connection_check_interval);
+}
+
+
+/*
+ * Call callbacks for checking remote servers.
+ *
+ * Note that this function will not return anything.
+ * Callback functions must throw ereport(ERROR) if disconnection has been detected.
+ */
+void
+CallCheckingRemoteServersCallbacks(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+ for (item = fdw_callbacks; item; item = item->next)
+ item->callback(item->arg);
+}
+
+/*
+ * Check whether any callbacks has been registered.
+ */
+bool
+HaveCheckingRemoteServersCallbacks(void)
+{
+ return fdw_callbacks != NULL;
+}
diff --git a/src/backend/libpq/pqcomm.c b/src/backend/libpq/pqcomm.c
index 9ebba025cc..5130a8340b 100644
--- a/src/backend/libpq/pqcomm.c
+++ b/src/backend/libpq/pqcomm.c
@@ -1171,7 +1171,6 @@ pq_startmsgread(void)
ereport(FATAL,
(errcode(ERRCODE_PROTOCOL_VIOLATION),
errmsg("terminating connection because protocol synchronization was lost")));
-
PqCommReadingMsg = true;
}
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 0775abe35d..ca5d50236b 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -43,6 +43,7 @@
#include "commands/async.h"
#include "commands/prepare.h"
#include "executor/spi.h"
+#include "foreign/foreign.h"
#include "jit/jit.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@@ -349,6 +350,7 @@ SocketBackend(StringInfo inBuf)
* Get message type code from the frontend.
*/
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
qtype = pq_getbyte();
@@ -455,6 +457,7 @@ SocketBackend(StringInfo inBuf)
*/
if (pq_getmessage(inBuf, maxmsglen))
return EOF; /* suitable message already logged */
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
return qtype;
@@ -2708,6 +2711,13 @@ start_xact_command(void)
!get_timeout_active(CLIENT_CONNECTION_CHECK_TIMEOUT))
enable_timeout_after(CLIENT_CONNECTION_CHECK_TIMEOUT,
client_connection_check_interval);
+ if (remote_servers_connection_check_interval > 0 &&
+ IsUnderPostmaster &&
+ MyProcPort &&
+ HaveCheckingRemoteServersCallbacks() &&
+ !get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
}
static void
@@ -3213,6 +3223,27 @@ ProcessInterrupts(void)
}
}
+ if (CheckingRemoteServersTimeoutPending)
+ {
+ if (CheckingRemoteServersHoldoffCount != 0)
+ {
+ /*
+ * Skip checking foreign servers while reading messages.
+ */
+ InterruptPending = true;
+ }
+ else
+ {
+ CheckingRemoteServersTimeoutPending = false;
+
+ CallCheckingRemoteServersCallbacks();
+
+ if (remote_servers_connection_check_interval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+ }
+ }
+
if (ClientConnectionLost)
{
QueryCancelPending = false; /* lost connection trumps QueryCancel */
diff --git a/src/backend/utils/init/globals.c b/src/backend/utils/init/globals.c
index 381d9e548d..15b0c2727b 100644
--- a/src/backend/utils/init/globals.c
+++ b/src/backend/utils/init/globals.c
@@ -36,9 +36,11 @@ volatile sig_atomic_t IdleInTransactionSessionTimeoutPending = false;
volatile sig_atomic_t IdleSessionTimeoutPending = false;
volatile sig_atomic_t ProcSignalBarrierPending = false;
volatile sig_atomic_t LogMemoryContextPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
volatile uint32 InterruptHoldoffCount = 0;
volatile uint32 QueryCancelHoldoffCount = 0;
volatile uint32 CritSectionCount = 0;
+volatile uint32 CheckingRemoteServersHoldoffCount = 0;
int MyProcPid;
pg_time_t MyStartTime;
diff --git a/src/backend/utils/init/postinit.c b/src/backend/utils/init/postinit.c
index 646126edee..5962b1e395 100644
--- a/src/backend/utils/init/postinit.c
+++ b/src/backend/utils/init/postinit.c
@@ -73,6 +73,7 @@ static void LockTimeoutHandler(void);
static void IdleInTransactionSessionTimeoutHandler(void);
static void IdleSessionTimeoutHandler(void);
static void ClientCheckTimeoutHandler(void);
+static void CheckingRemoteServersTimeoutHandler(void);
static bool ThereIsAtLeastOneRole(void);
static void process_startup_options(Port *port, bool am_superuser);
static void process_settings(Oid databaseid, Oid roleid);
@@ -621,6 +622,7 @@ InitPostgres(const char *in_dbname, Oid dboid, const char *username,
IdleInTransactionSessionTimeoutHandler);
RegisterTimeout(IDLE_SESSION_TIMEOUT, IdleSessionTimeoutHandler);
RegisterTimeout(CLIENT_CONNECTION_CHECK_TIMEOUT, ClientCheckTimeoutHandler);
+ RegisterTimeout(CHECKING_REMOTE_SERVERS_TIMEOUT, CheckingRemoteServersTimeoutHandler);
}
/*
@@ -1250,6 +1252,14 @@ ClientCheckTimeoutHandler(void)
SetLatch(MyLatch);
}
+static void
+CheckingRemoteServersTimeoutHandler(void)
+{
+ CheckingRemoteServersTimeoutPending = true;
+ InterruptPending = true;
+ SetLatch(MyLatch);
+}
+
/*
* Returns true if at least one role is defined in this database cluster.
*/
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index e91d5a3cfd..1faeb59b87 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -51,6 +51,7 @@
#include "commands/vacuum.h"
#include "commands/variable.h"
#include "common/string.h"
+#include "foreign/foreign.h"
#include "funcapi.h"
#include "jit/jit.h"
#include "libpq/auth.h"
@@ -105,6 +106,7 @@
#include "utils/queryjumble.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/timeout.h"
#include "utils/tzparser.h"
#include "utils/inval.h"
#include "utils/varlena.h"
@@ -3583,6 +3585,18 @@ static struct config_int ConfigureNamesInt[] =
NULL, NULL, NULL
},
+
+ {
+ {"remote_servers_connection_check_interval", PGC_USERSET, CONN_AUTH_SETTINGS,
+ gettext_noop("Sets the time interval between checks for disconnection of remote servers."),
+ NULL,
+ GUC_UNIT_MS
+ },
+ &remote_servers_connection_check_interval,
+ 0, 0, INT_MAX,
+ NULL, NULL, NULL
+ },
+
/* End-of-list marker */
{
{NULL, 0, 0, NULL, NULL}, NULL, 0, 0, 0, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 1cbc9feeb6..9b70761d9c 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -90,6 +90,10 @@
# disconnection while running queries;
# 0 for never
+#remote_servers_connection_check_interval = 0 # time between time between checks for
+ # foreign server disconnection;
+ # 0 for never
+
# - Authentication -
#authentication_timeout = 1min # 1s-600s
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 8169eb76b1..98f59c1153 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -81,4 +81,20 @@ extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum);
extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok);
extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);
+
+/* functions and variables for fdw checking. */
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+typedef struct CheckingRemoteServersCallbackItem
+{
+ struct CheckingRemoteServersCallbackItem *next;
+ CheckingRemoteServersCallback callback;
+ void *arg;
+} CheckingRemoteServersCallbackItem;
+
+extern void RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg);
+extern void CallCheckingRemoteServersCallbacks(void);
+extern bool HaveCheckingRemoteServersCallbacks(void);
+
+extern int remote_servers_connection_check_interval;
+
#endif /* FOREIGN_H */
diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h
index 90a3016065..377fc68aaa 100644
--- a/src/include/miscadmin.h
+++ b/src/include/miscadmin.h
@@ -98,10 +98,13 @@ extern PGDLLIMPORT volatile sig_atomic_t LogMemoryContextPending;
extern PGDLLIMPORT volatile sig_atomic_t CheckClientConnectionPending;
extern PGDLLIMPORT volatile sig_atomic_t ClientConnectionLost;
+extern PGDLLIMPORT volatile sig_atomic_t CheckingRemoteServersTimeoutPending;
+
/* these are marked volatile because they are examined by signal handlers: */
extern PGDLLIMPORT volatile uint32 InterruptHoldoffCount;
extern PGDLLIMPORT volatile uint32 QueryCancelHoldoffCount;
extern PGDLLIMPORT volatile uint32 CritSectionCount;
+extern PGDLLIMPORT volatile uint32 CheckingRemoteServersHoldoffCount;
/* in tcop/postgres.c */
extern void ProcessInterrupts(void);
@@ -126,7 +129,7 @@ do { \
/* Is ProcessInterrupts() guaranteed to clear InterruptPending? */
#define INTERRUPTS_CAN_BE_PROCESSED() \
(InterruptHoldoffCount == 0 && CritSectionCount == 0 && \
- QueryCancelHoldoffCount == 0)
+ QueryCancelHoldoffCount == 0 && CheckingRemoteServersHoldoffCount == 0)
#define HOLD_INTERRUPTS() (InterruptHoldoffCount++)
@@ -152,6 +155,13 @@ do { \
CritSectionCount--; \
} while(0)
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS() (CheckingRemoteServersHoldoffCount++)
+
+#define RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS() \
+do { \
+ Assert(CheckingRemoteServersHoldoffCount > 0); \
+ CheckingRemoteServersHoldoffCount--; \
+} while(0)
/*****************************************************************************
* globals.h -- *
diff --git a/src/include/utils/timeout.h b/src/include/utils/timeout.h
index 2cbc5de4d9..ceb6b1c12c 100644
--- a/src/include/utils/timeout.h
+++ b/src/include/utils/timeout.h
@@ -34,6 +34,7 @@ typedef enum TimeoutId
IDLE_SESSION_TIMEOUT,
CLIENT_CONNECTION_CHECK_TIMEOUT,
STARTUP_PROGRESS_TIMEOUT,
+ CHECKING_REMOTE_SERVERS_TIMEOUT,
/* First user-definable timeout reason */
USER_TIMEOUT,
/* Maximum number of timeout reasons */
v04_0002_add_doc.patchapplication/octet-stream; name=v04_0002_add_doc.patchDownload
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index ab617c7b86..a93c73da2f 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -1035,6 +1035,25 @@ include_dir 'conf.d'
</listitem>
</varlistentry>
+ <varlistentry id="guc-remote-servers-connection-check-interval" xreflabel="remote_servers_connection_check_interval">
+ <term><varname>remote_servers_connection_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>remote_servers_connection_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that the remote servers
+ are still alive. If this parameter is set to a valid value, registered
+ callback functions are executed at the specified time interval.
+ If your FDW extension does not implement a callback function, nothing
+ happens after the specified amount of time. If the value is specified
+ without units, it is taken as milliseconds. The default value is
+ <literal>0</literal>, this means the feature is disabled.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
diff --git a/doc/src/sgml/fdwhandler.sgml b/doc/src/sgml/fdwhandler.sgml
index dbf5dd3d15..df52c53ae6 100644
--- a/doc/src/sgml/fdwhandler.sgml
+++ b/doc/src/sgml/fdwhandler.sgml
@@ -2136,4 +2136,26 @@ GetForeignServerByName(const char *name, bool missing_ok);
</sect1>
+ <sect1 id="fdw-checking-remote-servers">
+ <title>Checking the Health of Remote Servers via Foreign Data Wrapper</title>
+
+ <para>
+ For verifying the health of remote servers, callback functions can be
+ registered that runs periodically. The time interval is controlled by
+ <xref linkend="guc-remote-servers-connection-check-interval"/>.
+ The API for registering functions is:
+ <programlisting>
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg);
+ </programlisting>
+ Only functions that return void can be registered as callback functions.
+ Please set to void* arg a pointer if you want to pass an argument.
+ If you have problems with the health check results and want to
+ abort the transaction, please execute <function>ereport(ERROR)</function>
+ in the callback function.
+ </para>
+
+ </sect1>
+
+
</chapter>
On Mon, Nov 29, 2021 at 12:51 AM kuroda.hayato@fujitsu.com <
kuroda.hayato@fujitsu.com> wrote:
Dear Zhihong,
Thank you for giving comments! I'll post new patches later.
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS()
(CheckingRemoteServersHoldoffCount++)
The macro contains only one operation. Can the macro be removed (with
`CheckingRemoteServersHoldoffCount++` inlined) ?
Hmm, these HOLD/RESUME macros are followed HOLD_INTERRUPUST() and
HOLD_CANCEL_INTERRUPTS():```
#define HOLD_INTERRUPTS() (InterruptHoldoffCount++)#define RESUME_INTERRUPTS() \
do { \
Assert(InterruptHoldoffCount > 0); \
InterruptHoldoffCount--; \
} while(0)#define HOLD_CANCEL_INTERRUPTS() (QueryCancelHoldoffCount++)
#define RESUME_CANCEL_INTERRUPTS() \
do { \
Assert(QueryCancelHoldoffCount > 0); \
QueryCancelHoldoffCount--; \
} while(0)#define START_CRIT_SECTION() (CritSectionCount++)
#define END_CRIT_SECTION() \
do { \
Assert(CritSectionCount > 0); \
CritSectionCount--; \
} while(0)
```So I want to keep the current style. Could you tell me if you have any
other reasons?+ if (CheckingRemoteServersTimeoutPending &&
CheckingRemoteServersHoldoffCount != 0)
+ { + /* + * Skip checking foreign servers while reading messages. + */ + InterruptPending = true; + } + else if (CheckingRemoteServersTimeoutPending)Would the code be more readable if the above two if blocks be moved
inside one enclosing if block (factoring the common condition)?
+ if (CheckingRemoteServersTimeoutPending)
+1. Will fix.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Hi,
It is Okay to keep the macros.
Thanks
On 2021-11-29 21:36, Zhihong Yu wrote:
On Mon, Nov 29, 2021 at 12:51 AM kuroda.hayato@fujitsu.com
<kuroda.hayato@fujitsu.com> wrote:Dear Zhihong,
Thank you for giving comments! I'll post new patches later.
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS()
(CheckingRemoteServersHoldoffCount++)
The macro contains only one operation. Can the macro be removed
(with `CheckingRemoteServersHoldoffCount++` inlined) ?
Hmm, these HOLD/RESUME macros are followed HOLD_INTERRUPUST() and
HOLD_CANCEL_INTERRUPTS():```
#define HOLD_INTERRUPTS() (InterruptHoldoffCount++)#define RESUME_INTERRUPTS() \
do { \
Assert(InterruptHoldoffCount > 0); \
InterruptHoldoffCount--; \
} while(0)#define HOLD_CANCEL_INTERRUPTS() (QueryCancelHoldoffCount++)
#define RESUME_CANCEL_INTERRUPTS() \
do { \
Assert(QueryCancelHoldoffCount > 0); \
QueryCancelHoldoffCount--; \
} while(0)#define START_CRIT_SECTION() (CritSectionCount++)
#define END_CRIT_SECTION() \
do { \
Assert(CritSectionCount > 0); \
CritSectionCount--; \
} while(0)
```So I want to keep the current style. Could you tell me if you have
any other reasons?+ if (CheckingRemoteServersTimeoutPending &&
CheckingRemoteServersHoldoffCount != 0)
+ { + /* + * Skip checking foreign servers while reading messages. + */ + InterruptPending = true; + } + else if (CheckingRemoteServersTimeoutPending)Would the code be more readable if the above two if blocks be
moved inside one enclosing if block (factoring the common
condition)?+ if (CheckingRemoteServersTimeoutPending)
+1. Will fix.
Best Regards,
Hayato Kuroda
FUJITSU LIMITEDHi,
It is Okay to keep the macros.
Thanks
Hi, Kuroda-san. Sorry for late reply.
Even for local-only transaction, I thought it useless to execute
CallCheckingRemoteServersCallbacks() and enable_timeout_after(). Can I
make it so that it determines outside whether it contains SQL to the
remote or not?
The following points are minor.
1. In foreign.c, some of the lines are too long and should be broken.
2. In pqcomm.c, the newline have been removed, what is the intention of
this?
3. In postgres.c,
3-1. how about inserting a comment between lines 2713 and 2714, similar
to line 2707?
3-2. the line breaks in line 3242 and line 3243 should be aligned.
3-3. you should change
/*
* Skip checking foreign servers while reading messages.
*/
to
/*
* Skip checking foreign servers while reading messages.
*/
4. In connection.c, There is a typo in line 1684, so "fucntion" should
be changed to "function".
--
Regards,
--
Shinya Kato
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Kato-san,
Thank you for giving comments! And sorry for late reply.
I rebased my patches.
Even for local-only transaction, I thought it useless to execute
CallCheckingRemoteServersCallbacks() and enable_timeout_after(). Can I
make it so that it determines outside whether it contains SQL to the
remote or not?
Yeah, remote-checking timeout will be enable even ifa local transaction is opened.
In my understanding, postgres cannot distinguish whether opening transactions
are using only local object or not.
My first idea was that turning on the timeout when GetFdwRoutineXXX functions
were called, but in some cases FDWs may not use remote connection even if
they call such a handler function. e.g. postgresExplainForeignScan().
Hence I tried another approach that unregister all checking callback
the end of each transactions. Only FDWs can notice that transactions are remote or local,
so they must register callback when they really connect to other database.
This implementation will avoid calling remote checking in the case of local transaction,
but multiple registering and unregistering may lead another overhead.
I attached which implements that.
The following points are minor.
1. In foreign.c, some of the lines are too long and should be broken.
2. In pqcomm.c, the newline have been removed, what is the intention of
this?
3. In postgres.c,
3-1. how about inserting a comment between lines 2713 and 2714, similar
to line 2707?
3-2. the line breaks in line 3242 and line 3243 should be aligned.
3-3. you should change
/*
* Skip checking foreign servers while reading
messages.
*/
to
/*
* Skip checking foreign servers while reading
messages.
*/
4. In connection.c, There is a typo in line 1684, so "fucntion" should
be changed to "function".
Maybe all of them were fixed. Thanks!
How do you think?
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v05_0001_add_checking_infrastracture.patchapplication/octet-stream; name=v05_0001_add_checking_infrastracture.patchDownload
diff --git a/src/backend/commands/copyfromparse.c b/src/backend/commands/copyfromparse.c
index aac10165ec..0c4d61a34c 100644
--- a/src/backend/commands/copyfromparse.c
+++ b/src/backend/commands/copyfromparse.c
@@ -269,6 +269,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
readmessage:
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
mtype = pq_getbyte();
if (mtype == EOF)
@@ -300,6 +301,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
ereport(ERROR,
(errcode(ERRCODE_CONNECTION_FAILURE),
errmsg("unexpected EOF on client connection with an open transaction")));
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
/* ... and process it */
switch (mtype)
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index e07cc57431..d6a6d3d215 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -14,6 +14,7 @@
#include "access/htup_details.h"
#include "access/reloptions.h"
+#include "access/xact.h"
#include "catalog/pg_foreign_data_wrapper.h"
#include "catalog/pg_foreign_server.h"
#include "catalog/pg_foreign_table.h"
@@ -26,7 +27,13 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
+/* for checking remote servers */
+int remote_servers_connection_check_interval = 0;
+static CheckingRemoteServersCallbackItem *fdw_callbacks = NULL;
+static bool isRegistered = false;
+static void UnregisterCheckingCallbacks(XactEvent event, void *arg);
/*
* GetForeignDataWrapper - look up the foreign-data wrapper by OID.
@@ -836,3 +843,144 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
}
return NULL;
}
+
+/*
+ * Register callbacks for checking remote servers.
+ *
+ * This function is intended for use by FDW extensions.
+ * The checking timeout will be fired after registering the first callback.
+ */
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+ /* should we start checking timeout? */
+ bool shouldStart = !HaveCheckingRemoteServersCallbacks();
+
+ item = (CheckingRemoteServersCallbackItem *)
+ MemoryContextAlloc(TopMemoryContext,
+ sizeof(CheckingRemoteServersCallbackItem));
+ item->callback = callback;
+ item->arg = arg;
+ item->next = fdw_callbacks;
+ fdw_callbacks = item;
+
+ if (shouldStart && remote_servers_connection_check_interval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+
+ if (!isRegistered)
+ {
+ RegisterXactCallback(UnregisterCheckingCallbacks, NULL);
+ isRegistered = true;
+ }
+}
+
+static void
+UnregisterCheckingCallbacks(XactEvent event, void *arg)
+{
+ if (event != XACT_EVENT_PRE_COMMIT &&
+ event != XACT_EVENT_PRE_PREPARE)
+ UnregisterAllCheckingRemoteServersCallback();
+}
+
+/*
+ * Unregister the specified callback.
+ */
+void
+UnregisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+ CheckingRemoteServersCallbackItem *prev;
+
+ prev = NULL;
+ for (item = fdw_callbacks; item; prev = item, item = item->next)
+ {
+ if (item->callback == callback && item->arg == arg)
+ {
+ if (prev)
+ prev->next = item->next;
+ else
+ fdw_callbacks = item->next;
+ pfree(item);
+ break;
+ }
+ }
+ if (!HaveCheckingRemoteServersCallbacks() &&
+ get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ disable_timeout(CHECKING_REMOTE_SERVERS_TIMEOUT, false);
+}
+
+/*
+ * Unregister all callbacks.
+ *
+ * This function is called when commit/abort any transactions.
+ */
+void
+UnregisterAllCheckingRemoteServersCallback(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+ item = fdw_callbacks;
+ while (item)
+ {
+ CheckingRemoteServersCallbackItem *next;
+ next = item->next;
+ pfree(item);
+ item = next;
+ }
+ fdw_callbacks = NULL;
+ if (get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ disable_timeout(CHECKING_REMOTE_SERVERS_TIMEOUT, false);
+}
+
+/*
+ * Call callbacks for checking remote servers.
+ *
+ * Note that this function will not return anything.
+ * Callback functions must throw ereport(ERROR)
+ * if disconnection has been detected.
+ */
+void
+CallCheckingRemoteServersCallbacks(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+ for (item = fdw_callbacks; item; item = item->next)
+ item->callback(item->arg);
+}
+
+/*
+ * Check whether any callbacks has been registered.
+ */
+bool
+HaveCheckingRemoteServersCallbacks(void)
+{
+ return fdw_callbacks != NULL;
+}
+
+void
+assign_remote_servers_connection_check_interval(int newval,
+ void *extra)
+{
+ /* Quick return if we don't have any callbacks */
+ if (!HaveCheckingRemoteServersCallbacks())
+ return;
+
+ if (get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ {
+ /* disable timeout if zero */
+ if (newval == 0)
+ disable_timeout(CHECKING_REMOTE_SERVERS_TIMEOUT, false);
+
+ /*
+ * we don't have to do anything because
+ * new value will be used in ProcessInterrupts().
+ */
+ return;
+ }
+
+ if (newval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ newval);
+}
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 82de01cdc6..de0ed3f7b6 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -44,6 +44,7 @@
#include "commands/prepare.h"
#include "common/pg_prng.h"
#include "executor/spi.h"
+#include "foreign/foreign.h"
#include "jit/jit.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@@ -350,6 +351,7 @@ SocketBackend(StringInfo inBuf)
* Get message type code from the frontend.
*/
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
qtype = pq_getbyte();
@@ -456,6 +458,7 @@ SocketBackend(StringInfo inBuf)
*/
if (pq_getmessage(inBuf, maxmsglen))
return EOF; /* suitable message already logged */
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
return qtype;
@@ -2709,6 +2712,13 @@ start_xact_command(void)
!get_timeout_active(CLIENT_CONNECTION_CHECK_TIMEOUT))
enable_timeout_after(CLIENT_CONNECTION_CHECK_TIMEOUT,
client_connection_check_interval);
+ if (remote_servers_connection_check_interval > 0 &&
+ IsUnderPostmaster &&
+ MyProcPort &&
+ HaveCheckingRemoteServersCallbacks() &&
+ !get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
}
static void
@@ -3214,6 +3224,27 @@ ProcessInterrupts(void)
}
}
+ if (CheckingRemoteServersTimeoutPending)
+ {
+ if (CheckingRemoteServersHoldoffCount != 0)
+ {
+ /*
+ * Skip checking foreign servers while reading messages.
+ */
+ InterruptPending = true;
+ }
+ else
+ {
+ CheckingRemoteServersTimeoutPending = false;
+
+ CallCheckingRemoteServersCallbacks();
+
+ if (remote_servers_connection_check_interval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+ }
+ }
+
if (ClientConnectionLost)
{
QueryCancelPending = false; /* lost connection trumps QueryCancel */
diff --git a/src/backend/utils/init/globals.c b/src/backend/utils/init/globals.c
index 381d9e548d..15b0c2727b 100644
--- a/src/backend/utils/init/globals.c
+++ b/src/backend/utils/init/globals.c
@@ -36,9 +36,11 @@ volatile sig_atomic_t IdleInTransactionSessionTimeoutPending = false;
volatile sig_atomic_t IdleSessionTimeoutPending = false;
volatile sig_atomic_t ProcSignalBarrierPending = false;
volatile sig_atomic_t LogMemoryContextPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
volatile uint32 InterruptHoldoffCount = 0;
volatile uint32 QueryCancelHoldoffCount = 0;
volatile uint32 CritSectionCount = 0;
+volatile uint32 CheckingRemoteServersHoldoffCount = 0;
int MyProcPid;
pg_time_t MyStartTime;
diff --git a/src/backend/utils/init/postinit.c b/src/backend/utils/init/postinit.c
index 7292e51f7d..3f936be326 100644
--- a/src/backend/utils/init/postinit.c
+++ b/src/backend/utils/init/postinit.c
@@ -73,6 +73,7 @@ static void LockTimeoutHandler(void);
static void IdleInTransactionSessionTimeoutHandler(void);
static void IdleSessionTimeoutHandler(void);
static void ClientCheckTimeoutHandler(void);
+static void CheckingRemoteServersTimeoutHandler(void);
static bool ThereIsAtLeastOneRole(void);
static void process_startup_options(Port *port, bool am_superuser);
static void process_settings(Oid databaseid, Oid roleid);
@@ -621,6 +622,7 @@ InitPostgres(const char *in_dbname, Oid dboid, const char *username,
IdleInTransactionSessionTimeoutHandler);
RegisterTimeout(IDLE_SESSION_TIMEOUT, IdleSessionTimeoutHandler);
RegisterTimeout(CLIENT_CONNECTION_CHECK_TIMEOUT, ClientCheckTimeoutHandler);
+ RegisterTimeout(CHECKING_REMOTE_SERVERS_TIMEOUT, CheckingRemoteServersTimeoutHandler);
}
/*
@@ -1239,6 +1241,14 @@ ClientCheckTimeoutHandler(void)
SetLatch(MyLatch);
}
+static void
+CheckingRemoteServersTimeoutHandler(void)
+{
+ CheckingRemoteServersTimeoutPending = true;
+ InterruptPending = true;
+ SetLatch(MyLatch);
+}
+
/*
* Returns true if at least one role is defined in this database cluster.
*/
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index f736e8d872..763f8198e5 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -51,6 +51,7 @@
#include "commands/vacuum.h"
#include "commands/variable.h"
#include "common/string.h"
+#include "foreign/foreign.h"
#include "funcapi.h"
#include "jit/jit.h"
#include "libpq/auth.h"
@@ -105,6 +106,7 @@
#include "utils/queryjumble.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/timeout.h"
#include "utils/tzparser.h"
#include "utils/inval.h"
#include "utils/varlena.h"
@@ -3590,6 +3592,18 @@ static struct config_int ConfigureNamesInt[] =
NULL, NULL, NULL
},
+
+ {
+ {"remote_servers_connection_check_interval", PGC_USERSET, CONN_AUTH_SETTINGS,
+ gettext_noop("Sets the time interval between checks for disconnection of remote servers."),
+ NULL,
+ GUC_UNIT_MS
+ },
+ &remote_servers_connection_check_interval,
+ 0, 0, INT_MAX,
+ NULL, assign_remote_servers_connection_check_interval, NULL
+ },
+
/* End-of-list marker */
{
{NULL, 0, 0, NULL, NULL}, NULL, 0, 0, 0, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index a1acd46b61..cad3c72336 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -90,6 +90,10 @@
# disconnection while running queries;
# 0 for never
+#remote_servers_connection_check_interval = 0 # time between time between checks for
+ # foreign server disconnection;
+ # 0 for never
+
# - Authentication -
#authentication_timeout = 1min # 1s-600s
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 8169eb76b1..a1e01d91e4 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -81,4 +81,26 @@ extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum);
extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok);
extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);
+
+/* functions and variables for fdw checking. */
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+typedef struct CheckingRemoteServersCallbackItem
+{
+ struct CheckingRemoteServersCallbackItem *next;
+ CheckingRemoteServersCallback callback;
+ void *arg;
+} CheckingRemoteServersCallbackItem;
+
+extern void RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg);
+extern void UnregisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg);
+extern void UnregisterAllCheckingRemoteServersCallback(void);
+extern void CallCheckingRemoteServersCallbacks(void);
+extern bool HaveCheckingRemoteServersCallbacks(void);
+
+extern int remote_servers_connection_check_interval;
+extern void assign_remote_servers_connection_check_interval(int newval,
+ void *extra);
+
#endif /* FOREIGN_H */
diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h
index 90a3016065..377fc68aaa 100644
--- a/src/include/miscadmin.h
+++ b/src/include/miscadmin.h
@@ -98,10 +98,13 @@ extern PGDLLIMPORT volatile sig_atomic_t LogMemoryContextPending;
extern PGDLLIMPORT volatile sig_atomic_t CheckClientConnectionPending;
extern PGDLLIMPORT volatile sig_atomic_t ClientConnectionLost;
+extern PGDLLIMPORT volatile sig_atomic_t CheckingRemoteServersTimeoutPending;
+
/* these are marked volatile because they are examined by signal handlers: */
extern PGDLLIMPORT volatile uint32 InterruptHoldoffCount;
extern PGDLLIMPORT volatile uint32 QueryCancelHoldoffCount;
extern PGDLLIMPORT volatile uint32 CritSectionCount;
+extern PGDLLIMPORT volatile uint32 CheckingRemoteServersHoldoffCount;
/* in tcop/postgres.c */
extern void ProcessInterrupts(void);
@@ -126,7 +129,7 @@ do { \
/* Is ProcessInterrupts() guaranteed to clear InterruptPending? */
#define INTERRUPTS_CAN_BE_PROCESSED() \
(InterruptHoldoffCount == 0 && CritSectionCount == 0 && \
- QueryCancelHoldoffCount == 0)
+ QueryCancelHoldoffCount == 0 && CheckingRemoteServersHoldoffCount == 0)
#define HOLD_INTERRUPTS() (InterruptHoldoffCount++)
@@ -152,6 +155,13 @@ do { \
CritSectionCount--; \
} while(0)
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS() (CheckingRemoteServersHoldoffCount++)
+
+#define RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS() \
+do { \
+ Assert(CheckingRemoteServersHoldoffCount > 0); \
+ CheckingRemoteServersHoldoffCount--; \
+} while(0)
/*****************************************************************************
* globals.h -- *
diff --git a/src/include/utils/timeout.h b/src/include/utils/timeout.h
index 2cbc5de4d9..ceb6b1c12c 100644
--- a/src/include/utils/timeout.h
+++ b/src/include/utils/timeout.h
@@ -34,6 +34,7 @@ typedef enum TimeoutId
IDLE_SESSION_TIMEOUT,
CLIENT_CONNECTION_CHECK_TIMEOUT,
STARTUP_PROGRESS_TIMEOUT,
+ CHECKING_REMOTE_SERVERS_TIMEOUT,
/* First user-definable timeout reason */
USER_TIMEOUT,
/* Maximum number of timeout reasons */
v05_0002_add_doc.patchapplication/octet-stream; name=v05_0002_add_doc.patchDownload
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index afbb6c35e3..08c372db63 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -1012,9 +1012,9 @@ include_dir 'conf.d'
the kernel reports that the connection is closed.
</para>
<para>
- This option is currently available only on systems that support the
- non-standard <symbol>POLLRDHUP</symbol> extension to the
- <symbol>poll</symbol> system call, including Linux.
+ This option relies on kernel events exposed by Linux, macOS, illumos
+ and the BSD family of operating systems, and is not currently available
+ on other systems.
</para>
<para>
If the value is specified without units, it is taken as milliseconds.
@@ -1035,6 +1035,25 @@ include_dir 'conf.d'
</listitem>
</varlistentry>
+ <varlistentry id="guc-remote-servers-connection-check-interval" xreflabel="remote_servers_connection_check_interval">
+ <term><varname>remote_servers_connection_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>remote_servers_connection_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that the remote servers
+ are still alive. If this parameter is set to a valid value, registered
+ callback functions are executed at the specified time interval.
+ If your FDW extension does not implement a callback function, nothing
+ happens after the specified amount of time. If the value is specified
+ without units, it is taken as milliseconds. The default value is
+ <literal>0</literal>, this means the feature is disabled.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
diff --git a/doc/src/sgml/fdwhandler.sgml b/doc/src/sgml/fdwhandler.sgml
index dbf5dd3d15..38e67730bf 100644
--- a/doc/src/sgml/fdwhandler.sgml
+++ b/doc/src/sgml/fdwhandler.sgml
@@ -2136,4 +2136,28 @@ GetForeignServerByName(const char *name, bool missing_ok);
</sect1>
+ <sect1 id="fdw-checking-remote-servers">
+ <title>Checking the Health of Remote Servers via Foreign Data Wrapper</title>
+
+ <para>
+ For verifying the health of remote servers, callback functions can be
+ registered that runs periodically. The time interval is controlled by
+ <xref linkend="guc-remote-servers-connection-check-interval"/>.
+ The API for registering functions is:
+ <programlisting>
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg);
+ </programlisting>
+ Only functions that return void can be registered as callback functions.
+ Please set to void* arg a pointer if you want to pass an argument.
+ If you have problems with the health check results and want to
+ abort the transaction, please execute <function>ereport(ERROR)</function>
+ in the callback function.
+ Note that callback functions will be released at end of each transaction.
+ Please register callback functions every time you connect to remote servers.
+ </para>
+
+ </sect1>
+
+
</chapter>
Thank you for the new patch!
On 2021-12-15 15:40, kuroda.hayato@fujitsu.com wrote:
Dear Kato-san,
Thank you for giving comments! And sorry for late reply.
I rebased my patches.Even for local-only transaction, I thought it useless to execute
CallCheckingRemoteServersCallbacks() and enable_timeout_after(). Can I
make it so that it determines outside whether it contains SQL to the
remote or not?Yeah, remote-checking timeout will be enable even ifa local
transaction is opened.
In my understanding, postgres cannot distinguish whether opening
transactions
are using only local object or not.
My first idea was that turning on the timeout when GetFdwRoutineXXX
functions
were called, but in some cases FDWs may not use remote connection even
if
they call such a handler function. e.g. postgresExplainForeignScan().
Hence I tried another approach that unregister all checking callback
the end of each transactions. Only FDWs can notice that transactions
are remote or local,
so they must register callback when they really connect to other
database.
This implementation will avoid calling remote checking in the case of
local transaction,
but multiple registering and unregistering may lead another overhead.
I attached which implements that.
It certainly incurs another overhead, but I think it's better than the
previous one.
So far, I haven't encountered any problems, but I'd like other people's
opinions.
The following points are minor.
1. In foreign.c, some of the lines are too long and should be broken.
2. In pqcomm.c, the newline have been removed, what is the intention
of
this?
3. In postgres.c,
3-1. how about inserting a comment between lines 2713 and 2714,
similar
to line 2707?
3-2. the line breaks in line 3242 and line 3243 should be aligned.
3-3. you should change
/*
* Skip checking foreign servers while reading
messages.
*/
to
/*
* Skip checking foreign servers while reading
messages.
*/
4. In connection.c, There is a typo in line 1684, so "fucntion" should
be changed to "function".Maybe all of them were fixed. Thanks!
Thank you, and it looks good to me.
--
Regards,
--
Shinya Kato
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
On Tue, Jan 4, 2022 at 10:21 PM Shinya Kato <Shinya11.Kato@oss.nttdata.com>
wrote:
Thank you for the new patch!
On 2021-12-15 15:40, kuroda.hayato@fujitsu.com wrote:
Dear Kato-san,
Thank you for giving comments! And sorry for late reply.
I rebased my patches.Even for local-only transaction, I thought it useless to execute
CallCheckingRemoteServersCallbacks() and enable_timeout_after(). Can I
make it so that it determines outside whether it contains SQL to the
remote or not?Yeah, remote-checking timeout will be enable even ifa local
transaction is opened.
In my understanding, postgres cannot distinguish whether opening
transactions
are using only local object or not.
My first idea was that turning on the timeout when GetFdwRoutineXXX
functions
were called, but in some cases FDWs may not use remote connection even
if
they call such a handler function. e.g. postgresExplainForeignScan().
Hence I tried another approach that unregister all checking callback
the end of each transactions. Only FDWs can notice that transactions
are remote or local,
so they must register callback when they really connect to other
database.
This implementation will avoid calling remote checking in the case of
local transaction,
but multiple registering and unregistering may lead another overhead.
I attached which implements that.It certainly incurs another overhead, but I think it's better than the
previous one.
So far, I haven't encountered any problems, but I'd like other people's
opinions.The following points are minor.
1. In foreign.c, some of the lines are too long and should be broken.
2. In pqcomm.c, the newline have been removed, what is the intention
of
this?
3. In postgres.c,
3-1. how about inserting a comment between lines 2713 and 2714,
similar
to line 2707?
3-2. the line breaks in line 3242 and line 3243 should be aligned.
3-3. you should change
/*
* Skip checking foreign servers while reading
messages.
*/
to
/*
* Skip checking foreign servers while reading
messages.
*/
4. In connection.c, There is a typo in line 1684, so "fucntion" should
be changed to "function".Maybe all of them were fixed. Thanks!
Thank you, and it looks good to me.
Hi,
+ UnregisterAllCheckingRemoteServersCallback();
UnregisterAllCheckingRemoteServersCallback
-> UnregisterAllCheckingRemoteServersCallbacks
+ CheckingRemoteServersCallbackItem *item;
+ item = fdw_callbacks;
The above two lines can be combined.
+UnregisterCheckingRemoteServersCallback(CheckingRemoteServersCallback
callback,
+ void *arg)
Is the above func called anywhere ?
+ if (item->callback == callback && item->arg == arg)
Is comparing argument pointers stable ? What if the same argument is cloned
?
+ CallCheckingRemoteServersCallbacks();
+
+ if (remote_servers_connection_check_interval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+
remote_servers_connection_check_interval);
Should the call to CallCheckingRemoteServersCallbacks() be placed under the
if block checking remote_servers_connection_check_interval ?
If remote_servers_connection_check_interval is 0, it seems the callbacks
shouldn't be called.
Cheers
On 2021/12/15 15:40, kuroda.hayato@fujitsu.com wrote:
Yeah, remote-checking timeout will be enable even ifa local transaction is opened.
In my understanding, postgres cannot distinguish whether opening transactions
are using only local object or not.
My first idea was that turning on the timeout when GetFdwRoutineXXX functions
were called,
What about starting the timeout in GetConnection(), instead?
I attached which implements that.
v05_0004_add_tests.patch failed to be applied to the master. Could you rebase it?
- This option is currently available only on systems that support the
- non-standard <symbol>POLLRDHUP</symbol> extension to the
- <symbol>poll</symbol> system call, including Linux.
+ This option relies on kernel events exposed by Linux, macOS, illumos
+ and the BSD family of operating systems, and is not currently available
+ on other systems.
The above change is included in both v5-0003-Use-WL_SOCKET_CLOSED-for-client_connection_check_.patch and v05_0002_add_doc.patch. If it should be in the former patch, it should be removed from your patch v05_0002_add_doc.patch.
There seems no user of UnregisterCheckingRemoteServersCallback(). So how about removing it?
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Zhihong,
Thank you for reviewing! And I have to apologize for the late.
I'll post new patchset later.
+ UnregisterAllCheckingRemoteServersCallback();
UnregisterAllCheckingRemoteServersCallback
-> UnregisterAllCheckingRemoteServersCallbacks
Will fix.
+ CheckingRemoteServersCallbackItem *item; + item = fdw_callbacks;The above two lines can be combined.
Will fix.
+UnregisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, + void *arg)Is the above func called anywhere ?
Currently not, I just kept the API because of any other FDW extensions.
But I cannot find any use cases, so will remove.
+ if (item->callback == callback && item->arg == arg)
Is comparing argument pointers stable ? What if the same argument is cloned
?
This part is no longer needed. Will remove.
+ CallCheckingRemoteServersCallbacks(); + + if (remote_servers_connection_check_interval > 0) + enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT, + remote_servers_connection_check_interval);Should the call to CallCheckingRemoteServersCallbacks() be placed under the
if block checking remote_servers_connection_check_interval ?
If remote_servers_connection_check_interval is 0, it seems the callbacks
shouldn't be called.
Agreed. We force stopping timeout when the GUC sets to 0 in assign_hook,
so your saying is consistent. Will move.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Dear Fujii-san,
Thank you for your interest! I'll post new version within several days.
Yeah, remote-checking timeout will be enable even ifa local transaction is
opened.
In my understanding, postgres cannot distinguish whether opening transactions
are using only local object or not.
My first idea was that turning on the timeout when GetFdwRoutineXXXfunctions
were called,
What about starting the timeout in GetConnection(), instead?
Did you said about a function in postgres_fdw/connection.c?
In my understanding that means that the timeout should be enabled or disabled
by each FDW extensions.
I did not find bad cases for that, so I'll change like that and make new APIs.
v05_0004_add_tests.patch failed to be applied to the master. Could you rebase it?
It's caused because a testcase was added in postgres_fdw. Will rebase.
The above change is included in both
v5-0003-Use-WL_SOCKET_CLOSED-for-client_connection_check_.patch and
v05_0002_add_doc.patch. If it should be in the former patch, it should be removed
from your patch v05_0002_add_doc.patch.
I confused about doc-patch. Sorry for inconvenience.
There seems no user of UnregisterCheckingRemoteServersCallback(). So how
about removing it?
Previously I kept the API for any other extensions, but I cannot find use cases.
Will remove.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Dear Fujii-san, Zhihong,
I attached the latest version.
The biggest change is that callbacks are no longer un-registered at the end of transactions.
FDW developer must enable or disable timeout instead, via new APIs.
The timer will be turned on when:
* new GUC is >= 0, and
* anyone calls TryEnableRemoteServerCheckingTimeout().
I think this version is reduced overhead, but it might not be developer friendly...
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v06_0002_add_doc.patchapplication/octet-stream; name=v06_0002_add_doc.patchDownload
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 4cd9818acf..870221fab4 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -1035,6 +1035,25 @@ include_dir 'conf.d'
</listitem>
</varlistentry>
+ <varlistentry id="guc-remote-servers-connection-check-interval" xreflabel="remote_servers_connection_check_interval">
+ <term><varname>remote_servers_connection_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>remote_servers_connection_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that the remote servers
+ are still alive. If this parameter is set to a valid value, registered
+ callback functions are executed at the specified time interval.
+ If your FDW extension does not implement a callback function, nothing
+ happens after the specified amount of time. If the value is specified
+ without units, it is taken as milliseconds. The default value is
+ <literal>0</literal>, this means the feature is disabled.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
diff --git a/doc/src/sgml/fdwhandler.sgml b/doc/src/sgml/fdwhandler.sgml
index dbf5dd3d15..f7482ab79f 100644
--- a/doc/src/sgml/fdwhandler.sgml
+++ b/doc/src/sgml/fdwhandler.sgml
@@ -2136,4 +2136,40 @@ GetForeignServerByName(const char *name, bool missing_ok);
</sect1>
+ <sect1 id="fdw-checking-remote-servers">
+ <title>Checking the Health of Remote Servers via Foreign Data Wrapper</title>
+
+ <para>
+ For verifying the health of remote servers, callback functions can be
+ registered that runs periodically. The time interval is controlled by
+ <xref linkend="guc-remote-servers-connection-check-interval"/>.
+ The API for registering functions is:
+ <programlisting>
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg);
+ </programlisting>
+ Only functions that return void can be registered as callback functions.
+ Please set to void* arg a pointer if you want to pass an argument.
+ If you have problems with the health check results and want to
+ abort the transaction, please execute <function>ereport(ERROR)</function>
+ in the callback function.
+ </para>
+ <para>
+ Note that starting or stopping the periodic execution is FDW's responsibility.
+ If you want to start verification, the following function must be performed
+ after registering callback functions:
+ <programlisting>
+int
+TryEnableRemoteServerCheckingTimeout(void)
+ </programlisting>
+ If you want to stop, the following function must be performed:
+ <programlisting>
+int
+TryDisableRemoteServerCheckingTimeout(void)
+ </programlisting>
+ </para>
+
+ </sect1>
+
+
</chapter>
v06_0001_add_checking_infrastracture.patchapplication/octet-stream; name=v06_0001_add_checking_infrastracture.patchDownload
diff --git a/src/backend/commands/copyfromparse.c b/src/backend/commands/copyfromparse.c
index baf328b620..996386fdd4 100644
--- a/src/backend/commands/copyfromparse.c
+++ b/src/backend/commands/copyfromparse.c
@@ -269,6 +269,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
readmessage:
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
mtype = pq_getbyte();
if (mtype == EOF)
@@ -300,6 +301,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
ereport(ERROR,
(errcode(ERRCODE_CONNECTION_FAILURE),
errmsg("unexpected EOF on client connection with an open transaction")));
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
/* ... and process it */
switch (mtype)
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index 294e22c78c..9622058aaa 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -26,7 +26,13 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
+/* for checking remote servers */
+int remote_servers_connection_check_interval = 0;
+static CheckingRemoteServersCallbackItem *fdw_callbacks = NULL;
+/* counter for keeping re-entrancy */
+static int timeout_counter = 0;
/*
* GetForeignDataWrapper - look up the foreign-data wrapper by OID.
@@ -836,3 +842,98 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
}
return NULL;
}
+
+/*
+ * Register callbacks for checking remote servers.
+ *
+ * This function is intended for use by FDW extensions.
+ * The checking timeout will be fired after registering the first callback.
+ */
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+
+ item = (CheckingRemoteServersCallbackItem *)
+ MemoryContextAlloc(TopMemoryContext,
+ sizeof(CheckingRemoteServersCallbackItem));
+ item->callback = callback;
+ item->arg = arg;
+ item->next = fdw_callbacks;
+ fdw_callbacks = item;
+}
+
+/*
+ * Call callbacks for checking remote servers.
+ *
+ * Note that this function will not return anything.
+ * Callback functions must throw ereport(ERROR)
+ * if disconnection has been detected.
+ */
+void
+CallCheckingRemoteServersCallbacks(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+ for (item = fdw_callbacks; item; item = item->next)
+ item->callback(item->arg);
+}
+
+/*
+ * Increment counter, and enable timeout if it has been not started yet.
+ */
+int
+TryEnableRemoteServerCheckingTimeout(void)
+{
+ timeout_counter++;
+
+ if (remote_servers_connection_check_interval > 0 &&
+ !get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+
+ return timeout_counter;
+}
+
+/*
+ * Decrement counter, and disable timeout if it is no more needed.
+ *
+ * This functions must be called after TryEnableRemoteServerCheckingTimeout().
+ */
+int
+TryDisableRemoteServerCheckingTimeout(void)
+{
+ Assert(timeout_counter > 0);
+ timeout_counter--;
+
+ if (timeout_counter == 0 &&
+ get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ disable_timeout(CHECKING_REMOTE_SERVERS_TIMEOUT, false);
+
+ return timeout_counter;
+}
+
+void
+assign_remote_servers_connection_check_interval(int newval,
+ void *extra)
+{
+ /* Quick return if we don't have any callbacks */
+ if (fdw_callbacks == NULL)
+ return;
+
+ if (get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ {
+ if (newval == 0)
+ disable_timeout(CHECKING_REMOTE_SERVERS_TIMEOUT, false);
+
+ /*
+ * we don't have to do anything because
+ * new value will be used in ProcessInterrupts().
+ */
+ return;
+ }
+
+ /* Start timeout if anyone wants to */
+ if (newval > 0 && timeout_counter > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT, newval);
+}
\ No newline at end of file
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index fda2e9360e..60a7e91889 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -44,6 +44,7 @@
#include "commands/prepare.h"
#include "common/pg_prng.h"
#include "executor/spi.h"
+#include "foreign/foreign.h"
#include "jit/jit.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@@ -350,6 +351,7 @@ SocketBackend(StringInfo inBuf)
* Get message type code from the frontend.
*/
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
qtype = pq_getbyte();
@@ -456,6 +458,7 @@ SocketBackend(StringInfo inBuf)
*/
if (pq_getmessage(inBuf, maxmsglen))
return EOF; /* suitable message already logged */
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
return qtype;
@@ -3214,6 +3217,28 @@ ProcessInterrupts(void)
}
}
+ if (CheckingRemoteServersTimeoutPending)
+ {
+ if (CheckingRemoteServersHoldoffCount != 0)
+ {
+ /*
+ * Skip checking foreign servers while reading messages.
+ */
+ InterruptPending = true;
+ }
+ else
+ {
+ CheckingRemoteServersTimeoutPending = false;
+
+ if (remote_servers_connection_check_interval > 0)
+ {
+ CallCheckingRemoteServersCallbacks();
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+ }
+ }
+ }
+
if (ClientConnectionLost)
{
QueryCancelPending = false; /* lost connection trumps QueryCancel */
diff --git a/src/backend/utils/init/globals.c b/src/backend/utils/init/globals.c
index c26a1a73df..7efa9cff84 100644
--- a/src/backend/utils/init/globals.c
+++ b/src/backend/utils/init/globals.c
@@ -36,9 +36,11 @@ volatile sig_atomic_t IdleInTransactionSessionTimeoutPending = false;
volatile sig_atomic_t IdleSessionTimeoutPending = false;
volatile sig_atomic_t ProcSignalBarrierPending = false;
volatile sig_atomic_t LogMemoryContextPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
volatile uint32 InterruptHoldoffCount = 0;
volatile uint32 QueryCancelHoldoffCount = 0;
volatile uint32 CritSectionCount = 0;
+volatile uint32 CheckingRemoteServersHoldoffCount = 0;
int MyProcPid;
pg_time_t MyStartTime;
diff --git a/src/backend/utils/init/postinit.c b/src/backend/utils/init/postinit.c
index 0236165f60..d828097076 100644
--- a/src/backend/utils/init/postinit.c
+++ b/src/backend/utils/init/postinit.c
@@ -73,6 +73,7 @@ static void LockTimeoutHandler(void);
static void IdleInTransactionSessionTimeoutHandler(void);
static void IdleSessionTimeoutHandler(void);
static void ClientCheckTimeoutHandler(void);
+static void CheckingRemoteServersTimeoutHandler(void);
static bool ThereIsAtLeastOneRole(void);
static void process_startup_options(Port *port, bool am_superuser);
static void process_settings(Oid databaseid, Oid roleid);
@@ -621,6 +622,7 @@ InitPostgres(const char *in_dbname, Oid dboid, const char *username,
IdleInTransactionSessionTimeoutHandler);
RegisterTimeout(IDLE_SESSION_TIMEOUT, IdleSessionTimeoutHandler);
RegisterTimeout(CLIENT_CONNECTION_CHECK_TIMEOUT, ClientCheckTimeoutHandler);
+ RegisterTimeout(CHECKING_REMOTE_SERVERS_TIMEOUT, CheckingRemoteServersTimeoutHandler);
}
/*
@@ -1239,6 +1241,14 @@ ClientCheckTimeoutHandler(void)
SetLatch(MyLatch);
}
+static void
+CheckingRemoteServersTimeoutHandler(void)
+{
+ CheckingRemoteServersTimeoutPending = true;
+ InterruptPending = true;
+ SetLatch(MyLatch);
+}
+
/*
* Returns true if at least one role is defined in this database cluster.
*/
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index 4c94f09c64..fc64c2e63a 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -52,6 +52,7 @@
#include "commands/vacuum.h"
#include "commands/variable.h"
#include "common/string.h"
+#include "foreign/foreign.h"
#include "funcapi.h"
#include "jit/jit.h"
#include "libpq/auth.h"
@@ -106,6 +107,7 @@
#include "utils/queryjumble.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/timeout.h"
#include "utils/tzparser.h"
#include "utils/inval.h"
#include "utils/varlena.h"
@@ -3600,6 +3602,18 @@ static struct config_int ConfigureNamesInt[] =
NULL, NULL, NULL
},
+
+ {
+ {"remote_servers_connection_check_interval", PGC_USERSET, CONN_AUTH_SETTINGS,
+ gettext_noop("Sets the time interval between checks for disconnection of remote servers."),
+ NULL,
+ GUC_UNIT_MS
+ },
+ &remote_servers_connection_check_interval,
+ 0, 0, INT_MAX,
+ NULL, assign_remote_servers_connection_check_interval, NULL
+ },
+
/* End-of-list marker */
{
{NULL, 0, 0, NULL, NULL}, NULL, 0, 0, 0, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 817d5f5324..b97dc30514 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -90,6 +90,10 @@
# disconnection while running queries;
# 0 for never
+#remote_servers_connection_check_interval = 0 # time between time between checks for
+ # foreign server disconnection;
+ # 0 for never
+
# - Authentication -
#authentication_timeout = 1min # 1s-600s
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 75538110fc..76364ce8a3 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -81,4 +81,24 @@ extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum);
extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok);
extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);
+
+/* functions and variables for fdw checking. */
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+typedef struct CheckingRemoteServersCallbackItem
+{
+ struct CheckingRemoteServersCallbackItem *next;
+ CheckingRemoteServersCallback callback;
+ void *arg;
+} CheckingRemoteServersCallbackItem;
+
+extern void RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg);
+extern void CallCheckingRemoteServersCallbacks(void);
+
+extern int TryEnableRemoteServerCheckingTimeout(void);
+extern int TryDisableRemoteServerCheckingTimeout(void);
+
+extern int remote_servers_connection_check_interval;
+extern void assign_remote_servers_connection_check_interval(int newval,
+ void *extra);
#endif /* FOREIGN_H */
diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h
index 02276d3edd..0319fe1605 100644
--- a/src/include/miscadmin.h
+++ b/src/include/miscadmin.h
@@ -98,10 +98,13 @@ extern PGDLLIMPORT volatile sig_atomic_t LogMemoryContextPending;
extern PGDLLIMPORT volatile sig_atomic_t CheckClientConnectionPending;
extern PGDLLIMPORT volatile sig_atomic_t ClientConnectionLost;
+extern PGDLLIMPORT volatile sig_atomic_t CheckingRemoteServersTimeoutPending;
+
/* these are marked volatile because they are examined by signal handlers: */
extern PGDLLIMPORT volatile uint32 InterruptHoldoffCount;
extern PGDLLIMPORT volatile uint32 QueryCancelHoldoffCount;
extern PGDLLIMPORT volatile uint32 CritSectionCount;
+extern PGDLLIMPORT volatile uint32 CheckingRemoteServersHoldoffCount;
/* in tcop/postgres.c */
extern void ProcessInterrupts(void);
@@ -126,7 +129,7 @@ do { \
/* Is ProcessInterrupts() guaranteed to clear InterruptPending? */
#define INTERRUPTS_CAN_BE_PROCESSED() \
(InterruptHoldoffCount == 0 && CritSectionCount == 0 && \
- QueryCancelHoldoffCount == 0)
+ QueryCancelHoldoffCount == 0 && CheckingRemoteServersHoldoffCount == 0)
#define HOLD_INTERRUPTS() (InterruptHoldoffCount++)
@@ -152,6 +155,13 @@ do { \
CritSectionCount--; \
} while(0)
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS() (CheckingRemoteServersHoldoffCount++)
+
+#define RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS() \
+do { \
+ Assert(CheckingRemoteServersHoldoffCount > 0); \
+ CheckingRemoteServersHoldoffCount--; \
+} while(0)
/*****************************************************************************
* globals.h -- *
diff --git a/src/include/utils/timeout.h b/src/include/utils/timeout.h
index 099f91c61d..7f02a8b491 100644
--- a/src/include/utils/timeout.h
+++ b/src/include/utils/timeout.h
@@ -34,6 +34,7 @@ typedef enum TimeoutId
IDLE_SESSION_TIMEOUT,
CLIENT_CONNECTION_CHECK_TIMEOUT,
STARTUP_PROGRESS_TIMEOUT,
+ CHECKING_REMOTE_SERVERS_TIMEOUT,
/* First user-definable timeout reason */
USER_TIMEOUT,
/* Maximum number of timeout reasons */
On 2022/01/21 15:08, kuroda.hayato@fujitsu.com wrote:
Dear Fujii-san, Zhihong,
I attached the latest version.
Thanks for updating the patch!
+int
+TryDisableRemoteServerCheckingTimeout(void)
When more than one FDWs are used, even if one FDW calls this function to disable the timeout, its remote-server-check-callback can still be called. Is this OK?
Please imagine the case where two FDWs are used and they registered their callbacks. Even when one FDW calls TryDisableRemoteServerCheckingTimeout(), if another FDW has not called that yet, the timeout is still being enabled. If the timeout is triggered during that period, even the callback registered by the FDW that has already called TryDisableRemoteServerCheckingTimeout() would be called.
+ if (remote_servers_connection_check_interval > 0)
+ {
+ CallCheckingRemoteServersCallbacks();
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
LockErrorCleanup() needs to be called before reporting the error, doesn't it?
This can cause an error even while DoingCommandRead == true. Is that safe?
The biggest change is that callbacks are no longer un-registered at the end of transactions.
FDW developer must enable or disable timeout instead, via new APIs.The timer will be turned on when:
* new GUC is >= 0, and
This can cause the timeout to be enabled even when no remote transaction is started?
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Fujii-san,
Thank you for reviewing! I attached the latest version.
When more than one FDWs are used, even if one FDW calls this function to
disable the timeout, its remote-server-check-callback can still be called. Is this
OK?
Please imagine the case where two FDWs are used and they registered their
callbacks. Even when one FDW calls TryDisableRemoteServerCheckingTimeout(),
if another FDW has not called that yet, the timeout is still being enabled. If the
timeout is triggered during that period, even the callback registered by the FDW
that has already called TryDisableRemoteServerCheckingTimeout() would be
called.
Indeed and it should be avoided. I added a counter to CheckingRemoteServersCallbackItem.
The register function returns the registered item, and it must be set as the argument for
enable and disable functions.
Callback functions will be called when item->counter is larger than zero.
+ if (remote_servers_connection_check_interval > 0) + { + CallCheckingRemoteServersCallbacks(); + enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT, + remote_servers_connection_check_interval);LockErrorCleanup() needs to be called before reporting the error, doesn't it?
You are right. I think this suggests that error-reporting should be done in the core layer.
For meaningful error reporting, I changed a callback specification
that it should return ForeignServer* which points to downed remote server.
This can cause an error even while DoingCommandRead == true. Is that safe?
I read codes again and I think it is not safe. It is OK when whereToSendOutput is DestRemote,
but not good in InteractiveBackend().
I changed that if-statement for CheckingRemoteServersTimeoutPending is moved just after
ClientConnectionLost, because the that may throw a FATAL error and disconnect from client.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v07_0001_add_checking_infrastracture.patchapplication/octet-stream; name=v07_0001_add_checking_infrastracture.patchDownload
diff --git a/src/backend/commands/copyfromparse.c b/src/backend/commands/copyfromparse.c
index baf328b620..996386fdd4 100644
--- a/src/backend/commands/copyfromparse.c
+++ b/src/backend/commands/copyfromparse.c
@@ -269,6 +269,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
readmessage:
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
mtype = pq_getbyte();
if (mtype == EOF)
@@ -300,6 +301,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
ereport(ERROR,
(errcode(ERRCODE_CONNECTION_FAILURE),
errmsg("unexpected EOF on client connection with an open transaction")));
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
/* ... and process it */
switch (mtype)
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index 294e22c78c..9779eadf01 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -26,7 +26,13 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
+/* for checking remote servers */
+int remote_servers_connection_check_interval = 0;
+static CheckingRemoteServersCallbackItem *fdw_callbacks = NULL;
+/* counter for keeping re-entrancy */
+static int timeout_counter = 0;
/*
* GetForeignDataWrapper - look up the foreign-data wrapper by OID.
@@ -836,3 +842,111 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
}
return NULL;
}
+
+/*
+ * Register callbacks for checking remote servers.
+ *
+ * This function is intended for use by FDW extensions.
+ * The checking timeout will be fired after registering the first callback.
+ */
+CheckingRemoteServersCallbackItem *
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+
+ item = (CheckingRemoteServersCallbackItem *)
+ MemoryContextAlloc(TopMemoryContext,
+ sizeof(CheckingRemoteServersCallbackItem));
+ item->callback = callback;
+ item->counter = 0;
+ item->arg = arg;
+ item->next = fdw_callbacks;
+ fdw_callbacks = item;
+
+ return item;
+}
+
+/*
+ * Call callbacks for checking remote servers if needed.
+ * This retruns the downed server, or NULL if all servers are good.
+ */
+ForeignServer *
+CallCheckingRemoteServersCallbacks(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+ ForeignServer *server = NULL;
+
+ for (item = fdw_callbacks; item; item = item->next)
+ {
+ if (item->counter > 0)
+ {
+ server = item->callback(item->arg);
+ if (server != NULL)
+ break;
+ }
+ }
+
+ return server;
+}
+
+/*
+ * Increment counters, and enable timeout if it has been not started yet.
+ */
+int
+TryEnableRemoteServerCheckingTimeout(CheckingRemoteServersCallbackItem *item)
+{
+ timeout_counter++;
+ item->counter++;
+
+ if (remote_servers_connection_check_interval > 0 &&
+ !get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+
+ return timeout_counter;
+}
+
+/*
+ * Decrement counters, and disable timeout if it is no more needed.
+ *
+ * This functions must be called after TryEnableRemoteServerCheckingTimeout().
+ */
+int
+TryDisableRemoteServerCheckingTimeout(CheckingRemoteServersCallbackItem *item)
+{
+ Assert(timeout_counter > 0 && item->counter > 0);
+ timeout_counter--;
+ item->counter--;
+
+ if (timeout_counter == 0 &&
+ get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ disable_timeout(CHECKING_REMOTE_SERVERS_TIMEOUT, false);
+
+ return timeout_counter;
+}
+
+void
+assign_remote_servers_connection_check_interval(int newval,
+ void *extra)
+{
+ /* Quick return if we don't have any callbacks */
+ if (fdw_callbacks == NULL)
+ return;
+
+ if (get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ {
+ if (newval == 0)
+ disable_timeout(CHECKING_REMOTE_SERVERS_TIMEOUT, false);
+
+ /*
+ * we don't have to do anything because
+ * new value will be used in ProcessInterrupts().
+ */
+ return;
+ }
+
+ /* Start timeout if anyone wants to */
+ if (newval > 0 && timeout_counter > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT, newval);
+}
\ No newline at end of file
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index fda2e9360e..b99fcf7b48 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -44,6 +44,7 @@
#include "commands/prepare.h"
#include "common/pg_prng.h"
#include "executor/spi.h"
+#include "foreign/foreign.h"
#include "jit/jit.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@@ -350,6 +351,7 @@ SocketBackend(StringInfo inBuf)
* Get message type code from the frontend.
*/
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
qtype = pq_getbyte();
@@ -456,6 +458,7 @@ SocketBackend(StringInfo inBuf)
*/
if (pq_getmessage(inBuf, maxmsglen))
return EOF; /* suitable message already logged */
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
return qtype;
@@ -3225,6 +3228,39 @@ ProcessInterrupts(void)
errmsg("connection to client lost")));
}
+ if (CheckingRemoteServersTimeoutPending)
+ {
+ if (CheckingRemoteServersHoldoffCount != 0 || DoingCommandRead)
+ {
+ /*
+ * Skip checking foreign servers while reading messages or commands.
+ */
+ InterruptPending = true;
+ }
+ else
+ {
+ CheckingRemoteServersTimeoutPending = false;
+
+ /* Check remote servers and re-arm, if still configured. */
+ if (remote_servers_connection_check_interval > 0)
+ {
+ ForeignServer *downedServer = CallCheckingRemoteServersCallbacks();
+ if (downedServer != NULL)
+ {
+ LockErrorCleanup();
+ ereport(ERROR,
+ errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("foreign server \"%s\" disconnected due to the health-check failure",
+ downedServer->servername),
+ errdetail("Foreign server might be down."),
+ errhint("Please check the server and network health."));
+ }
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+ }
+ }
+ }
+
/*
* If a recovery conflict happens while we are waiting for input from the
* client, the client is presumably just sitting idle in a transaction,
diff --git a/src/backend/utils/init/globals.c b/src/backend/utils/init/globals.c
index c26a1a73df..7efa9cff84 100644
--- a/src/backend/utils/init/globals.c
+++ b/src/backend/utils/init/globals.c
@@ -36,9 +36,11 @@ volatile sig_atomic_t IdleInTransactionSessionTimeoutPending = false;
volatile sig_atomic_t IdleSessionTimeoutPending = false;
volatile sig_atomic_t ProcSignalBarrierPending = false;
volatile sig_atomic_t LogMemoryContextPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
volatile uint32 InterruptHoldoffCount = 0;
volatile uint32 QueryCancelHoldoffCount = 0;
volatile uint32 CritSectionCount = 0;
+volatile uint32 CheckingRemoteServersHoldoffCount = 0;
int MyProcPid;
pg_time_t MyStartTime;
diff --git a/src/backend/utils/init/postinit.c b/src/backend/utils/init/postinit.c
index 5b9ed2f6f5..9b0b4ddd58 100644
--- a/src/backend/utils/init/postinit.c
+++ b/src/backend/utils/init/postinit.c
@@ -75,6 +75,7 @@ static void LockTimeoutHandler(void);
static void IdleInTransactionSessionTimeoutHandler(void);
static void IdleSessionTimeoutHandler(void);
static void ClientCheckTimeoutHandler(void);
+static void CheckingRemoteServersTimeoutHandler(void);
static bool ThereIsAtLeastOneRole(void);
static void process_startup_options(Port *port, bool am_superuser);
static void process_settings(Oid databaseid, Oid roleid);
@@ -628,6 +629,7 @@ InitPostgres(const char *in_dbname, Oid dboid, const char *username,
IdleInTransactionSessionTimeoutHandler);
RegisterTimeout(IDLE_SESSION_TIMEOUT, IdleSessionTimeoutHandler);
RegisterTimeout(CLIENT_CONNECTION_CHECK_TIMEOUT, ClientCheckTimeoutHandler);
+ RegisterTimeout(CHECKING_REMOTE_SERVERS_TIMEOUT, CheckingRemoteServersTimeoutHandler);
}
/*
@@ -1246,6 +1248,14 @@ ClientCheckTimeoutHandler(void)
SetLatch(MyLatch);
}
+static void
+CheckingRemoteServersTimeoutHandler(void)
+{
+ CheckingRemoteServersTimeoutPending = true;
+ InterruptPending = true;
+ SetLatch(MyLatch);
+}
+
/*
* Returns true if at least one role is defined in this database cluster.
*/
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index b3fd42e0f1..6dfc171448 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -52,6 +52,7 @@
#include "commands/vacuum.h"
#include "commands/variable.h"
#include "common/string.h"
+#include "foreign/foreign.h"
#include "funcapi.h"
#include "jit/jit.h"
#include "libpq/auth.h"
@@ -106,6 +107,7 @@
#include "utils/queryjumble.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/timeout.h"
#include "utils/tzparser.h"
#include "utils/inval.h"
#include "utils/varlena.h"
@@ -3600,6 +3602,18 @@ static struct config_int ConfigureNamesInt[] =
NULL, NULL, NULL
},
+
+ {
+ {"remote_servers_connection_check_interval", PGC_USERSET, CONN_AUTH_SETTINGS,
+ gettext_noop("Sets the time interval between checks for disconnection of remote servers."),
+ NULL,
+ GUC_UNIT_MS
+ },
+ &remote_servers_connection_check_interval,
+ 0, 0, INT_MAX,
+ NULL, assign_remote_servers_connection_check_interval, NULL
+ },
+
/* End-of-list marker */
{
{NULL, 0, 0, NULL, NULL}, NULL, 0, 0, 0, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 817d5f5324..b97dc30514 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -90,6 +90,10 @@
# disconnection while running queries;
# 0 for never
+#remote_servers_connection_check_interval = 0 # time between time between checks for
+ # foreign server disconnection;
+ # 0 for never
+
# - Authentication -
#authentication_timeout = 1min # 1s-600s
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 75538110fc..922e63922b 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -81,4 +81,26 @@ extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum);
extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok);
extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);
+
+/* functions and variables for fdw checking. */
+typedef ForeignServer* (*CheckingRemoteServersCallback) (void *arg);
+typedef struct CheckingRemoteServersCallbackItem
+{
+ struct CheckingRemoteServersCallbackItem *next;
+ CheckingRemoteServersCallback callback;
+ int counter;
+ void *arg;
+} CheckingRemoteServersCallbackItem;
+
+extern CheckingRemoteServersCallbackItem *
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg);
+extern ForeignServer *CallCheckingRemoteServersCallbacks(void);
+
+extern int TryEnableRemoteServerCheckingTimeout(CheckingRemoteServersCallbackItem *item);
+extern int TryDisableRemoteServerCheckingTimeout(CheckingRemoteServersCallbackItem *item);
+
+extern int remote_servers_connection_check_interval;
+extern void assign_remote_servers_connection_check_interval(int newval,
+ void *extra);
#endif /* FOREIGN_H */
diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h
index 02276d3edd..0319fe1605 100644
--- a/src/include/miscadmin.h
+++ b/src/include/miscadmin.h
@@ -98,10 +98,13 @@ extern PGDLLIMPORT volatile sig_atomic_t LogMemoryContextPending;
extern PGDLLIMPORT volatile sig_atomic_t CheckClientConnectionPending;
extern PGDLLIMPORT volatile sig_atomic_t ClientConnectionLost;
+extern PGDLLIMPORT volatile sig_atomic_t CheckingRemoteServersTimeoutPending;
+
/* these are marked volatile because they are examined by signal handlers: */
extern PGDLLIMPORT volatile uint32 InterruptHoldoffCount;
extern PGDLLIMPORT volatile uint32 QueryCancelHoldoffCount;
extern PGDLLIMPORT volatile uint32 CritSectionCount;
+extern PGDLLIMPORT volatile uint32 CheckingRemoteServersHoldoffCount;
/* in tcop/postgres.c */
extern void ProcessInterrupts(void);
@@ -126,7 +129,7 @@ do { \
/* Is ProcessInterrupts() guaranteed to clear InterruptPending? */
#define INTERRUPTS_CAN_BE_PROCESSED() \
(InterruptHoldoffCount == 0 && CritSectionCount == 0 && \
- QueryCancelHoldoffCount == 0)
+ QueryCancelHoldoffCount == 0 && CheckingRemoteServersHoldoffCount == 0)
#define HOLD_INTERRUPTS() (InterruptHoldoffCount++)
@@ -152,6 +155,13 @@ do { \
CritSectionCount--; \
} while(0)
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS() (CheckingRemoteServersHoldoffCount++)
+
+#define RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS() \
+do { \
+ Assert(CheckingRemoteServersHoldoffCount > 0); \
+ CheckingRemoteServersHoldoffCount--; \
+} while(0)
/*****************************************************************************
* globals.h -- *
diff --git a/src/include/utils/timeout.h b/src/include/utils/timeout.h
index 099f91c61d..7f02a8b491 100644
--- a/src/include/utils/timeout.h
+++ b/src/include/utils/timeout.h
@@ -34,6 +34,7 @@ typedef enum TimeoutId
IDLE_SESSION_TIMEOUT,
CLIENT_CONNECTION_CHECK_TIMEOUT,
STARTUP_PROGRESS_TIMEOUT,
+ CHECKING_REMOTE_SERVERS_TIMEOUT,
/* First user-definable timeout reason */
USER_TIMEOUT,
/* Maximum number of timeout reasons */
v07_0002_add_doc.patchapplication/octet-stream; name=v07_0002_add_doc.patchDownload
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 692d8a2a17..fb400a3a91 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -1035,6 +1035,25 @@ include_dir 'conf.d'
</listitem>
</varlistentry>
+ <varlistentry id="guc-remote-servers-connection-check-interval" xreflabel="remote_servers_connection_check_interval">
+ <term><varname>remote_servers_connection_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>remote_servers_connection_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that the remote servers
+ are still alive. If this parameter is set to a valid value, registered
+ callback functions are executed at the specified time interval.
+ If your FDW extension does not implement a callback function, nothing
+ happens after the specified amount of time. If the value is specified
+ without units, it is taken as milliseconds. The default value is
+ <literal>0</literal>, this means the feature is disabled.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
diff --git a/doc/src/sgml/fdwhandler.sgml b/doc/src/sgml/fdwhandler.sgml
index dbf5dd3d15..3b75a77067 100644
--- a/doc/src/sgml/fdwhandler.sgml
+++ b/doc/src/sgml/fdwhandler.sgml
@@ -2136,4 +2136,40 @@ GetForeignServerByName(const char *name, bool missing_ok);
</sect1>
+ <sect1 id="fdw-checking-remote-servers">
+ <title>Checking the Health of Remote Servers via Foreign Data Wrapper</title>
+
+ <para>
+ For verifying the health of remote servers, callback functions can be
+ registered that runs periodically. The time interval is controlled by
+ <xref linkend="guc-remote-servers-connection-check-interval"/>.
+ The API for registering functions is:
+ <programlisting>
+CheckingRemoteServersCallbackItem *
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg);
+ </programlisting>
+ Only functions that return <type>ForeignServer*</type> can be
+ registered as callback functions. Please set to <literal>void* arg</literal>
+ if you want to pass an argument. The returning value must be set as the argument
+ of following enable and disable fucntions.
+ If you have problems with the health check results and want to abort the transaction,
+ please return the pointer of downed server as <type>ForeignServer*</type>.
+ </para>
+ <para>
+ Note that starting or stopping the periodic execution is FDW's responsibility.
+ If you want to start verification, the following function must be performed
+ after registering callback functions:
+ <programlisting>
+int
+TryEnableRemoteServerCheckingTimeout(CheckingRemoteServersCallbackItem *item)
+ </programlisting>
+ If you want to stop, the following function must be performed:
+ <programlisting>
+int
+TryDisableRemoteServerCheckingTimeout(CheckingRemoteServersCallbackItem *item)
+ </programlisting>
+ </para>
+ </sect1>
+
+
</chapter>
On 2022/02/01 13:37, kuroda.hayato@fujitsu.com wrote:
Dear Fujii-san,
Thank you for reviewing! I attached the latest version.
Thanks!
Indeed and it should be avoided. I added a counter to CheckingRemoteServersCallbackItem.
The register function returns the registered item, and it must be set as the argument for
enable and disable functions.
Callback functions will be called when item->counter is larger than zero.
This logic sounds complicated to me. I'm afraid that FDW developers may a bit easily misunderstand the logic and make the bug in their FDW.
Isn't it simpler to just disable the timeout in core whenever the transaction ends whether committed or aborted, like statement_timeout is disabled after each command? For example, call something like DisableForeignCheckTimeout() in CommitTransaction() etc.
You are right. I think this suggests that error-reporting should be done in the core layer.
For meaningful error reporting, I changed a callback specification
that it should return ForeignServer* which points to downed remote server.
This approach seems to assume that FDW must manage all the ForeignServer information so that the callback can return it. Is this assumption valid for all the FDW?
How about making FDW trigger a query cancel interrupt by signaling SIGINT to the backend, instead?
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Fujii-san,
Thank you for good suggestions.
This logic sounds complicated to me. I'm afraid that FDW developers may a bit
easily misunderstand the logic and make the bug in their FDW.
Isn't it simpler to just disable the timeout in core whenever the transaction ends
whether committed or aborted, like statement_timeout is disabled after each
command? For example, call something like DisableForeignCheckTimeout() in
CommitTransaction() etc.
Your idea is that stop the timer at the end of each transactions, right?
I had not adopted that because I thought some developers might want not to stop the timer
even if transactions ends. It caused complexed situation and not have good usecase, however,
so your logic was implemented.
You are right. I think this suggests that error-reporting should be done in the
core layer.
For meaningful error reporting, I changed a callback specification
that it should return ForeignServer* which points to downed remote server.This approach seems to assume that FDW must manage all the ForeignServer
information so that the callback can return it. Is this assumption valid for all the
FDW?
Not sure, the assumption might be too optimistic.
mysql_fdw can easily return ForeignServer* because it caches serverid,
but dblink and maybe oracle_fdw cannot.
How about making FDW trigger a query cancel interrupt by signaling SIGINT to
the backend, instead?
I understood that the error should be caught by QueryCancelPending.
Could you check 0003? Does it follow that?
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v08_0001_add_checking_infrastracture.patchapplication/octet-stream; name=v08_0001_add_checking_infrastracture.patchDownload
diff --git a/src/backend/access/transam/xact.c b/src/backend/access/transam/xact.c
index c9516e03fa..1e321e18c4 100644
--- a/src/backend/access/transam/xact.c
+++ b/src/backend/access/transam/xact.c
@@ -39,6 +39,7 @@
#include "commands/trigger.h"
#include "common/pg_prng.h"
#include "executor/spi.h"
+#include "foreign/foreign.h"
#include "libpq/be-fsstubs.h"
#include "libpq/pqsignal.h"
#include "miscadmin.h"
@@ -2365,6 +2366,9 @@ CommitTransaction(void)
XactTopFullTransactionId = InvalidFullTransactionId;
nParallelCurrentXids = 0;
+ /* stop checking remote servers */
+ DisableForeignCheckTimeout();
+
/*
* done with commit processing, set current transaction state back to
* default
@@ -2652,6 +2656,9 @@ PrepareTransaction(void)
XactTopFullTransactionId = InvalidFullTransactionId;
nParallelCurrentXids = 0;
+ /* stop checking remote servers */
+ DisableForeignCheckTimeout();
+
/*
* done with 1st phase commit processing, set current transaction state
* back to default
diff --git a/src/backend/commands/copyfromparse.c b/src/backend/commands/copyfromparse.c
index baf328b620..996386fdd4 100644
--- a/src/backend/commands/copyfromparse.c
+++ b/src/backend/commands/copyfromparse.c
@@ -269,6 +269,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
readmessage:
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
mtype = pq_getbyte();
if (mtype == EOF)
@@ -300,6 +301,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
ereport(ERROR,
(errcode(ERRCODE_CONNECTION_FAILURE),
errmsg("unexpected EOF on client connection with an open transaction")));
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
/* ... and process it */
switch (mtype)
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index 294e22c78c..6084a77336 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -26,7 +26,11 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
+/* for checking remote servers */
+int remote_servers_connection_check_interval = 0;
+static CheckingRemoteServersCallbackItem *fdw_callbacks = NULL;
/*
* GetForeignDataWrapper - look up the foreign-data wrapper by OID.
@@ -836,3 +840,83 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
}
return NULL;
}
+
+/*
+ * Register callbacks for checking remote servers.
+ *
+ * This function is intended for use by FDW extensions.
+ * The checking timeout will be fired after registering the first callback.
+ */
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+
+ item = (CheckingRemoteServersCallbackItem *)
+ MemoryContextAlloc(TopMemoryContext,
+ sizeof(CheckingRemoteServersCallbackItem));
+ item->callback = callback;
+ item->arg = arg;
+ item->next = fdw_callbacks;
+ fdw_callbacks = item;
+}
+
+/*
+ * Call callbacks for checking remote servers.
+ */
+void
+CallCheckingRemoteServersCallbacks(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+
+ for (item = fdw_callbacks; item; item = item->next)
+ item->callback(item->arg);
+}
+
+/*
+ * enable timeout if it has been not started yet.
+ */
+void
+EnableForeignCheckTimeout(void)
+{
+ if (remote_servers_connection_check_interval > 0 &&
+ !get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+}
+
+/*
+ * disable timeout if enabled.
+ */
+void
+DisableForeignCheckTimeout(void)
+{
+ if (get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ disable_timeout(CHECKING_REMOTE_SERVERS_TIMEOUT, false);
+}
+
+void
+assign_remote_servers_connection_check_interval(int newval,
+ void *extra)
+{
+ /* Quick return if we don't have any callbacks */
+ if (fdw_callbacks == NULL)
+ return;
+
+ if (get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ {
+ if (newval == 0)
+ disable_timeout(CHECKING_REMOTE_SERVERS_TIMEOUT, false);
+
+ /*
+ * we don't have to do anything because
+ * new value will be used in ProcessInterrupts().
+ */
+ return;
+ }
+
+ /* Start timeout if anyone wants to */
+ if (newval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT, newval);
+}
\ No newline at end of file
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index fda2e9360e..d5de5557e7 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -44,6 +44,7 @@
#include "commands/prepare.h"
#include "common/pg_prng.h"
#include "executor/spi.h"
+#include "foreign/foreign.h"
#include "jit/jit.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@@ -350,6 +351,7 @@ SocketBackend(StringInfo inBuf)
* Get message type code from the frontend.
*/
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
qtype = pq_getbyte();
@@ -456,6 +458,7 @@ SocketBackend(StringInfo inBuf)
*/
if (pq_getmessage(inBuf, maxmsglen))
return EOF; /* suitable message already logged */
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
return qtype;
@@ -3225,6 +3228,29 @@ ProcessInterrupts(void)
errmsg("connection to client lost")));
}
+ if (CheckingRemoteServersTimeoutPending)
+ {
+ if (CheckingRemoteServersHoldoffCount != 0 || DoingCommandRead)
+ {
+ /*
+ * Skip checking foreign servers while reading messages or commands.
+ */
+ InterruptPending = true;
+ }
+ else
+ {
+ CheckingRemoteServersTimeoutPending = false;
+
+ /* Check remote servers and re-arm, if still configured. */
+ if (remote_servers_connection_check_interval > 0)
+ {
+ CallCheckingRemoteServersCallbacks();
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+ }
+ }
+ }
+
/*
* If a recovery conflict happens while we are waiting for input from the
* client, the client is presumably just sitting idle in a transaction,
diff --git a/src/backend/utils/init/globals.c b/src/backend/utils/init/globals.c
index c26a1a73df..7efa9cff84 100644
--- a/src/backend/utils/init/globals.c
+++ b/src/backend/utils/init/globals.c
@@ -36,9 +36,11 @@ volatile sig_atomic_t IdleInTransactionSessionTimeoutPending = false;
volatile sig_atomic_t IdleSessionTimeoutPending = false;
volatile sig_atomic_t ProcSignalBarrierPending = false;
volatile sig_atomic_t LogMemoryContextPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
volatile uint32 InterruptHoldoffCount = 0;
volatile uint32 QueryCancelHoldoffCount = 0;
volatile uint32 CritSectionCount = 0;
+volatile uint32 CheckingRemoteServersHoldoffCount = 0;
int MyProcPid;
pg_time_t MyStartTime;
diff --git a/src/backend/utils/init/postinit.c b/src/backend/utils/init/postinit.c
index 5b9ed2f6f5..9b0b4ddd58 100644
--- a/src/backend/utils/init/postinit.c
+++ b/src/backend/utils/init/postinit.c
@@ -75,6 +75,7 @@ static void LockTimeoutHandler(void);
static void IdleInTransactionSessionTimeoutHandler(void);
static void IdleSessionTimeoutHandler(void);
static void ClientCheckTimeoutHandler(void);
+static void CheckingRemoteServersTimeoutHandler(void);
static bool ThereIsAtLeastOneRole(void);
static void process_startup_options(Port *port, bool am_superuser);
static void process_settings(Oid databaseid, Oid roleid);
@@ -628,6 +629,7 @@ InitPostgres(const char *in_dbname, Oid dboid, const char *username,
IdleInTransactionSessionTimeoutHandler);
RegisterTimeout(IDLE_SESSION_TIMEOUT, IdleSessionTimeoutHandler);
RegisterTimeout(CLIENT_CONNECTION_CHECK_TIMEOUT, ClientCheckTimeoutHandler);
+ RegisterTimeout(CHECKING_REMOTE_SERVERS_TIMEOUT, CheckingRemoteServersTimeoutHandler);
}
/*
@@ -1246,6 +1248,14 @@ ClientCheckTimeoutHandler(void)
SetLatch(MyLatch);
}
+static void
+CheckingRemoteServersTimeoutHandler(void)
+{
+ CheckingRemoteServersTimeoutPending = true;
+ InterruptPending = true;
+ SetLatch(MyLatch);
+}
+
/*
* Returns true if at least one role is defined in this database cluster.
*/
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index b3fd42e0f1..6dfc171448 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -52,6 +52,7 @@
#include "commands/vacuum.h"
#include "commands/variable.h"
#include "common/string.h"
+#include "foreign/foreign.h"
#include "funcapi.h"
#include "jit/jit.h"
#include "libpq/auth.h"
@@ -106,6 +107,7 @@
#include "utils/queryjumble.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/timeout.h"
#include "utils/tzparser.h"
#include "utils/inval.h"
#include "utils/varlena.h"
@@ -3600,6 +3602,18 @@ static struct config_int ConfigureNamesInt[] =
NULL, NULL, NULL
},
+
+ {
+ {"remote_servers_connection_check_interval", PGC_USERSET, CONN_AUTH_SETTINGS,
+ gettext_noop("Sets the time interval between checks for disconnection of remote servers."),
+ NULL,
+ GUC_UNIT_MS
+ },
+ &remote_servers_connection_check_interval,
+ 0, 0, INT_MAX,
+ NULL, assign_remote_servers_connection_check_interval, NULL
+ },
+
/* End-of-list marker */
{
{NULL, 0, 0, NULL, NULL}, NULL, 0, 0, 0, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 817d5f5324..b97dc30514 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -90,6 +90,10 @@
# disconnection while running queries;
# 0 for never
+#remote_servers_connection_check_interval = 0 # time between time between checks for
+ # foreign server disconnection;
+ # 0 for never
+
# - Authentication -
#authentication_timeout = 1min # 1s-600s
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 75538110fc..900cc4e3aa 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -81,4 +81,24 @@ extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum);
extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok);
extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);
+
+/* functions and variables for fdw checking. */
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+typedef struct CheckingRemoteServersCallbackItem
+{
+ struct CheckingRemoteServersCallbackItem *next;
+ CheckingRemoteServersCallback callback;
+ void *arg;
+} CheckingRemoteServersCallbackItem;
+
+extern void RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg);
+extern void CallCheckingRemoteServersCallbacks(void);
+
+extern void EnableForeignCheckTimeout(void);
+extern void DisableForeignCheckTimeout(void);
+
+extern int remote_servers_connection_check_interval;
+extern void assign_remote_servers_connection_check_interval(int newval,
+ void *extra);
#endif /* FOREIGN_H */
diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h
index 02276d3edd..0319fe1605 100644
--- a/src/include/miscadmin.h
+++ b/src/include/miscadmin.h
@@ -98,10 +98,13 @@ extern PGDLLIMPORT volatile sig_atomic_t LogMemoryContextPending;
extern PGDLLIMPORT volatile sig_atomic_t CheckClientConnectionPending;
extern PGDLLIMPORT volatile sig_atomic_t ClientConnectionLost;
+extern PGDLLIMPORT volatile sig_atomic_t CheckingRemoteServersTimeoutPending;
+
/* these are marked volatile because they are examined by signal handlers: */
extern PGDLLIMPORT volatile uint32 InterruptHoldoffCount;
extern PGDLLIMPORT volatile uint32 QueryCancelHoldoffCount;
extern PGDLLIMPORT volatile uint32 CritSectionCount;
+extern PGDLLIMPORT volatile uint32 CheckingRemoteServersHoldoffCount;
/* in tcop/postgres.c */
extern void ProcessInterrupts(void);
@@ -126,7 +129,7 @@ do { \
/* Is ProcessInterrupts() guaranteed to clear InterruptPending? */
#define INTERRUPTS_CAN_BE_PROCESSED() \
(InterruptHoldoffCount == 0 && CritSectionCount == 0 && \
- QueryCancelHoldoffCount == 0)
+ QueryCancelHoldoffCount == 0 && CheckingRemoteServersHoldoffCount == 0)
#define HOLD_INTERRUPTS() (InterruptHoldoffCount++)
@@ -152,6 +155,13 @@ do { \
CritSectionCount--; \
} while(0)
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS() (CheckingRemoteServersHoldoffCount++)
+
+#define RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS() \
+do { \
+ Assert(CheckingRemoteServersHoldoffCount > 0); \
+ CheckingRemoteServersHoldoffCount--; \
+} while(0)
/*****************************************************************************
* globals.h -- *
diff --git a/src/include/utils/timeout.h b/src/include/utils/timeout.h
index 099f91c61d..7f02a8b491 100644
--- a/src/include/utils/timeout.h
+++ b/src/include/utils/timeout.h
@@ -34,6 +34,7 @@ typedef enum TimeoutId
IDLE_SESSION_TIMEOUT,
CLIENT_CONNECTION_CHECK_TIMEOUT,
STARTUP_PROGRESS_TIMEOUT,
+ CHECKING_REMOTE_SERVERS_TIMEOUT,
/* First user-definable timeout reason */
USER_TIMEOUT,
/* Maximum number of timeout reasons */
v08_0002_add_doc.patchapplication/octet-stream; name=v08_0002_add_doc.patchDownload
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 692d8a2a17..fb400a3a91 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -1035,6 +1035,25 @@ include_dir 'conf.d'
</listitem>
</varlistentry>
+ <varlistentry id="guc-remote-servers-connection-check-interval" xreflabel="remote_servers_connection_check_interval">
+ <term><varname>remote_servers_connection_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>remote_servers_connection_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that the remote servers
+ are still alive. If this parameter is set to a valid value, registered
+ callback functions are executed at the specified time interval.
+ If your FDW extension does not implement a callback function, nothing
+ happens after the specified amount of time. If the value is specified
+ without units, it is taken as milliseconds. The default value is
+ <literal>0</literal>, this means the feature is disabled.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
diff --git a/doc/src/sgml/fdwhandler.sgml b/doc/src/sgml/fdwhandler.sgml
index dbf5dd3d15..8e245f87dc 100644
--- a/doc/src/sgml/fdwhandler.sgml
+++ b/doc/src/sgml/fdwhandler.sgml
@@ -2136,4 +2136,34 @@ GetForeignServerByName(const char *name, bool missing_ok);
</sect1>
+ <sect1 id="fdw-checking-remote-servers">
+ <title>Checking the Health of Remote Servers via Foreign Data Wrapper</title>
+
+ <para>
+ For verifying the health of remote servers, callback functions can be
+ registered that runs periodically. The time interval is controlled by
+ <xref linkend="guc-remote-servers-connection-check-interval"/>.
+ The API for registering functions is:
+ <programlisting>
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg);
+ </programlisting>
+ Only functions that return nothing can be registered as callback functions.
+ Please set to <literal>void* arg</literal> if you want to pass an argument.
+ If problems are found by the health check and want to abort the transaction,
+ please send a signal <systemitem>SIGINT</systemitem> to the backend process.
+ </para>
+ <para>
+ Note that starting the periodic run is FDW's responsibility.
+ If you want to start verification, the following function must be performed
+ after registering callback functions:
+ <programlisting>
+int
+EnableForeignCheckTimeout(void)
+ </programlisting>
+ The periodic run will stop at end of each transaction.
+ </para>
+ </sect1>
+
+
</chapter>
Dear Hackers,
I found patches we depend have been committed, so rebased.
https://git.postgresql.org/gitweb/?p=postgresql.git;a=commit;h=50e570a59e7f86bb41f029a66b781fc79b8d50f1
In this version there is a little bit change in part of postgres_fdw.
A system checking by WaitEventSetCanReportClosed() is added
because some OSes cannot wait WL_SOCKET_CLOSED event.
Note that test cannot be added in the regression test
because cfbot may be not happy.
In my environment a test that contained in previous patches works well.
0001, 0002 is not changed from previous version.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v09_0003_helth_check_for_postgres_fdw.patchapplication/octet-stream; name=v09_0003_helth_check_for_postgres_fdw.patchDownload
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 29fcb6a76e..10316d2f10 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -109,6 +109,7 @@ static void pgfdw_abort_cleanup(ConnCacheEntry *entry, const char *sql,
bool toplevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool pgfdw_connection_check_internal(PGconn *conn);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -153,11 +154,17 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
pgfdw_inval_callback, (Datum) 0);
CacheRegisterSyscacheCallback(USERMAPPINGOID,
pgfdw_inval_callback, (Datum) 0);
+
+ /* Register a callback fore checking remote servers */
+ RegisterCheckingRemoteServersCallback(pgfdw_connection_check, NULL);
}
/* Set flag that we did GetConnection during the current transaction */
xact_got_connection = true;
+ /* Start checking timer */
+ EnableForeignCheckTimeout();
+
/* Create hash key for the entry. Assume no pad bytes in key struct */
key = user->umid;
@@ -1709,3 +1716,71 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Callback function for checking remote servers.
+ *
+ * This function searches the hash table from the beginning
+ * and performs a health-check on each entry.
+ *
+ * Raise SIGINT if someone might be down, otherwise do nothing.
+ */
+void
+pgfdw_connection_check(void *args)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+
+ /* Exit immediately if hash is not initialized. */
+ if (!ConnectionHash)
+ return;
+
+ /*
+ * checking will be done by waiting WL_SOCKET_CLOSED event,
+ * so exit immediately if it cannot be used in this system.
+ */
+ if (!WaitEventSetCanReportClosed())
+ return;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ if (entry->conn == NULL || entry->xact_depth == 0)
+ continue;
+ if (!pgfdw_connection_check_internal(entry->conn))
+ {
+ ForeignServer *server = GetForeignServer(entry->serverid);
+ elog(LOG, "Foreign Server %s might be down.", server->servername);
+ disconnect_pg_server(entry);
+ raise(SIGINT);
+ }
+ }
+
+ return;
+}
+
+/*
+ * helper function for pgfdw_connection_check
+ */
+static bool
+pgfdw_connection_check_internal(PGconn *conn)
+{
+ WaitEventSet *eventset;
+ WaitEvent events;
+
+ Assert(WaitEventSetCanReportClosed());
+
+ eventset = CreateWaitEventSet(CurrentMemoryContext, 1);
+ AddWaitEventToSet(eventset, WL_SOCKET_CLOSED, PQsocket(conn), NULL, NULL);
+
+ WaitEventSetWait(eventset, 0, &events, 1, 0);
+
+ if (events.events & WL_SOCKET_CLOSED)
+ {
+ FreeWaitEventSet(eventset);
+ return false;
+ }
+ FreeWaitEventSet(eventset);
+
+ return true;
+}
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 8ae79e97e4..0f4f4641c6 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -151,6 +151,7 @@ extern PGresult *pgfdw_exec_query(PGconn *conn, const char *query,
PgFdwConnState *state);
extern void pgfdw_report_error(int elevel, PGresult *res, PGconn *conn,
bool clear, const char *sql);
+extern void pgfdw_connection_check(void *args);
/* in option.c */
extern int ExtractConnectionOptions(List *defelems,
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 2bb31f1125..228f4629a5 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -774,6 +774,16 @@ postgres=# SELECT postgres_fdw_disconnect_all();
connections that are no longer necessary, thereby releasing
connections on the foreign server.
</para>
+
+ <para>
+ During a remote transaction, postgres_fdw checks the health of used connections
+ if <xref linkend="guc-remote-servers-connection-check-interval"/> sets to
+ greater than zero. When losing a remote connection is detected,
+ the running transaction is aborted. Note that this feature is performed
+ by polling the socket, and available platforms are the
+ same as <xref linkend="guc-client-connection-check-interval"/>.
+ </para>
+
</sect2>
<sect2>
v09_0002_add_doc_about_infrastructure.patchapplication/octet-stream; name=v09_0002_add_doc_about_infrastructure.patchDownload
diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml
index 53b361e7a9..6e4f67aed9 100644
--- a/doc/src/sgml/config.sgml
+++ b/doc/src/sgml/config.sgml
@@ -1035,6 +1035,25 @@ include_dir 'conf.d'
</listitem>
</varlistentry>
+ <varlistentry id="guc-remote-servers-connection-check-interval" xreflabel="remote_servers_connection_check_interval">
+ <term><varname>remote_servers_connection_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>remote_servers_connection_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that the remote servers
+ are still alive. If this parameter is set to a valid value, registered
+ callback functions are executed at the specified time interval.
+ If your FDW extension does not implement a callback function, nothing
+ happens after the specified amount of time. If the value is specified
+ without units, it is taken as milliseconds. The default value is
+ <literal>0</literal>, this means the feature is disabled.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
diff --git a/doc/src/sgml/fdwhandler.sgml b/doc/src/sgml/fdwhandler.sgml
index dbf5dd3d15..8e245f87dc 100644
--- a/doc/src/sgml/fdwhandler.sgml
+++ b/doc/src/sgml/fdwhandler.sgml
@@ -2136,4 +2136,34 @@ GetForeignServerByName(const char *name, bool missing_ok);
</sect1>
+ <sect1 id="fdw-checking-remote-servers">
+ <title>Checking the Health of Remote Servers via Foreign Data Wrapper</title>
+
+ <para>
+ For verifying the health of remote servers, callback functions can be
+ registered that runs periodically. The time interval is controlled by
+ <xref linkend="guc-remote-servers-connection-check-interval"/>.
+ The API for registering functions is:
+ <programlisting>
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, void *arg);
+ </programlisting>
+ Only functions that return nothing can be registered as callback functions.
+ Please set to <literal>void* arg</literal> if you want to pass an argument.
+ If problems are found by the health check and want to abort the transaction,
+ please send a signal <systemitem>SIGINT</systemitem> to the backend process.
+ </para>
+ <para>
+ Note that starting the periodic run is FDW's responsibility.
+ If you want to start verification, the following function must be performed
+ after registering callback functions:
+ <programlisting>
+int
+EnableForeignCheckTimeout(void)
+ </programlisting>
+ The periodic run will stop at end of each transaction.
+ </para>
+ </sect1>
+
+
</chapter>
v09_0001_add_checking_infrastracture.patchapplication/octet-stream; name=v09_0001_add_checking_infrastracture.patchDownload
diff --git a/src/backend/access/transam/xact.c b/src/backend/access/transam/xact.c
index c9516e03fa..1e321e18c4 100644
--- a/src/backend/access/transam/xact.c
+++ b/src/backend/access/transam/xact.c
@@ -39,6 +39,7 @@
#include "commands/trigger.h"
#include "common/pg_prng.h"
#include "executor/spi.h"
+#include "foreign/foreign.h"
#include "libpq/be-fsstubs.h"
#include "libpq/pqsignal.h"
#include "miscadmin.h"
@@ -2365,6 +2366,9 @@ CommitTransaction(void)
XactTopFullTransactionId = InvalidFullTransactionId;
nParallelCurrentXids = 0;
+ /* stop checking remote servers */
+ DisableForeignCheckTimeout();
+
/*
* done with commit processing, set current transaction state back to
* default
@@ -2652,6 +2656,9 @@ PrepareTransaction(void)
XactTopFullTransactionId = InvalidFullTransactionId;
nParallelCurrentXids = 0;
+ /* stop checking remote servers */
+ DisableForeignCheckTimeout();
+
/*
* done with 1st phase commit processing, set current transaction state
* back to default
diff --git a/src/backend/commands/copyfromparse.c b/src/backend/commands/copyfromparse.c
index baf328b620..996386fdd4 100644
--- a/src/backend/commands/copyfromparse.c
+++ b/src/backend/commands/copyfromparse.c
@@ -269,6 +269,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
readmessage:
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
mtype = pq_getbyte();
if (mtype == EOF)
@@ -300,6 +301,7 @@ CopyGetData(CopyFromState cstate, void *databuf, int minread, int maxread)
ereport(ERROR,
(errcode(ERRCODE_CONNECTION_FAILURE),
errmsg("unexpected EOF on client connection with an open transaction")));
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
/* ... and process it */
switch (mtype)
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index 294e22c78c..6084a77336 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -26,7 +26,11 @@
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
+/* for checking remote servers */
+int remote_servers_connection_check_interval = 0;
+static CheckingRemoteServersCallbackItem *fdw_callbacks = NULL;
/*
* GetForeignDataWrapper - look up the foreign-data wrapper by OID.
@@ -836,3 +840,83 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
}
return NULL;
}
+
+/*
+ * Register callbacks for checking remote servers.
+ *
+ * This function is intended for use by FDW extensions.
+ * The checking timeout will be fired after registering the first callback.
+ */
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+
+ item = (CheckingRemoteServersCallbackItem *)
+ MemoryContextAlloc(TopMemoryContext,
+ sizeof(CheckingRemoteServersCallbackItem));
+ item->callback = callback;
+ item->arg = arg;
+ item->next = fdw_callbacks;
+ fdw_callbacks = item;
+}
+
+/*
+ * Call callbacks for checking remote servers.
+ */
+void
+CallCheckingRemoteServersCallbacks(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+
+ for (item = fdw_callbacks; item; item = item->next)
+ item->callback(item->arg);
+}
+
+/*
+ * enable timeout if it has been not started yet.
+ */
+void
+EnableForeignCheckTimeout(void)
+{
+ if (remote_servers_connection_check_interval > 0 &&
+ !get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+}
+
+/*
+ * disable timeout if enabled.
+ */
+void
+DisableForeignCheckTimeout(void)
+{
+ if (get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ disable_timeout(CHECKING_REMOTE_SERVERS_TIMEOUT, false);
+}
+
+void
+assign_remote_servers_connection_check_interval(int newval,
+ void *extra)
+{
+ /* Quick return if we don't have any callbacks */
+ if (fdw_callbacks == NULL)
+ return;
+
+ if (get_timeout_active(CHECKING_REMOTE_SERVERS_TIMEOUT))
+ {
+ if (newval == 0)
+ disable_timeout(CHECKING_REMOTE_SERVERS_TIMEOUT, false);
+
+ /*
+ * we don't have to do anything because
+ * new value will be used in ProcessInterrupts().
+ */
+ return;
+ }
+
+ /* Start timeout if anyone wants to */
+ if (newval > 0)
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT, newval);
+}
\ No newline at end of file
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index fda2e9360e..d5de5557e7 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -44,6 +44,7 @@
#include "commands/prepare.h"
#include "common/pg_prng.h"
#include "executor/spi.h"
+#include "foreign/foreign.h"
#include "jit/jit.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@@ -350,6 +351,7 @@ SocketBackend(StringInfo inBuf)
* Get message type code from the frontend.
*/
HOLD_CANCEL_INTERRUPTS();
+ HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS();
pq_startmsgread();
qtype = pq_getbyte();
@@ -456,6 +458,7 @@ SocketBackend(StringInfo inBuf)
*/
if (pq_getmessage(inBuf, maxmsglen))
return EOF; /* suitable message already logged */
+ RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS();
RESUME_CANCEL_INTERRUPTS();
return qtype;
@@ -3225,6 +3228,29 @@ ProcessInterrupts(void)
errmsg("connection to client lost")));
}
+ if (CheckingRemoteServersTimeoutPending)
+ {
+ if (CheckingRemoteServersHoldoffCount != 0 || DoingCommandRead)
+ {
+ /*
+ * Skip checking foreign servers while reading messages or commands.
+ */
+ InterruptPending = true;
+ }
+ else
+ {
+ CheckingRemoteServersTimeoutPending = false;
+
+ /* Check remote servers and re-arm, if still configured. */
+ if (remote_servers_connection_check_interval > 0)
+ {
+ CallCheckingRemoteServersCallbacks();
+ enable_timeout_after(CHECKING_REMOTE_SERVERS_TIMEOUT,
+ remote_servers_connection_check_interval);
+ }
+ }
+ }
+
/*
* If a recovery conflict happens while we are waiting for input from the
* client, the client is presumably just sitting idle in a transaction,
diff --git a/src/backend/utils/init/globals.c b/src/backend/utils/init/globals.c
index c26a1a73df..7efa9cff84 100644
--- a/src/backend/utils/init/globals.c
+++ b/src/backend/utils/init/globals.c
@@ -36,9 +36,11 @@ volatile sig_atomic_t IdleInTransactionSessionTimeoutPending = false;
volatile sig_atomic_t IdleSessionTimeoutPending = false;
volatile sig_atomic_t ProcSignalBarrierPending = false;
volatile sig_atomic_t LogMemoryContextPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
volatile uint32 InterruptHoldoffCount = 0;
volatile uint32 QueryCancelHoldoffCount = 0;
volatile uint32 CritSectionCount = 0;
+volatile uint32 CheckingRemoteServersHoldoffCount = 0;
int MyProcPid;
pg_time_t MyStartTime;
diff --git a/src/backend/utils/init/postinit.c b/src/backend/utils/init/postinit.c
index 02207a5b6f..9ce99df962 100644
--- a/src/backend/utils/init/postinit.c
+++ b/src/backend/utils/init/postinit.c
@@ -80,6 +80,7 @@ static void LockTimeoutHandler(void);
static void IdleInTransactionSessionTimeoutHandler(void);
static void IdleSessionTimeoutHandler(void);
static void ClientCheckTimeoutHandler(void);
+static void CheckingRemoteServersTimeoutHandler(void);
static bool ThereIsAtLeastOneRole(void);
static void process_startup_options(Port *port, bool am_superuser);
static void process_settings(Oid databaseid, Oid roleid);
@@ -700,6 +701,7 @@ InitPostgres(const char *in_dbname, Oid dboid, const char *username,
IdleInTransactionSessionTimeoutHandler);
RegisterTimeout(IDLE_SESSION_TIMEOUT, IdleSessionTimeoutHandler);
RegisterTimeout(CLIENT_CONNECTION_CHECK_TIMEOUT, ClientCheckTimeoutHandler);
+ RegisterTimeout(CHECKING_REMOTE_SERVERS_TIMEOUT, CheckingRemoteServersTimeoutHandler);
}
/*
@@ -1318,6 +1320,14 @@ ClientCheckTimeoutHandler(void)
SetLatch(MyLatch);
}
+static void
+CheckingRemoteServersTimeoutHandler(void)
+{
+ CheckingRemoteServersTimeoutPending = true;
+ InterruptPending = true;
+ SetLatch(MyLatch);
+}
+
/*
* Returns true if at least one role is defined in this database cluster.
*/
diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c
index e2fe219aa8..d558117e64 100644
--- a/src/backend/utils/misc/guc.c
+++ b/src/backend/utils/misc/guc.c
@@ -52,6 +52,7 @@
#include "commands/vacuum.h"
#include "commands/variable.h"
#include "common/string.h"
+#include "foreign/foreign.h"
#include "funcapi.h"
#include "jit/jit.h"
#include "libpq/auth.h"
@@ -106,6 +107,7 @@
#include "utils/queryjumble.h"
#include "utils/rls.h"
#include "utils/snapmgr.h"
+#include "utils/timeout.h"
#include "utils/tzparser.h"
#include "utils/inval.h"
#include "utils/varlena.h"
@@ -3600,6 +3602,18 @@ static struct config_int ConfigureNamesInt[] =
NULL, NULL, NULL
},
+
+ {
+ {"remote_servers_connection_check_interval", PGC_USERSET, CONN_AUTH_SETTINGS,
+ gettext_noop("Sets the time interval between checks for disconnection of remote servers."),
+ NULL,
+ GUC_UNIT_MS
+ },
+ &remote_servers_connection_check_interval,
+ 0, 0, INT_MAX,
+ NULL, assign_remote_servers_connection_check_interval, NULL
+ },
+
/* End-of-list marker */
{
{NULL, 0, 0, NULL, NULL}, NULL, 0, 0, 0, NULL, NULL, NULL
diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample
index 56d0bee6d9..04fa73967b 100644
--- a/src/backend/utils/misc/postgresql.conf.sample
+++ b/src/backend/utils/misc/postgresql.conf.sample
@@ -90,6 +90,10 @@
# disconnection while running queries;
# 0 for never
+#remote_servers_connection_check_interval = 0 # time between time between checks for
+ # foreign server disconnection;
+ # 0 for never
+
# - Authentication -
#authentication_timeout = 1min # 1s-600s
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 75538110fc..900cc4e3aa 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -81,4 +81,24 @@ extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum);
extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok);
extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);
+
+/* functions and variables for fdw checking. */
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+typedef struct CheckingRemoteServersCallbackItem
+{
+ struct CheckingRemoteServersCallbackItem *next;
+ CheckingRemoteServersCallback callback;
+ void *arg;
+} CheckingRemoteServersCallbackItem;
+
+extern void RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg);
+extern void CallCheckingRemoteServersCallbacks(void);
+
+extern void EnableForeignCheckTimeout(void);
+extern void DisableForeignCheckTimeout(void);
+
+extern int remote_servers_connection_check_interval;
+extern void assign_remote_servers_connection_check_interval(int newval,
+ void *extra);
#endif /* FOREIGN_H */
diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h
index 0abc3ad540..b14152e66b 100644
--- a/src/include/miscadmin.h
+++ b/src/include/miscadmin.h
@@ -98,10 +98,13 @@ extern PGDLLIMPORT volatile sig_atomic_t LogMemoryContextPending;
extern PGDLLIMPORT volatile sig_atomic_t CheckClientConnectionPending;
extern PGDLLIMPORT volatile sig_atomic_t ClientConnectionLost;
+extern PGDLLIMPORT volatile sig_atomic_t CheckingRemoteServersTimeoutPending;
+
/* these are marked volatile because they are examined by signal handlers: */
extern PGDLLIMPORT volatile uint32 InterruptHoldoffCount;
extern PGDLLIMPORT volatile uint32 QueryCancelHoldoffCount;
extern PGDLLIMPORT volatile uint32 CritSectionCount;
+extern PGDLLIMPORT volatile uint32 CheckingRemoteServersHoldoffCount;
/* in tcop/postgres.c */
extern void ProcessInterrupts(void);
@@ -126,7 +129,7 @@ do { \
/* Is ProcessInterrupts() guaranteed to clear InterruptPending? */
#define INTERRUPTS_CAN_BE_PROCESSED() \
(InterruptHoldoffCount == 0 && CritSectionCount == 0 && \
- QueryCancelHoldoffCount == 0)
+ QueryCancelHoldoffCount == 0 && CheckingRemoteServersHoldoffCount == 0)
#define HOLD_INTERRUPTS() (InterruptHoldoffCount++)
@@ -152,6 +155,13 @@ do { \
CritSectionCount--; \
} while(0)
+#define HOLD_CHECKING_REMOTE_SERVERS_INTERRUPTS() (CheckingRemoteServersHoldoffCount++)
+
+#define RESUME_CHECKING_REMOTE_SERVERS_INTERRUPTS() \
+do { \
+ Assert(CheckingRemoteServersHoldoffCount > 0); \
+ CheckingRemoteServersHoldoffCount--; \
+} while(0)
/*****************************************************************************
* globals.h -- *
diff --git a/src/include/utils/timeout.h b/src/include/utils/timeout.h
index 099f91c61d..7f02a8b491 100644
--- a/src/include/utils/timeout.h
+++ b/src/include/utils/timeout.h
@@ -34,6 +34,7 @@ typedef enum TimeoutId
IDLE_SESSION_TIMEOUT,
CLIENT_CONNECTION_CHECK_TIMEOUT,
STARTUP_PROGRESS_TIMEOUT,
+ CHECKING_REMOTE_SERVERS_TIMEOUT,
/* First user-definable timeout reason */
USER_TIMEOUT,
/* Maximum number of timeout reasons */
At Tue, 1 Feb 2022 23:51:54 +0900, Fujii Masao <masao.fujii@oss.nttdata.com> wrote in
This logic sounds complicated to me. I'm afraid that FDW developers
may a bit easily misunderstand the logic and make the bug in their
FDW.
Isn't it simpler to just disable the timeout in core whenever the
transaction ends whether committed or aborted, like statement_timeout
is disabled after each command? For example, call something like
DisableForeignCheckTimeout() in CommitTransaction() etc.
This approach seems to assume that FDW must manage all the
ForeignServer information so that the callback can return it. Is this
assumption valid for all the FDW?
FWIW, I'm not sure this feature necessarily requires core support
dedicated to FDWs. The core have USER_TIMEOUT feature already and
FDWs are not necessarily connection based. It seems better if FDWs
can implement health check feature without core support and it seems
possible. Or at least the core feature should be more generic and
simpler. Why don't we just expose InTransactionHealthCheckCallbacks or
something and operating functions on it?
How about making FDW trigger a query cancel interrupt by signaling
SIGINT to the backend, instead?
Mmm. AFAICS the running command will stop with "canceling statement
due to user request", which is a hoax. We need a more decent message
there.
I understand that the motive of this patch is "to avoid wasted long
local work when fdw-connection dies". In regard to the workload in
your first mail, it is easily avoided by ending the transaction as soon
as remote access ends. This feature doesn't work for the case "begin;
<long local query>; <fdw access>". But the same measure also works in
that case. So the only case where this feature is useful is "begin;
<fdw-access>; <some long work>; <fdw-access>; end;". But in the first
place how frequently do you expecting remote-connection close happens?
If that happens so frequently, you might need to recheck the system
health before implementing this feature. Since it is correctly
detected when something really went wrong, I feel that it is a bit too
complex for the usefulness especially for the core part.
In conclusion, as my humble opinion I would like to propose to reduce
this feature to:
- Just periodically check health (in any aspect) of all live
connections regardless of the session state.
- If an existing connection is found to be dead, just try canceling
the query (or sending query cancel).
One issue with it is how to show the decent message for the query
cancel, but maybe we can have a global variable that suggests the
reason for the cancel.
regards.
--
Kyotaro Horiguchi
NTT Open Source Software Center
Dear Horiguchi-san,
Thank you for giving your suggestions. I want to confirm your saying.
FWIW, I'm not sure this feature necessarily requires core support
dedicated to FDWs. The core have USER_TIMEOUT feature already and
FDWs are not necessarily connection based. It seems better if FDWs
can implement health check feature without core support and it seems
possible. Or at least the core feature should be more generic and
simpler. Why don't we just expose InTransactionHealthCheckCallbacks or
something and operating functions on it?
I understood that core is too complicated and FDW side is too stupid, right?
Mmm. AFAICS the running command will stop with "canceling statement
due to user request", which is a hoax. We need a more decent message
there.
+1 about better messages.
I understand that the motive of this patch is "to avoid wasted long
local work when fdw-connection dies".
Yeah your understanding is right.
In regard to the workload in
your first mail, it is easily avoided by ending the transaction as soon
as remote access ends. This feature doesn't work for the case "begin;
<long local query>; <fdw access>". But the same measure also works in
that case. So the only case where this feature is useful is "begin;
<fdw-access>; <some long work>; <fdw-access>; end;". But in the first
place how frequently do you expecting remote-connection close happens?
If that happens so frequently, you might need to recheck the system
health before implementing this feature. Since it is correctly
detected when something really went wrong, I feel that it is a bit too
complex for the usefulness especially for the core part.
Thanks for analyzing motivation.
Indeed, some cases may be resolved by separating tx and this event rarely happens.
In conclusion, as my humble opinion I would like to propose to reduce
this feature to:- Just periodically check health (in any aspect) of all live
connections regardless of the session state.
I understood here as removing following mechanism from core:
* disable timeout at end of tx.
* skip if held off or read commands
- If an existing connection is found to be dead, just try canceling
the query (or sending query cancel).
One issue with it is how to show the decent message for the query
cancel, but maybe we can have a global variable that suggests the
reason for the cancel.
Currently I have no good idea for that but I'll try.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
I understood here as removing following mechanism from core:
* disable timeout at end of tx.
While reading again and this part might be wrong.
Sorry for inconvenience.
But anyway some codes should be (re)moved from core, right?
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Hi, Kuroda-san.
At Thu, 17 Feb 2022 04:11:09 +0000, "kuroda.hayato@fujitsu.com" <kuroda.hayato@fujitsu.com> wrote in
Dear Horiguchi-san,
Thank you for giving your suggestions. I want to confirm your saying.
FWIW, I'm not sure this feature necessarily requires core support
dedicated to FDWs. The core have USER_TIMEOUT feature already and
FDWs are not necessarily connection based. It seems better if FDWs
can implement health check feature without core support and it seems
possible. Or at least the core feature should be more generic and
simpler. Why don't we just expose InTransactionHealthCheckCallbacks or
something and operating functions on it?I understood that core is too complicated and FDW side is too stupid, right?
I don't think the FDW side is stupid but seem too complex for the
benefit. And just think that maybe we don't need the core part.
Mmm. AFAICS the running command will stop with "canceling statement
due to user request", which is a hoax. We need a more decent message
there.+1 about better messages.
I understand that the motive of this patch is "to avoid wasted long
local work when fdw-connection dies".Yeah your understanding is right.
In regard to the workload in
your first mail, it is easily avoided by ending the transaction as soon
as remote access ends. This feature doesn't work for the case "begin;
<long local query>; <fdw access>". But the same measure also works in
that case. So the only case where this feature is useful is "begin;
<fdw-access>; <some long work>; <fdw-access>; end;". But in the first
place how frequently do you expecting remote-connection close happens?
If that happens so frequently, you might need to recheck the system
health before implementing this feature. Since it is correctly
detected when something really went wrong, I feel that it is a bit too
complex for the usefulness especially for the core part.Thanks for analyzing motivation.
Indeed, some cases may be resolved by separating tx and this event rarely happens.In conclusion, as my humble opinion I would like to propose to reduce
this feature to:- Just periodically check health (in any aspect) of all live
connections regardless of the session state.I understood here as removing following mechanism from core:
* disable timeout at end of tx.
* skip if held off or read commands
I think we're on the same page. Anyway query cancel interrupt is
ignored while rading input.
- If an existing connection is found to be dead, just try canceling
the query (or sending query cancel).
One issue with it is how to show the decent message for the query
cancel, but maybe we can have a global variable that suggests the
reason for the cancel.Currently I have no good idea for that but I'll try.
However, I would like to hear others' opnions about the direction, of
course.
regards.
--
Kyotaro Horiguchi
NTT Open Source Software Center
At Thu, 17 Feb 2022 04:32:26 +0000, "kuroda.hayato@fujitsu.com" <kuroda.hayato@fujitsu.com> wrote in
I understood here as removing following mechanism from core:
* disable timeout at end of tx.
While reading again and this part might be wrong.
Sorry for inconvenience.
But anyway some codes should be (re)moved from core, right?
I think we just don't need to add the special timeout kind to the
core. postgres_fdw can use USER_TIMEOUT and it would be suffiction to
keep running health checking regardless of transaction state then fire
query cancel if disconnection happens. As I said in the previous main,
possible extra query cancel woud be safe.
regards.
--
Kyotaro Horiguchi
NTT Open Source Software Center
Dear Horiguchi-san,
I think we just don't need to add the special timeout kind to the
core. postgres_fdw can use USER_TIMEOUT and it would be suffiction to
keep running health checking regardless of transaction state then fire
query cancel if disconnection happens. As I said in the previous main,
possible extra query cancel woud be safe.
I finally figured out that you mentioned about user-defined timeout system.
Firstly - before posting to hackers - I designed like that,
but I was afraid of an overhead that many FDW registers timeout
and call setitimer() many times. Is it too overcautious?
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
On 2022/02/17 19:35, kuroda.hayato@fujitsu.com wrote:
Dear Horiguchi-san,
I think we just don't need to add the special timeout kind to the
core. postgres_fdw can use USER_TIMEOUT and it would be suffiction to
keep running health checking regardless of transaction state then fire
query cancel if disconnection happens. As I said in the previous main,
possible extra query cancel woud be safe.
Sounds reasonable to me.
I finally figured out that you mentioned about user-defined timeout system.
Firstly - before posting to hackers - I designed like that,
but I was afraid of an overhead that many FDW registers timeout
and call setitimer() many times. Is it too overcautious?
Isn't it a very special case where many FDWs use their own user timeouts? Could you tell me the assumption that you're thinking, especially how many FDWs are working?
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Fujii-san,
Isn't it a very special case where many FDWs use their own user timeouts? Could
you tell me the assumption that you're thinking, especially how many FDWs are
working?
I came up with the case like star schema, which postgres database connects data store.
If each dbms are different and FDWs have each timeout, many timeout will be registered.
But it may be a corner case and should not be confused with OLTP case.
So I'll post new patch based on his post.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Dear Horiguchi-san, Fujii-san,
I understood here as removing following mechanism from core:
* disable timeout at end of tx.
* skip if held off or read commandsI think we're on the same page. Anyway query cancel interrupt is
ignored while rading input.- If an existing connection is found to be dead, just try canceling
the query (or sending query cancel).
One issue with it is how to show the decent message for the query
cancel, but maybe we can have a global variable that suggests the
reason for the cancel.Currently I have no good idea for that but I'll try.
However, I would like to hear others' opnions about the direction, of
course.
Based on the idea, I re-implemented the feature. Almost all feature is
moved to postgres_fdw. The abstract of my patch is as follows:
# core
* Exposes QueryCancelMessage for error reporting
* Uses above if it was not NULL
# postgres_fdw
* Defines new GUC postgres_fdw.health_check_interval.
It is renamed simpler.
* Registers a timeout when initializing connection hash.
* Raises SIGINT and sets QueryCancelMessage to message.
if detects a connection lost.
I also attached a test as zipped file for keep cfbot quiet.
When connection lost is detected, the following message will show:
```
ERROR: Foreign Server (servername) might be down.
```
How do you think?
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v10_0001_expose_cancel_message.patchapplication/octet-stream; name=v10_0001_expose_cancel_message.patchDownload
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 38d8b97894..891d6ac204 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -106,6 +106,8 @@ int PostAuthDelay = 0;
/* Time between checks that the client is still connected. */
int client_connection_check_interval = 0;
+char *QeuryCancelMessage = NULL;
+
/* ----------------
* private typedefs etc
* ----------------
@@ -3329,6 +3331,8 @@ ProcessInterrupts(void)
LockErrorCleanup();
ereport(ERROR,
(errcode(ERRCODE_QUERY_CANCELED),
+ QeuryCancelMessage ?
+ errmsg("%s", QeuryCancelMessage) :
errmsg("canceling statement due to user request")));
}
}
@@ -4240,6 +4244,9 @@ PostgresMain(const char *dbname, const char *username)
/* Report the error to the client and/or server log */
EmitErrorReport();
+ /* Make sure QeuryCancelMessage is reset. */
+ QeuryCancelMessage = NULL;
+
/*
* Make sure debug_query_string gets reset before we possibly clobber
* the storage it points at.
diff --git a/src/include/tcop/tcopprot.h b/src/include/tcop/tcopprot.h
index 15a11bc3ff..54ea1de9de 100644
--- a/src/include/tcop/tcopprot.h
+++ b/src/include/tcop/tcopprot.h
@@ -30,6 +30,7 @@ extern PGDLLIMPORT const char *debug_query_string;
extern int max_stack_depth;
extern int PostAuthDelay;
extern int client_connection_check_interval;
+extern char* QeuryCancelMessage;
/* GUC-configurable parameters */
v10_0002_add_health_check.patchapplication/octet-stream; name=v10_0002_add_health_check.patchDownload
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index f753c6e232..d55243fb7e 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -23,12 +23,14 @@
#include "postgres_fdw.h"
#include "storage/fd.h"
#include "storage/latch.h"
+#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/datetime.h"
#include "utils/hsearch.h"
#include "utils/inval.h"
#include "utils/memutils.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
/*
* Connection cache hash table entry
@@ -109,6 +111,10 @@ static void pgfdw_abort_cleanup(ConnCacheEntry *entry, const char *sql,
bool toplevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static void pgfdw_connection_check(void);
+static bool pgfdw_connection_check_internal(PGconn *conn);
+static TimeoutId pgfdw_health_check_timeout = MAX_TIMEOUTS;
+int pgfdw_health_check_interval;
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -153,6 +159,9 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
pgfdw_inval_callback, (Datum) 0);
CacheRegisterSyscacheCallback(USERMAPPINGOID,
pgfdw_inval_callback, (Datum) 0);
+
+ /* Register a timeout for checking remote servers */
+ pgfdw_health_check_timeout = RegisterTimeout(USER_TIMEOUT, pgfdw_connection_check);
}
/* Set flag that we did GetConnection during the current transaction */
@@ -276,6 +285,12 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
if (state)
*state = &entry->state;
+ /* Fire timeout if needed */
+ if (pgfdw_health_check_interval > 0 &&
+ !get_timeout_active(pgfdw_health_check_timeout))
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
return entry->conn;
}
@@ -1702,3 +1717,133 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Signal handler for checking remote servers.
+ *
+ * This function searches the hash table from the beginning
+ * and performs a health-check on each entry.
+ *
+ * Raise SIGINT if someone might be down, otherwise do nothing.
+ */
+void
+pgfdw_connection_check(void)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool raised = false;
+
+ Assert(ConnectionHash);
+
+ /*
+ * checking will be done by waiting WL_SOCKET_CLOSED event,
+ * so exit immediately if it cannot be used in this system.
+ */
+ if (!WaitEventSetCanReportClosed())
+ return;
+
+ /* Is there any cancel messages? */
+ if (QeuryCancelMessage != NULL)
+ return;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)) && !raised)
+ {
+ if (entry->conn == NULL || entry->xact_depth == 0)
+ continue;
+ if (!pgfdw_connection_check_internal(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so raise SIGINT.
+ * Note that error message is passed to QeuryCancelMessage
+ * for reporting error in ProcessInterrupts().
+ */
+ char msg[31 + MAXDATELEN];
+ MemoryContext old;
+ ForeignServer *server;
+
+ /*
+ * Switch to CurTransactionContext in order to
+ * make sure that the lifetime of palloc'd is transaction.
+ */
+ old = MemoryContextSwitchTo(CurTransactionContext);
+ server = GetForeignServer(entry->serverid);
+ snprintf(msg, sizeof(msg), "Foreign Server %s might be down.", server->servername);
+ QeuryCancelMessage = pstrdup(msg);
+ MemoryContextSwitchTo(old);
+
+ disconnect_pg_server(entry);
+ raise(SIGINT);
+ raised = true;
+ break;
+ }
+ }
+
+ /* re-schedule timer if needed. */
+ if (!raised && pgfdw_health_check_interval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
+ return;
+}
+
+/*
+ * helper function for pgfdw_connection_check
+ */
+static bool
+pgfdw_connection_check_internal(PGconn *conn)
+{
+ WaitEventSet *eventset;
+ WaitEvent events;
+
+ Assert(WaitEventSetCanReportClosed());
+
+ eventset = CreateWaitEventSet(CurrentMemoryContext, 1);
+ AddWaitEventToSet(eventset, WL_SOCKET_CLOSED, PQsocket(conn), NULL, NULL);
+
+ WaitEventSetWait(eventset, 0, &events, 1, 0);
+
+ if (events.events & WL_SOCKET_CLOSED)
+ {
+ FreeWaitEventSet(eventset);
+ return false;
+ }
+ FreeWaitEventSet(eventset);
+
+ return true;
+}
+
+bool
+check_pgfdw_health_check_interval(int *newval, void **extra, GucSource source)
+{
+ if (!WaitEventSetCanReportClosed() && *newval != 0)
+ {
+ GUC_check_errdetail("pgfdw_health_check_interval must be set to 0 on this platform");
+ return false;
+ }
+ return true;
+}
+
+void
+assign_pgfdw_health_check_interval(int newval, void *extra)
+{
+ /* Quick return if timeout is not registered yet. */
+ if (pgfdw_health_check_timeout == MAX_TIMEOUTS)
+ return;
+
+ if (get_timeout_active(pgfdw_health_check_timeout))
+ {
+ if (newval == 0)
+ disable_timeout(pgfdw_health_check_timeout, false);
+
+ /*
+ * we don't have to do anything because
+ * new value will be used in pgfdw_connection_check().
+ */
+ return;
+ }
+
+ /* Start timeout if wants to */
+ if (newval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout, newval);
+}
diff --git a/contrib/postgres_fdw/option.c b/contrib/postgres_fdw/option.c
index fc3ce6a53a..4dd18b565a 100644
--- a/contrib/postgres_fdw/option.c
+++ b/contrib/postgres_fdw/option.c
@@ -532,5 +532,18 @@ _PG_init(void)
NULL,
NULL);
+ DefineCustomIntVariable("postgres_fdw.health_check_interval",
+ "Sets the time interval between checks of remote servers.",
+ NULL,
+ &pgfdw_health_check_interval,
+ 0,
+ 0,
+ INT_MAX,
+ PGC_USERSET,
+ GUC_UNIT_MS,
+ check_pgfdw_health_check_interval,
+ assign_pgfdw_health_check_interval,
+ NULL);
+
EmitWarningsOnPlaceholders("postgres_fdw");
}
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 8ae79e97e4..c129af5082 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -18,6 +18,7 @@
#include "libpq-fe.h"
#include "nodes/execnodes.h"
#include "nodes/pathnodes.h"
+#include "utils/guc.h"
#include "utils/relcache.h"
/*
@@ -151,6 +152,10 @@ extern PGresult *pgfdw_exec_query(PGconn *conn, const char *query,
PgFdwConnState *state);
extern void pgfdw_report_error(int elevel, PGresult *res, PGconn *conn,
bool clear, const char *sql);
+extern bool check_pgfdw_health_check_interval(int *newval, void **extra,
+ GucSource source);
+extern void assign_pgfdw_health_check_interval(int newval, void *extra);
+extern int pgfdw_health_check_interval;
/* in option.c */
extern int ExtractConnectionOptions(List *defelems,
v10_0003_add_doc.patchapplication/octet-stream; name=v10_0003_add_doc.patchDownload
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 7bb6e525a4..dcc821df17 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -1014,6 +1014,32 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</listitem>
</varlistentry>
+ <varlistentry id="guc-pgfdw-health-check-interval" xreflabel="postgres_fdw.health_check_interval">
+ <term>
+ <varname>postgres_fdw.health_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>postgres_fdw.health_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that remote servers
+ are still alive. When losing a remote connection is detected,
+ the running transaction is aborted. This feature is performed
+ by polling the socket.
+ </para>
+ <para>
+ this option relies on kernel events exposed by Linux, macOS,
+ illumos and the BSD family of operating systems, and is not currently available
+ on other systems.
+ </para>
+ <para>
+ If the value is specified without units, it is taken as milliseconds.
+ The default value is <literal>0</literal>, which disables connection
+ checks.
+ </para>
+ </listitem>
+ </varlistentry>
</variablelist>
</sect2>
On 2022/02/22 11:53, kuroda.hayato@fujitsu.com wrote:
How do you think?
Thanks for updating the patches! I will read them.
cfbot is reporting that the 0002 patch fails to be applied cleanly. Could you update the patch?
http://cfbot.cputube.org/patch_37_3388.log
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Fujii-san,
cfbot is reporting that the 0002 patch fails to be applied cleanly. Could you update
the patch?
http://cfbot.cputube.org/patch_37_3388.log
Thanks for reporting and sorry for inconvenience.
I repo was not latest version. Attached can be applied to 52e4f0c
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v11_0001_add_checking_infrastracture.patchapplication/octet-stream; name=v11_0001_add_checking_infrastracture.patchDownload
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 3c7d08209f..206f7e1d59 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -106,6 +106,8 @@ int PostAuthDelay = 0;
/* Time between checks that the client is still connected. */
int client_connection_check_interval = 0;
+char *QeuryCancelMessage = NULL;
+
/* ----------------
* private typedefs etc
* ----------------
@@ -3327,6 +3329,8 @@ ProcessInterrupts(void)
LockErrorCleanup();
ereport(ERROR,
(errcode(ERRCODE_QUERY_CANCELED),
+ QeuryCancelMessage ?
+ errmsg("%s", QeuryCancelMessage) :
errmsg("canceling statement due to user request")));
}
}
@@ -4248,6 +4252,9 @@ PostgresMain(const char *dbname, const char *username)
/* Report the error to the client and/or server log */
EmitErrorReport();
+ /* Make sure QeuryCancelMessage is reset. */
+ QeuryCancelMessage = NULL;
+
/*
* Make sure debug_query_string gets reset before we possibly clobber
* the storage it points at.
diff --git a/src/include/tcop/tcopprot.h b/src/include/tcop/tcopprot.h
index 15a11bc3ff..54ea1de9de 100644
--- a/src/include/tcop/tcopprot.h
+++ b/src/include/tcop/tcopprot.h
@@ -30,6 +30,7 @@ extern PGDLLIMPORT const char *debug_query_string;
extern int max_stack_depth;
extern int PostAuthDelay;
extern int client_connection_check_interval;
+extern char* QeuryCancelMessage;
/* GUC-configurable parameters */
v11_0002_add_health_check.patchapplication/octet-stream; name=v11_0002_add_health_check.patchDownload
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index f753c6e232..d55243fb7e 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -23,12 +23,14 @@
#include "postgres_fdw.h"
#include "storage/fd.h"
#include "storage/latch.h"
+#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/datetime.h"
#include "utils/hsearch.h"
#include "utils/inval.h"
#include "utils/memutils.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
/*
* Connection cache hash table entry
@@ -109,6 +111,10 @@ static void pgfdw_abort_cleanup(ConnCacheEntry *entry, const char *sql,
bool toplevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static void pgfdw_connection_check(void);
+static bool pgfdw_connection_check_internal(PGconn *conn);
+static TimeoutId pgfdw_health_check_timeout = MAX_TIMEOUTS;
+int pgfdw_health_check_interval;
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -153,6 +159,9 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
pgfdw_inval_callback, (Datum) 0);
CacheRegisterSyscacheCallback(USERMAPPINGOID,
pgfdw_inval_callback, (Datum) 0);
+
+ /* Register a timeout for checking remote servers */
+ pgfdw_health_check_timeout = RegisterTimeout(USER_TIMEOUT, pgfdw_connection_check);
}
/* Set flag that we did GetConnection during the current transaction */
@@ -276,6 +285,12 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
if (state)
*state = &entry->state;
+ /* Fire timeout if needed */
+ if (pgfdw_health_check_interval > 0 &&
+ !get_timeout_active(pgfdw_health_check_timeout))
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
return entry->conn;
}
@@ -1702,3 +1717,133 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Signal handler for checking remote servers.
+ *
+ * This function searches the hash table from the beginning
+ * and performs a health-check on each entry.
+ *
+ * Raise SIGINT if someone might be down, otherwise do nothing.
+ */
+void
+pgfdw_connection_check(void)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool raised = false;
+
+ Assert(ConnectionHash);
+
+ /*
+ * checking will be done by waiting WL_SOCKET_CLOSED event,
+ * so exit immediately if it cannot be used in this system.
+ */
+ if (!WaitEventSetCanReportClosed())
+ return;
+
+ /* Is there any cancel messages? */
+ if (QeuryCancelMessage != NULL)
+ return;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)) && !raised)
+ {
+ if (entry->conn == NULL || entry->xact_depth == 0)
+ continue;
+ if (!pgfdw_connection_check_internal(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so raise SIGINT.
+ * Note that error message is passed to QeuryCancelMessage
+ * for reporting error in ProcessInterrupts().
+ */
+ char msg[31 + MAXDATELEN];
+ MemoryContext old;
+ ForeignServer *server;
+
+ /*
+ * Switch to CurTransactionContext in order to
+ * make sure that the lifetime of palloc'd is transaction.
+ */
+ old = MemoryContextSwitchTo(CurTransactionContext);
+ server = GetForeignServer(entry->serverid);
+ snprintf(msg, sizeof(msg), "Foreign Server %s might be down.", server->servername);
+ QeuryCancelMessage = pstrdup(msg);
+ MemoryContextSwitchTo(old);
+
+ disconnect_pg_server(entry);
+ raise(SIGINT);
+ raised = true;
+ break;
+ }
+ }
+
+ /* re-schedule timer if needed. */
+ if (!raised && pgfdw_health_check_interval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
+ return;
+}
+
+/*
+ * helper function for pgfdw_connection_check
+ */
+static bool
+pgfdw_connection_check_internal(PGconn *conn)
+{
+ WaitEventSet *eventset;
+ WaitEvent events;
+
+ Assert(WaitEventSetCanReportClosed());
+
+ eventset = CreateWaitEventSet(CurrentMemoryContext, 1);
+ AddWaitEventToSet(eventset, WL_SOCKET_CLOSED, PQsocket(conn), NULL, NULL);
+
+ WaitEventSetWait(eventset, 0, &events, 1, 0);
+
+ if (events.events & WL_SOCKET_CLOSED)
+ {
+ FreeWaitEventSet(eventset);
+ return false;
+ }
+ FreeWaitEventSet(eventset);
+
+ return true;
+}
+
+bool
+check_pgfdw_health_check_interval(int *newval, void **extra, GucSource source)
+{
+ if (!WaitEventSetCanReportClosed() && *newval != 0)
+ {
+ GUC_check_errdetail("pgfdw_health_check_interval must be set to 0 on this platform");
+ return false;
+ }
+ return true;
+}
+
+void
+assign_pgfdw_health_check_interval(int newval, void *extra)
+{
+ /* Quick return if timeout is not registered yet. */
+ if (pgfdw_health_check_timeout == MAX_TIMEOUTS)
+ return;
+
+ if (get_timeout_active(pgfdw_health_check_timeout))
+ {
+ if (newval == 0)
+ disable_timeout(pgfdw_health_check_timeout, false);
+
+ /*
+ * we don't have to do anything because
+ * new value will be used in pgfdw_connection_check().
+ */
+ return;
+ }
+
+ /* Start timeout if wants to */
+ if (newval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout, newval);
+}
diff --git a/contrib/postgres_fdw/option.c b/contrib/postgres_fdw/option.c
index 2c6b2894b9..75a910b0ff 100644
--- a/contrib/postgres_fdw/option.c
+++ b/contrib/postgres_fdw/option.c
@@ -538,5 +538,18 @@ _PG_init(void)
NULL,
NULL);
+ DefineCustomIntVariable("postgres_fdw.health_check_interval",
+ "Sets the time interval between checks of remote servers.",
+ NULL,
+ &pgfdw_health_check_interval,
+ 0,
+ 0,
+ INT_MAX,
+ PGC_USERSET,
+ GUC_UNIT_MS,
+ check_pgfdw_health_check_interval,
+ assign_pgfdw_health_check_interval,
+ NULL);
+
MarkGUCPrefixReserved("postgres_fdw");
}
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 8ae79e97e4..c129af5082 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -18,6 +18,7 @@
#include "libpq-fe.h"
#include "nodes/execnodes.h"
#include "nodes/pathnodes.h"
+#include "utils/guc.h"
#include "utils/relcache.h"
/*
@@ -151,6 +152,10 @@ extern PGresult *pgfdw_exec_query(PGconn *conn, const char *query,
PgFdwConnState *state);
extern void pgfdw_report_error(int elevel, PGresult *res, PGconn *conn,
bool clear, const char *sql);
+extern bool check_pgfdw_health_check_interval(int *newval, void **extra,
+ GucSource source);
+extern void assign_pgfdw_health_check_interval(int newval, void *extra);
+extern int pgfdw_health_check_interval;
/* in option.c */
extern int ExtractConnectionOptions(List *defelems,
v11_0003_add_doc.patchapplication/octet-stream; name=v11_0003_add_doc.patchDownload
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index dc57fe4b0d..21532e19d9 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -1028,6 +1028,32 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</listitem>
</varlistentry>
+ <varlistentry id="guc-pgfdw-health-check-interval" xreflabel="postgres_fdw.health_check_interval">
+ <term>
+ <varname>postgres_fdw.health_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>postgres_fdw.health_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that remote servers
+ are still alive. When losing a remote connection is detected,
+ the running transaction is aborted. This feature is performed
+ by polling the socket.
+ </para>
+ <para>
+ this option relies on kernel events exposed by Linux, macOS,
+ illumos and the BSD family of operating systems, and is not currently available
+ on other systems.
+ </para>
+ <para>
+ If the value is specified without units, it is taken as milliseconds.
+ The default value is <literal>0</literal>, which disables connection
+ checks.
+ </para>
+ </listitem>
+ </varlistentry>
</variablelist>
</sect2>
Cfbot is still angry because of missing PGDLLIMPORT, so attached.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v12_0002_add_health_check.patchapplication/octet-stream; name=v12_0002_add_health_check.patchDownload
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index f753c6e232..d55243fb7e 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -23,12 +23,14 @@
#include "postgres_fdw.h"
#include "storage/fd.h"
#include "storage/latch.h"
+#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/datetime.h"
#include "utils/hsearch.h"
#include "utils/inval.h"
#include "utils/memutils.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
/*
* Connection cache hash table entry
@@ -109,6 +111,10 @@ static void pgfdw_abort_cleanup(ConnCacheEntry *entry, const char *sql,
bool toplevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static void pgfdw_connection_check(void);
+static bool pgfdw_connection_check_internal(PGconn *conn);
+static TimeoutId pgfdw_health_check_timeout = MAX_TIMEOUTS;
+int pgfdw_health_check_interval;
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -153,6 +159,9 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
pgfdw_inval_callback, (Datum) 0);
CacheRegisterSyscacheCallback(USERMAPPINGOID,
pgfdw_inval_callback, (Datum) 0);
+
+ /* Register a timeout for checking remote servers */
+ pgfdw_health_check_timeout = RegisterTimeout(USER_TIMEOUT, pgfdw_connection_check);
}
/* Set flag that we did GetConnection during the current transaction */
@@ -276,6 +285,12 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
if (state)
*state = &entry->state;
+ /* Fire timeout if needed */
+ if (pgfdw_health_check_interval > 0 &&
+ !get_timeout_active(pgfdw_health_check_timeout))
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
return entry->conn;
}
@@ -1702,3 +1717,133 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Signal handler for checking remote servers.
+ *
+ * This function searches the hash table from the beginning
+ * and performs a health-check on each entry.
+ *
+ * Raise SIGINT if someone might be down, otherwise do nothing.
+ */
+void
+pgfdw_connection_check(void)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool raised = false;
+
+ Assert(ConnectionHash);
+
+ /*
+ * checking will be done by waiting WL_SOCKET_CLOSED event,
+ * so exit immediately if it cannot be used in this system.
+ */
+ if (!WaitEventSetCanReportClosed())
+ return;
+
+ /* Is there any cancel messages? */
+ if (QeuryCancelMessage != NULL)
+ return;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)) && !raised)
+ {
+ if (entry->conn == NULL || entry->xact_depth == 0)
+ continue;
+ if (!pgfdw_connection_check_internal(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so raise SIGINT.
+ * Note that error message is passed to QeuryCancelMessage
+ * for reporting error in ProcessInterrupts().
+ */
+ char msg[31 + MAXDATELEN];
+ MemoryContext old;
+ ForeignServer *server;
+
+ /*
+ * Switch to CurTransactionContext in order to
+ * make sure that the lifetime of palloc'd is transaction.
+ */
+ old = MemoryContextSwitchTo(CurTransactionContext);
+ server = GetForeignServer(entry->serverid);
+ snprintf(msg, sizeof(msg), "Foreign Server %s might be down.", server->servername);
+ QeuryCancelMessage = pstrdup(msg);
+ MemoryContextSwitchTo(old);
+
+ disconnect_pg_server(entry);
+ raise(SIGINT);
+ raised = true;
+ break;
+ }
+ }
+
+ /* re-schedule timer if needed. */
+ if (!raised && pgfdw_health_check_interval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
+ return;
+}
+
+/*
+ * helper function for pgfdw_connection_check
+ */
+static bool
+pgfdw_connection_check_internal(PGconn *conn)
+{
+ WaitEventSet *eventset;
+ WaitEvent events;
+
+ Assert(WaitEventSetCanReportClosed());
+
+ eventset = CreateWaitEventSet(CurrentMemoryContext, 1);
+ AddWaitEventToSet(eventset, WL_SOCKET_CLOSED, PQsocket(conn), NULL, NULL);
+
+ WaitEventSetWait(eventset, 0, &events, 1, 0);
+
+ if (events.events & WL_SOCKET_CLOSED)
+ {
+ FreeWaitEventSet(eventset);
+ return false;
+ }
+ FreeWaitEventSet(eventset);
+
+ return true;
+}
+
+bool
+check_pgfdw_health_check_interval(int *newval, void **extra, GucSource source)
+{
+ if (!WaitEventSetCanReportClosed() && *newval != 0)
+ {
+ GUC_check_errdetail("pgfdw_health_check_interval must be set to 0 on this platform");
+ return false;
+ }
+ return true;
+}
+
+void
+assign_pgfdw_health_check_interval(int newval, void *extra)
+{
+ /* Quick return if timeout is not registered yet. */
+ if (pgfdw_health_check_timeout == MAX_TIMEOUTS)
+ return;
+
+ if (get_timeout_active(pgfdw_health_check_timeout))
+ {
+ if (newval == 0)
+ disable_timeout(pgfdw_health_check_timeout, false);
+
+ /*
+ * we don't have to do anything because
+ * new value will be used in pgfdw_connection_check().
+ */
+ return;
+ }
+
+ /* Start timeout if wants to */
+ if (newval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout, newval);
+}
diff --git a/contrib/postgres_fdw/option.c b/contrib/postgres_fdw/option.c
index 2c6b2894b9..75a910b0ff 100644
--- a/contrib/postgres_fdw/option.c
+++ b/contrib/postgres_fdw/option.c
@@ -538,5 +538,18 @@ _PG_init(void)
NULL,
NULL);
+ DefineCustomIntVariable("postgres_fdw.health_check_interval",
+ "Sets the time interval between checks of remote servers.",
+ NULL,
+ &pgfdw_health_check_interval,
+ 0,
+ 0,
+ INT_MAX,
+ PGC_USERSET,
+ GUC_UNIT_MS,
+ check_pgfdw_health_check_interval,
+ assign_pgfdw_health_check_interval,
+ NULL);
+
MarkGUCPrefixReserved("postgres_fdw");
}
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 8ae79e97e4..c129af5082 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -18,6 +18,7 @@
#include "libpq-fe.h"
#include "nodes/execnodes.h"
#include "nodes/pathnodes.h"
+#include "utils/guc.h"
#include "utils/relcache.h"
/*
@@ -151,6 +152,10 @@ extern PGresult *pgfdw_exec_query(PGconn *conn, const char *query,
PgFdwConnState *state);
extern void pgfdw_report_error(int elevel, PGresult *res, PGconn *conn,
bool clear, const char *sql);
+extern bool check_pgfdw_health_check_interval(int *newval, void **extra,
+ GucSource source);
+extern void assign_pgfdw_health_check_interval(int newval, void *extra);
+extern int pgfdw_health_check_interval;
/* in option.c */
extern int ExtractConnectionOptions(List *defelems,
v12_0003_add_doc.patchapplication/octet-stream; name=v12_0003_add_doc.patchDownload
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index dc57fe4b0d..21532e19d9 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -1028,6 +1028,32 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</listitem>
</varlistentry>
+ <varlistentry id="guc-pgfdw-health-check-interval" xreflabel="postgres_fdw.health_check_interval">
+ <term>
+ <varname>postgres_fdw.health_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>postgres_fdw.health_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that remote servers
+ are still alive. When losing a remote connection is detected,
+ the running transaction is aborted. This feature is performed
+ by polling the socket.
+ </para>
+ <para>
+ this option relies on kernel events exposed by Linux, macOS,
+ illumos and the BSD family of operating systems, and is not currently available
+ on other systems.
+ </para>
+ <para>
+ If the value is specified without units, it is taken as milliseconds.
+ The default value is <literal>0</literal>, which disables connection
+ checks.
+ </para>
+ </listitem>
+ </varlistentry>
</variablelist>
</sect2>
v12_0001_add_checking_infrastracture.patchapplication/octet-stream; name=v12_0001_add_checking_infrastracture.patchDownload
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 3c7d08209f..206f7e1d59 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -106,6 +106,8 @@ int PostAuthDelay = 0;
/* Time between checks that the client is still connected. */
int client_connection_check_interval = 0;
+char *QeuryCancelMessage = NULL;
+
/* ----------------
* private typedefs etc
* ----------------
@@ -3327,6 +3329,8 @@ ProcessInterrupts(void)
LockErrorCleanup();
ereport(ERROR,
(errcode(ERRCODE_QUERY_CANCELED),
+ QeuryCancelMessage ?
+ errmsg("%s", QeuryCancelMessage) :
errmsg("canceling statement due to user request")));
}
}
@@ -4248,6 +4252,9 @@ PostgresMain(const char *dbname, const char *username)
/* Report the error to the client and/or server log */
EmitErrorReport();
+ /* Make sure QeuryCancelMessage is reset. */
+ QeuryCancelMessage = NULL;
+
/*
* Make sure debug_query_string gets reset before we possibly clobber
* the storage it points at.
diff --git a/src/include/tcop/tcopprot.h b/src/include/tcop/tcopprot.h
index 15a11bc3ff..83f894cbd0 100644
--- a/src/include/tcop/tcopprot.h
+++ b/src/include/tcop/tcopprot.h
@@ -30,6 +30,7 @@ extern PGDLLIMPORT const char *debug_query_string;
extern int max_stack_depth;
extern int PostAuthDelay;
extern int client_connection_check_interval;
+extern PGDLLIMPORT char* QeuryCancelMessage;
/* GUC-configurable parameters */
On 2022/02/22 15:41, kuroda.hayato@fujitsu.com wrote:
Cfbot is still angry because of missing PGDLLIMPORT, so attached.
Thanks for updating the patches!
The connection check timer is re-scheduled repeatedly even while the backend is in idle state or is running a local transaction that doesn't access to any foreign servers. I'm not sure if it's really worth checking the connections even in those states. Even without the periodic connection checks, if the connections are closed in those states, subsequent GetConnection() will detect that closed connection and re-establish the connection when starting remote transaction. Thought?
When a closed connection is detected in idle-in-transaction state and SIGINT is raised, nothing happens because there is no query running to be canceled by SIGINT. Also in this case the connection check timer gets disabled. So we can still execute queries that don't access to foreign servers, in the same transaction, and then the transaction commit fails. Is this expected behavior?
When I shutdowned the foreign server while the local backend is in idle-in-transaction state, the connection check timer was triggered and detected the closed connection. Then when I executed COMMIT command, I got the following WARNING message. Is this a bug?
WARNING: leaked hash_seq_search scan for hash table 0x7fd2ca878f20
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Fujii-san,
Thank you for your quick reviewing! I attached new version.
I found previous patches have wrong name. Sorry.
The connection check timer is re-scheduled repeatedly even while the backend is
in idle state or is running a local transaction that doesn't access to any foreign
servers. I'm not sure if it's really worth checking the connections even in those
states. Even without the periodic connection checks, if the connections are closed
in those states, subsequent GetConnection() will detect that closed connection
and re-establish the connection when starting remote transaction. Thought?
Indeed. We can now control the timer in fdw layer, so disable_timeout() was added
at the bottom of pgfdw_xact_callback().
When a closed connection is detected in idle-in-transaction state and SIGINT is
raised, nothing happens because there is no query running to be canceled by
SIGINT. Also in this case the connection check timer gets disabled. So we can still
execute queries that don't access to foreign servers, in the same transaction, and
then the transaction commit fails. Is this expected behavior?
It's not happy, but I'm not sure about a good solution. I made a timer reschedule
if connection lost had detected. But if queries in the transaction are quite short,
catching SIGINT may be fail.
When I shutdowned the foreign server while the local backend is in
idle-in-transaction state, the connection check timer was triggered and detected
the closed connection. Then when I executed COMMIT command, I got the
following WARNING message. Is this a bug?WARNING: leaked hash_seq_search scan for hash table 0x7fd2ca878f20
Fixed. It is caused because hash_seq_term() was not called when checker detects
a connection lost.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v13_0001_expose_cancel_message.patchapplication/octet-stream; name=v13_0001_expose_cancel_message.patchDownload
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 3c7d08209f..206f7e1d59 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -106,6 +106,8 @@ int PostAuthDelay = 0;
/* Time between checks that the client is still connected. */
int client_connection_check_interval = 0;
+char *QeuryCancelMessage = NULL;
+
/* ----------------
* private typedefs etc
* ----------------
@@ -3327,6 +3329,8 @@ ProcessInterrupts(void)
LockErrorCleanup();
ereport(ERROR,
(errcode(ERRCODE_QUERY_CANCELED),
+ QeuryCancelMessage ?
+ errmsg("%s", QeuryCancelMessage) :
errmsg("canceling statement due to user request")));
}
}
@@ -4248,6 +4252,9 @@ PostgresMain(const char *dbname, const char *username)
/* Report the error to the client and/or server log */
EmitErrorReport();
+ /* Make sure QeuryCancelMessage is reset. */
+ QeuryCancelMessage = NULL;
+
/*
* Make sure debug_query_string gets reset before we possibly clobber
* the storage it points at.
diff --git a/src/include/tcop/tcopprot.h b/src/include/tcop/tcopprot.h
index 15a11bc3ff..83f894cbd0 100644
--- a/src/include/tcop/tcopprot.h
+++ b/src/include/tcop/tcopprot.h
@@ -30,6 +30,7 @@ extern PGDLLIMPORT const char *debug_query_string;
extern int max_stack_depth;
extern int PostAuthDelay;
extern int client_connection_check_interval;
+extern PGDLLIMPORT char* QeuryCancelMessage;
/* GUC-configurable parameters */
v13_0002_add_health_check.patchapplication/octet-stream; name=v13_0002_add_health_check.patchDownload
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index f753c6e232..f691b482a1 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -23,12 +23,14 @@
#include "postgres_fdw.h"
#include "storage/fd.h"
#include "storage/latch.h"
+#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/datetime.h"
#include "utils/hsearch.h"
#include "utils/inval.h"
#include "utils/memutils.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
/*
* Connection cache hash table entry
@@ -109,6 +111,10 @@ static void pgfdw_abort_cleanup(ConnCacheEntry *entry, const char *sql,
bool toplevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static void pgfdw_connection_check(void);
+static bool pgfdw_connection_check_internal(PGconn *conn);
+static TimeoutId pgfdw_health_check_timeout = MAX_TIMEOUTS;
+int pgfdw_health_check_interval;
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -153,6 +159,9 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
pgfdw_inval_callback, (Datum) 0);
CacheRegisterSyscacheCallback(USERMAPPINGOID,
pgfdw_inval_callback, (Datum) 0);
+
+ /* Register a timeout for checking remote servers */
+ pgfdw_health_check_timeout = RegisterTimeout(USER_TIMEOUT, pgfdw_connection_check);
}
/* Set flag that we did GetConnection during the current transaction */
@@ -276,6 +285,12 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
if (state)
*state = &entry->state;
+ /* Fire timeout if needed */
+ if (pgfdw_health_check_interval > 0 &&
+ !get_timeout_active(pgfdw_health_check_timeout))
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
return entry->conn;
}
@@ -1007,6 +1022,9 @@ pgfdw_xact_callback(XactEvent event, void *arg)
*/
xact_got_connection = false;
+ /* stop timer because checking is no more needed. */
+ disable_timeout(pgfdw_health_check_timeout, false);
+
/* Also reset cursor numbering for next transaction */
cursor_number = 0;
}
@@ -1702,3 +1720,139 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Signal handler for checking remote servers.
+ *
+ * This function searches the hash table from the beginning
+ * and performs a health-check on each entry.
+ *
+ * Raise SIGINT if someone might be down, otherwise do nothing.
+ */
+void
+pgfdw_connection_check(void)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+
+ Assert(ConnectionHash);
+
+ /*
+ * checking will be done by waiting WL_SOCKET_CLOSED event,
+ * so exit immediately if it cannot be used in this system.
+ */
+ if (!WaitEventSetCanReportClosed())
+ return;
+
+ /* Is there any cancel messages? If so, raise again and re-schedule */
+ if (QeuryCancelMessage != NULL)
+ {
+ raise(SIGINT);
+ if (pgfdw_health_check_interval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+ return;
+ }
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ if (entry->conn == NULL || entry->xact_depth == 0)
+ continue;
+ if (!pgfdw_connection_check_internal(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so raise SIGINT.
+ * Note that error message is passed to QeuryCancelMessage
+ * for reporting error in ProcessInterrupts().
+ */
+ char msg[31 + MAXDATELEN];
+ MemoryContext old;
+ ForeignServer *server;
+
+ /*
+ * Switch to CurTransactionContext in order to
+ * make sure that the lifetime of palloc'd is transaction.
+ */
+ old = MemoryContextSwitchTo(CurTransactionContext);
+ server = GetForeignServer(entry->serverid);
+ snprintf(msg, sizeof(msg), "Foreign Server %s might be down.", server->servername);
+ QeuryCancelMessage = pstrdup(msg);
+ MemoryContextSwitchTo(old);
+
+ disconnect_pg_server(entry);
+ hash_seq_term(&scan);
+
+ raise(SIGINT);
+ break;
+ }
+ }
+
+ /* re-schedule timer if needed. */
+ if (pgfdw_health_check_interval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
+ return;
+}
+
+/*
+ * helper function for pgfdw_connection_check
+ */
+static bool
+pgfdw_connection_check_internal(PGconn *conn)
+{
+ WaitEventSet *eventset;
+ WaitEvent events;
+
+ Assert(WaitEventSetCanReportClosed());
+
+ eventset = CreateWaitEventSet(CurrentMemoryContext, 1);
+ AddWaitEventToSet(eventset, WL_SOCKET_CLOSED, PQsocket(conn), NULL, NULL);
+
+ WaitEventSetWait(eventset, 0, &events, 1, 0);
+
+ if (events.events & WL_SOCKET_CLOSED)
+ {
+ FreeWaitEventSet(eventset);
+ return false;
+ }
+ FreeWaitEventSet(eventset);
+
+ return true;
+}
+
+bool
+check_pgfdw_health_check_interval(int *newval, void **extra, GucSource source)
+{
+ if (!WaitEventSetCanReportClosed() && *newval != 0)
+ {
+ GUC_check_errdetail("pgfdw_health_check_interval must be set to 0 on this platform");
+ return false;
+ }
+ return true;
+}
+
+void
+assign_pgfdw_health_check_interval(int newval, void *extra)
+{
+ /* Quick return if timeout is not registered yet. */
+ if (pgfdw_health_check_timeout == MAX_TIMEOUTS)
+ return;
+
+ if (get_timeout_active(pgfdw_health_check_timeout))
+ {
+ if (newval == 0)
+ disable_timeout(pgfdw_health_check_timeout, false);
+
+ /*
+ * we don't have to do anything because
+ * new value will be used in pgfdw_connection_check().
+ */
+ return;
+ }
+
+ /* Start timeout if wants to */
+ if (newval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout, newval);
+}
diff --git a/contrib/postgres_fdw/option.c b/contrib/postgres_fdw/option.c
index 2c6b2894b9..75a910b0ff 100644
--- a/contrib/postgres_fdw/option.c
+++ b/contrib/postgres_fdw/option.c
@@ -538,5 +538,18 @@ _PG_init(void)
NULL,
NULL);
+ DefineCustomIntVariable("postgres_fdw.health_check_interval",
+ "Sets the time interval between checks of remote servers.",
+ NULL,
+ &pgfdw_health_check_interval,
+ 0,
+ 0,
+ INT_MAX,
+ PGC_USERSET,
+ GUC_UNIT_MS,
+ check_pgfdw_health_check_interval,
+ assign_pgfdw_health_check_interval,
+ NULL);
+
MarkGUCPrefixReserved("postgres_fdw");
}
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 8ae79e97e4..c129af5082 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -18,6 +18,7 @@
#include "libpq-fe.h"
#include "nodes/execnodes.h"
#include "nodes/pathnodes.h"
+#include "utils/guc.h"
#include "utils/relcache.h"
/*
@@ -151,6 +152,10 @@ extern PGresult *pgfdw_exec_query(PGconn *conn, const char *query,
PgFdwConnState *state);
extern void pgfdw_report_error(int elevel, PGresult *res, PGconn *conn,
bool clear, const char *sql);
+extern bool check_pgfdw_health_check_interval(int *newval, void **extra,
+ GucSource source);
+extern void assign_pgfdw_health_check_interval(int newval, void *extra);
+extern int pgfdw_health_check_interval;
/* in option.c */
extern int ExtractConnectionOptions(List *defelems,
v13_0003_add_doc.patchapplication/octet-stream; name=v13_0003_add_doc.patchDownload
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index dc57fe4b0d..21532e19d9 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -1028,6 +1028,32 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</listitem>
</varlistentry>
+ <varlistentry id="guc-pgfdw-health-check-interval" xreflabel="postgres_fdw.health_check_interval">
+ <term>
+ <varname>postgres_fdw.health_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>postgres_fdw.health_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that remote servers
+ are still alive. When losing a remote connection is detected,
+ the running transaction is aborted. This feature is performed
+ by polling the socket.
+ </para>
+ <para>
+ this option relies on kernel events exposed by Linux, macOS,
+ illumos and the BSD family of operating systems, and is not currently available
+ on other systems.
+ </para>
+ <para>
+ If the value is specified without units, it is taken as milliseconds.
+ The default value is <literal>0</literal>, which disables connection
+ checks.
+ </para>
+ </listitem>
+ </varlistentry>
</variablelist>
</sect2>
Hi Hackers,
It's not happy, but I'm not sure about a good solution. I made a timer reschedule
if connection lost had detected. But if queries in the transaction are quite short,
catching SIGINT may be fail.
Attached uses another way: sets pending flags again if DoingCommandRead is true.
If a remote server goes down while it is in idle_in_transaction,
next query will fail because of ereport(ERROR).
How do you think?
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v14_0001_expose_cancel_message.patchapplication/octet-stream; name=v14_0001_expose_cancel_message.patchDownload
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 34c13a1113..47c72def5b 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -105,6 +105,8 @@ int PostAuthDelay = 0;
/* Time between checks that the client is still connected. */
int client_connection_check_interval = 0;
+char *QueryCancelMessage = NULL;
+
/* ----------------
* private typedefs etc
* ----------------
@@ -3326,8 +3328,20 @@ ProcessInterrupts(void)
LockErrorCleanup();
ereport(ERROR,
(errcode(ERRCODE_QUERY_CANCELED),
+ QueryCancelMessage ?
+ errmsg("%s", QueryCancelMessage) :
errmsg("canceling statement due to user request")));
}
+ else if (QueryCancelMessage != NULL)
+ {
+ /*
+ * If we reach here someone wanted to cancel query but it was skepped
+ * because connection status was idle. So re-arm Pending flags
+ * for next iteration.
+ */
+ InterruptPending = true;
+ QueryCancelPending = true;
+ }
}
if (IdleInTransactionSessionTimeoutPending)
@@ -4247,6 +4261,9 @@ PostgresMain(const char *dbname, const char *username)
/* Report the error to the client and/or server log */
EmitErrorReport();
+ /* Make sure QueryCancelMessage is reset. */
+ QueryCancelMessage = NULL;
+
/*
* Make sure debug_query_string gets reset before we possibly clobber
* the storage it points at.
diff --git a/src/include/tcop/tcopprot.h b/src/include/tcop/tcopprot.h
index 15a11bc3ff..51f91be14b 100644
--- a/src/include/tcop/tcopprot.h
+++ b/src/include/tcop/tcopprot.h
@@ -30,6 +30,7 @@ extern PGDLLIMPORT const char *debug_query_string;
extern int max_stack_depth;
extern int PostAuthDelay;
extern int client_connection_check_interval;
+extern PGDLLIMPORT char* QueryCancelMessage;
/* GUC-configurable parameters */
v14_0002_add_health_check.patchapplication/octet-stream; name=v14_0002_add_health_check.patchDownload
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 8c64d42dda..cc9aeab799 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -23,12 +23,14 @@
#include "postgres_fdw.h"
#include "storage/fd.h"
#include "storage/latch.h"
+#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/datetime.h"
#include "utils/hsearch.h"
#include "utils/inval.h"
#include "utils/memutils.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
/*
* Connection cache hash table entry
@@ -117,6 +119,10 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static void pgfdw_connection_check(void);
+static bool pgfdw_connection_check_internal(PGconn *conn);
+static TimeoutId pgfdw_health_check_timeout = MAX_TIMEOUTS;
+int pgfdw_health_check_interval;
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -161,6 +167,9 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
pgfdw_inval_callback, (Datum) 0);
CacheRegisterSyscacheCallback(USERMAPPINGOID,
pgfdw_inval_callback, (Datum) 0);
+
+ /* Register a timeout for checking remote servers */
+ pgfdw_health_check_timeout = RegisterTimeout(USER_TIMEOUT, pgfdw_connection_check);
}
/* Set flag that we did GetConnection during the current transaction */
@@ -284,6 +293,12 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
if (state)
*state = &entry->state;
+ /* Fire timeout if needed */
+ if (pgfdw_health_check_interval > 0 &&
+ !get_timeout_active(pgfdw_health_check_timeout))
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
return entry->conn;
}
@@ -1040,6 +1055,9 @@ pgfdw_xact_callback(XactEvent event, void *arg)
*/
xact_got_connection = false;
+ /* stop timer because checking is no more needed. */
+ disable_timeout(pgfdw_health_check_timeout, false);
+
/* Also reset cursor numbering for next transaction */
cursor_number = 0;
}
@@ -1889,3 +1907,133 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Signal handler for checking remote servers.
+ *
+ * This function searches the hash table from the beginning
+ * and performs a health-check on each entry.
+ *
+ * Raise SIGINT if someone might be down, otherwise do nothing.
+ */
+void
+pgfdw_connection_check(void)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+
+ Assert(ConnectionHash);
+
+ /*
+ * checking will be done by waiting WL_SOCKET_CLOSED event,
+ * so exit immediately if it cannot be used in this system.
+ */
+ if (!WaitEventSetCanReportClosed())
+ return;
+
+ /* Quick exit if QueryCancelMessage has already set. */
+ if (QueryCancelMessage != NULL)
+ return;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ if (entry->conn == NULL || entry->xact_depth == 0)
+ continue;
+ if (!pgfdw_connection_check_internal(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so raise SIGINT.
+ * Note that error message is passed to QueryCancelMessage
+ * for reporting error in ProcessInterrupts().
+ */
+ char msg[31 + MAXDATELEN];
+ MemoryContext old;
+ ForeignServer *server;
+
+ /*
+ * Switch to CurTransactionContext in order to
+ * make sure that the lifetime of palloc'd is transaction.
+ */
+ old = MemoryContextSwitchTo(CurTransactionContext);
+ server = GetForeignServer(entry->serverid);
+ snprintf(msg, sizeof(msg), "Foreign Server %s might be down.", server->servername);
+ QueryCancelMessage = pstrdup(msg);
+ MemoryContextSwitchTo(old);
+
+ disconnect_pg_server(entry);
+ hash_seq_term(&scan);
+
+ raise(SIGINT);
+ break;
+ }
+ }
+
+ /* re-schedule timer if needed. */
+ if (pgfdw_health_check_interval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
+ return;
+}
+
+/*
+ * helper function for pgfdw_connection_check
+ */
+static bool
+pgfdw_connection_check_internal(PGconn *conn)
+{
+ WaitEventSet *eventset;
+ WaitEvent events;
+
+ Assert(WaitEventSetCanReportClosed());
+
+ eventset = CreateWaitEventSet(CurrentMemoryContext, 1);
+ AddWaitEventToSet(eventset, WL_SOCKET_CLOSED, PQsocket(conn), NULL, NULL);
+
+ WaitEventSetWait(eventset, 0, &events, 1, 0);
+
+ if (events.events & WL_SOCKET_CLOSED)
+ {
+ FreeWaitEventSet(eventset);
+ return false;
+ }
+ FreeWaitEventSet(eventset);
+
+ return true;
+}
+
+bool
+check_pgfdw_health_check_interval(int *newval, void **extra, GucSource source)
+{
+ if (!WaitEventSetCanReportClosed() && *newval != 0)
+ {
+ GUC_check_errdetail("pgfdw_health_check_interval must be set to 0 on this platform");
+ return false;
+ }
+ return true;
+}
+
+void
+assign_pgfdw_health_check_interval(int newval, void *extra)
+{
+ /* Quick return if timeout is not registered yet. */
+ if (pgfdw_health_check_timeout == MAX_TIMEOUTS)
+ return;
+
+ if (get_timeout_active(pgfdw_health_check_timeout))
+ {
+ if (newval == 0)
+ disable_timeout(pgfdw_health_check_timeout, false);
+
+ /*
+ * we don't have to do anything because
+ * new value will be used in pgfdw_connection_check().
+ */
+ return;
+ }
+
+ /* Start timeout if wants to */
+ if (newval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout, newval);
+}
diff --git a/contrib/postgres_fdw/option.c b/contrib/postgres_fdw/option.c
index 572591a558..496a27960c 100644
--- a/contrib/postgres_fdw/option.c
+++ b/contrib/postgres_fdw/option.c
@@ -540,5 +540,18 @@ _PG_init(void)
NULL,
NULL);
+ DefineCustomIntVariable("postgres_fdw.health_check_interval",
+ "Sets the time interval between checks of remote servers.",
+ NULL,
+ &pgfdw_health_check_interval,
+ 0,
+ 0,
+ INT_MAX,
+ PGC_USERSET,
+ GUC_UNIT_MS,
+ check_pgfdw_health_check_interval,
+ assign_pgfdw_health_check_interval,
+ NULL);
+
MarkGUCPrefixReserved("postgres_fdw");
}
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 8ae79e97e4..c129af5082 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -18,6 +18,7 @@
#include "libpq-fe.h"
#include "nodes/execnodes.h"
#include "nodes/pathnodes.h"
+#include "utils/guc.h"
#include "utils/relcache.h"
/*
@@ -151,6 +152,10 @@ extern PGresult *pgfdw_exec_query(PGconn *conn, const char *query,
PgFdwConnState *state);
extern void pgfdw_report_error(int elevel, PGresult *res, PGconn *conn,
bool clear, const char *sql);
+extern bool check_pgfdw_health_check_interval(int *newval, void **extra,
+ GucSource source);
+extern void assign_pgfdw_health_check_interval(int newval, void *extra);
+extern int pgfdw_health_check_interval;
/* in option.c */
extern int ExtractConnectionOptions(List *defelems,
v14_0003_add_doc.patchapplication/octet-stream; name=v14_0003_add_doc.patchDownload
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 8ebf0dc3a0..992f093992 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -1074,6 +1074,32 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</listitem>
</varlistentry>
+ <varlistentry id="guc-pgfdw-health-check-interval" xreflabel="postgres_fdw.health_check_interval">
+ <term>
+ <varname>postgres_fdw.health_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>postgres_fdw.health_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that remote servers
+ are still alive. When losing a remote connection is detected,
+ the running transaction is aborted. This feature is performed
+ by polling the socket.
+ </para>
+ <para>
+ this option relies on kernel events exposed by Linux, macOS,
+ illumos and the BSD family of operating systems, and is not currently available
+ on other systems.
+ </para>
+ <para>
+ If the value is specified without units, it is taken as milliseconds.
+ The default value is <literal>0</literal>, which disables connection
+ checks.
+ </para>
+ </listitem>
+ </varlistentry>
</variablelist>
</sect2>
On 2022/03/04 15:17, kuroda.hayato@fujitsu.com wrote:
Hi Hackers,
It's not happy, but I'm not sure about a good solution. I made a timer reschedule
if connection lost had detected. But if queries in the transaction are quite short,
catching SIGINT may be fail.Attached uses another way: sets pending flags again if DoingCommandRead is true.
If a remote server goes down while it is in idle_in_transaction,
next query will fail because of ereport(ERROR).How do you think?
Sounds ok to me.
Thanks for updating the patches!
These failed to be applied to the master branch cleanly. Could you update them?
+ this option relies on kernel events exposed by Linux, macOS,
s/this/This
+ GUC_check_errdetail("pgfdw_health_check_interval must be set to 0 on this platform");
The actual parameter name "postgres_fdw.health_check_interval"
should be used for the message instead of internal variable name.
+ /* Register a timeout for checking remote servers */
+ pgfdw_health_check_timeout = RegisterTimeout(USER_TIMEOUT, pgfdw_connection_check);
This registered signal handler does lots of things. But that's not acceptable
and they should be performed outside signal handler. No?
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Fujii-san,
Thanks for checking!
These failed to be applied to the master branch cleanly. Could you update them?
PSA rebased patches. I reviewed my myself and they contain changes.
E.g., move GUC-related code to option.c.
+ this option relies on kernel events exposed by Linux, macOS,
s/this/This
Fixed.
+ GUC_check_errdetail("pgfdw_health_check_interval must be set
to 0 on this platform");The actual parameter name "postgres_fdw.health_check_interval"
should be used for the message instead of internal variable name.
Fixed.
This registered signal handler does lots of things. But that's not acceptable
and they should be performed outside signal handler. No?
I modified like v09 or earlier versions, which has a mechanism for registering CheckingRemoteServersCallback.
It had been removed because we want to keep core simpler, but IIUC it is needed
if the signal handler just sets some flags.
The core-side does not consider the current status of transaction and running query for simpleness.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v15-0001-Add-an-infrastracture-for-checking-remote-server.patchapplication/octet-stream; name=v15-0001-Add-an-infrastracture-for-checking-remote-server.patchDownload
From adca9c34d807d37b3226ea83800f0d6187586b73 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:02:45 +0000
Subject: [PATCH v15 1/4] Add an infrastracture for checking remote servers
This patch adds a mechanism for registering callback functions.
They should be used for checking health of remote servers.
These functions will be called when an added flag is set to true.
The flag is expected that it is set from signal handlers, which is registered by FDWs.
Inside the function a signal SIGINT should be raised and a message should be set to QueryCancelMessage
if one of remote servers is disconnected.
When a query is canceled and a string is set to QueryCancelMessage,
the server will output the given message to the log instead of the normal message.
Note that QueryCancelMessage will be never pfree()'d.
Developers must use appropriate memory context.
---
src/backend/foreign/foreign.c | 57 ++++++++++++++++++++++++++++++++
src/backend/tcop/postgres.c | 26 +++++++++++++++
src/backend/utils/init/globals.c | 1 +
src/include/foreign/foreign.h | 19 +++++++++++
src/include/miscadmin.h | 2 ++
src/include/tcop/tcopprot.h | 1 +
6 files changed, 106 insertions(+)
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index 353e20a0cf..fbc943bea9 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -28,7 +28,9 @@
#include "utils/rel.h"
#include "utils/syscache.h"
#include "utils/varlena.h"
+#include "utils/timeout.h"
+static CheckingRemoteServersCallbackItem *remote_check_callbacks = NULL;
/*
* GetForeignDataWrapper - look up the foreign-data wrapper by OID.
@@ -810,3 +812,58 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
}
return NULL;
}
+
+
+/*
+ * Register callbacks for checking remote servers.
+ *
+ * This function is intended for use by FDW extensions.
+ */
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+
+ item = (CheckingRemoteServersCallbackItem *)
+ MemoryContextAlloc(TopMemoryContext,
+ sizeof(CheckingRemoteServersCallbackItem));
+ item->callback = callback;
+ item->arg = arg;
+ item->next = remote_check_callbacks;
+ remote_check_callbacks = item;
+}
+
+void
+UnRegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+ CheckingRemoteServersCallbackItem *prev;
+
+ prev = NULL;
+ for (item = remote_check_callbacks; item; prev = item, item = item->next)
+ {
+ if (item->callback == callback && item->arg == arg)
+ {
+ if (prev)
+ prev->next = item->next;
+ else
+ remote_check_callbacks = item->next;
+ pfree(item);
+ break;
+ }
+ }
+}
+
+/*
+ * Call callbacks for checking remote servers.
+ */
+void
+CallCheckingRemoteServersCallbacks(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+
+ for (item = remote_check_callbacks; item; item = item->next)
+ item->callback(item->arg);
+}
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 35eff28bd3..772a388a87 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -35,6 +35,7 @@
#include "commands/async.h"
#include "commands/prepare.h"
#include "common/pg_prng.h"
+#include "foreign/foreign.h"
#include "jit/jit.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@@ -98,6 +99,9 @@ int PostAuthDelay = 0;
/* Time between checks that the client is still connected. */
int client_connection_check_interval = 0;
+/* Message string for canceling qurery caused by extensions */
+char *QueryCancelMessage = NULL;
+
/* ----------------
* private typedefs etc
* ----------------
@@ -3224,6 +3228,13 @@ ProcessInterrupts(void)
errmsg("connection to client lost")));
}
+ if (CheckingRemoteServersTimeoutPending)
+ {
+ CheckingRemoteServersTimeoutPending = false;
+
+ CallCheckingRemoteServersCallbacks();
+ }
+
/*
* If a recovery conflict happens while we are waiting for input from the
* client, the client is presumably just sitting idle in a transaction,
@@ -3328,8 +3339,20 @@ ProcessInterrupts(void)
LockErrorCleanup();
ereport(ERROR,
(errcode(ERRCODE_QUERY_CANCELED),
+ QueryCancelMessage ?
+ errmsg("%s", QueryCancelMessage) :
errmsg("canceling statement due to user request")));
}
+ else if (QueryCancelMessage != NULL)
+ {
+ /*
+ * If we reach here someone wanted to cancel query but it was skepped
+ * because connection status was idle. So re-arm Pending flags
+ * for next iteration.
+ */
+ InterruptPending = true;
+ QueryCancelPending = true;
+ }
}
if (IdleInTransactionSessionTimeoutPending)
@@ -4264,6 +4287,9 @@ PostgresMain(const char *dbname, const char *username)
/* Report the error to the client and/or server log */
EmitErrorReport();
+ /* Make sure QueryCancelMessage is reset. */
+ QueryCancelMessage = NULL;
+
/*
* Make sure debug_query_string gets reset before we possibly clobber
* the storage it points at.
diff --git a/src/backend/utils/init/globals.c b/src/backend/utils/init/globals.c
index 1a5d29ac9b..bb94adfea8 100644
--- a/src/backend/utils/init/globals.c
+++ b/src/backend/utils/init/globals.c
@@ -37,6 +37,7 @@ volatile sig_atomic_t IdleSessionTimeoutPending = false;
volatile sig_atomic_t ProcSignalBarrierPending = false;
volatile sig_atomic_t LogMemoryContextPending = false;
volatile sig_atomic_t IdleStatsUpdateTimeoutPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
volatile uint32 InterruptHoldoffCount = 0;
volatile uint32 QueryCancelHoldoffCount = 0;
volatile uint32 CritSectionCount = 0;
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index ac82125530..9859513ac6 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -82,4 +82,23 @@ extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum);
extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok);
extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);
+
+/* Functions and variables for fdw checking */
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+
+typedef struct CheckingRemoteServersCallbackItem CheckingRemoteServersCallbackItem;
+
+struct CheckingRemoteServersCallbackItem
+{
+ CheckingRemoteServersCallbackItem *next;
+ CheckingRemoteServersCallback callback;
+ void *arg;
+};
+
+extern void RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg);
+extern void UnRegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg);
+extern void CallCheckingRemoteServersCallbacks(void);
+
#endif /* FOREIGN_H */
diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h
index ee48e392ed..95b7d66ce3 100644
--- a/src/include/miscadmin.h
+++ b/src/include/miscadmin.h
@@ -99,6 +99,8 @@ extern PGDLLIMPORT volatile sig_atomic_t IdleStatsUpdateTimeoutPending;
extern PGDLLIMPORT volatile sig_atomic_t CheckClientConnectionPending;
extern PGDLLIMPORT volatile sig_atomic_t ClientConnectionLost;
+extern PGDLLIMPORT volatile sig_atomic_t CheckingRemoteServersTimeoutPending;
+
/* these are marked volatile because they are examined by signal handlers: */
extern PGDLLIMPORT volatile uint32 InterruptHoldoffCount;
extern PGDLLIMPORT volatile uint32 QueryCancelHoldoffCount;
diff --git a/src/include/tcop/tcopprot.h b/src/include/tcop/tcopprot.h
index 5d34978f32..3a8e8c5a19 100644
--- a/src/include/tcop/tcopprot.h
+++ b/src/include/tcop/tcopprot.h
@@ -30,6 +30,7 @@ extern PGDLLIMPORT const char *debug_query_string;
extern PGDLLIMPORT int max_stack_depth;
extern PGDLLIMPORT int PostAuthDelay;
extern PGDLLIMPORT int client_connection_check_interval;
+extern PGDLLIMPORT char* QueryCancelMessage;
/* GUC-configurable parameters */
--
2.27.0
v15-0002-postgres_fdw-Implement-health-check-feature.patchapplication/octet-stream; name=v15-0002-postgres_fdw-Implement-health-check-feature.patchDownload
From 87a482835635070347cc1c3fdf6847a4a54e5b55 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:30:56 +0000
Subject: [PATCH v15 2/4] postgres_fdw: Implement health check feature
This patch adds a new GUC parameter postgres_fdw.health_check_interval.
This defines a time interval between checking remote servers.
In the checking function we use a socket event WL_SOCKET_CLOSED.
---
contrib/postgres_fdw/connection.c | 130 ++++++++++++++++++++++++++++
contrib/postgres_fdw/option.c | 63 ++++++++++++++
contrib/postgres_fdw/postgres_fdw.h | 3 +
3 files changed, 196 insertions(+)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 939d114f02..64ec57b54e 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -23,12 +23,14 @@
#include "postgres_fdw.h"
#include "storage/fd.h"
#include "storage/latch.h"
+#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/datetime.h"
#include "utils/hsearch.h"
#include "utils/inval.h"
#include "utils/memutils.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
/*
* Connection cache hash table entry
@@ -80,6 +82,9 @@ static unsigned int prep_stmt_number = 0;
/* tracks whether any work is needed in callback functions */
static bool xact_got_connection = false;
+/* Timeout identifier for health check */
+TimeoutId pgfdw_health_check_timeout = MAX_TIMEOUTS;
+
/*
* SQL functions
*/
@@ -117,6 +122,11 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+/* Functions for checking remote servers */
+static void pgfdw_connection_check(void *arg);
+static bool pgfdw_connection_check_internal(PGconn *conn);
+static void pgfdw_checking_remote_servers_timeout_handler(void);
+
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
* server with the user's authorization. A new connection is established
@@ -160,6 +170,11 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
pgfdw_inval_callback, (Datum) 0);
CacheRegisterSyscacheCallback(USERMAPPINGOID,
pgfdw_inval_callback, (Datum) 0);
+
+ /* Register a timeout and a callback for checking remote servers */
+ pgfdw_health_check_timeout = RegisterTimeout(USER_TIMEOUT,
+ pgfdw_checking_remote_servers_timeout_handler);
+ RegisterCheckingRemoteServersCallback(pgfdw_connection_check, NULL);
}
/* Set flag that we did GetConnection during the current transaction */
@@ -283,6 +298,12 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
if (state)
*state = &entry->state;
+ /* Start health-check timer if needed */
+ if (pgfdw_health_check_interval > 0 &&
+ !get_timeout_active(pgfdw_health_check_timeout))
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
return entry->conn;
}
@@ -1040,6 +1061,9 @@ pgfdw_xact_callback(XactEvent event, void *arg)
*/
xact_got_connection = false;
+ /* Stop timer because checking is no more needed. */
+ disable_timeout(pgfdw_health_check_timeout, false);
+
/* Also reset cursor numbering for next transaction */
cursor_number = 0;
}
@@ -1862,3 +1886,109 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Signal handler for calling callbacks
+ */
+static void
+pgfdw_checking_remote_servers_timeout_handler(void)
+{
+ CheckingRemoteServersTimeoutPending = true;
+ InterruptPending = true;
+ SetLatch(MyLatch);
+}
+
+/*
+ * Function for checking remote servers.
+ *
+ * This function searches the hash table from the beginning
+ * and performs a health-check on each entry.
+ *
+ * Raise SIGINT if someone might be down, otherwise do nothing.
+ */
+static void
+pgfdw_connection_check(void *arg)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+
+ Assert(ConnectionHash);
+
+ /*
+ * checking will be done by waiting WL_SOCKET_CLOSED event,
+ * so exit immediately if it cannot be used in this system.
+ */
+ if (!WaitEventSetCanReportClosed())
+ return;
+
+ /* Quick exit if QueryCancelMessage has already set. */
+ if (QueryCancelMessage != NULL)
+ return;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ if (entry->conn == NULL || entry->xact_depth == 0)
+ continue;
+ if (!pgfdw_connection_check_internal(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so raise SIGINT.
+ * Note that error message is passed to QueryCancelMessage
+ * for reporting error in ProcessInterrupts().
+ */
+ char msg[31 + MAXDATELEN];
+ MemoryContext old;
+ ForeignServer *server;
+
+ /*
+ * Switch to CurTransactionContext in order to
+ * make sure that the lifetime of palloc'd is transaction.
+ */
+ old = MemoryContextSwitchTo(CurTransactionContext);
+ server = GetForeignServer(entry->serverid);
+ snprintf(msg, sizeof(msg), "Foreign Server %s might be down.", server->servername);
+ QueryCancelMessage = pstrdup(msg);
+ MemoryContextSwitchTo(old);
+
+ disconnect_pg_server(entry);
+ hash_seq_term(&scan);
+
+ raise(SIGINT);
+ break;
+ }
+ }
+
+ /* re-schedule timer if needed. */
+ if (pgfdw_health_check_interval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
+ return;
+}
+
+/*
+ * Helper function for pgfdw_connection_check
+ */
+static bool
+pgfdw_connection_check_internal(PGconn *conn)
+{
+ WaitEventSet *eventset;
+ WaitEvent events;
+
+ Assert(WaitEventSetCanReportClosed());
+
+ eventset = CreateWaitEventSet(CurrentMemoryContext, 1);
+ AddWaitEventToSet(eventset, WL_SOCKET_CLOSED, PQsocket(conn), NULL, NULL);
+
+ WaitEventSetWait(eventset, 0, &events, 1, 0);
+
+ if (events.events & WL_SOCKET_CLOSED)
+ {
+ FreeWaitEventSet(eventset);
+ return false;
+ }
+ FreeWaitEventSet(eventset);
+
+ return true;
+}
diff --git a/contrib/postgres_fdw/option.c b/contrib/postgres_fdw/option.c
index fa80ee2a55..9cd5a32e77 100644
--- a/contrib/postgres_fdw/option.c
+++ b/contrib/postgres_fdw/option.c
@@ -20,6 +20,7 @@
#include "commands/extension.h"
#include "libpq/libpq-be.h"
#include "postgres_fdw.h"
+#include "storage/latch.h"
#include "utils/builtins.h"
#include "utils/guc.h"
#include "utils/varlena.h"
@@ -50,6 +51,7 @@ static PQconninfoOption *libpq_options;
* GUC parameters
*/
char *pgfdw_application_name = NULL;
+int pgfdw_health_check_interval;
/*
* Helper functions
@@ -58,6 +60,13 @@ static void InitPgFdwOptions(void);
static bool is_valid_option(const char *keyword, Oid context);
static bool is_libpq_option(const char *keyword);
+/*
+ * GUC hooks
+ */
+static bool check_pgfdw_health_check_interval(int *newval, void **extra,
+ GucSource source);
+static void assign_pgfdw_health_check_interval(int newval, void *extra);
+
#include "miscadmin.h"
/*
@@ -518,6 +527,47 @@ process_pgfdw_appname(const char *appname)
return buf.data;
}
+/*
+ * Check hook for pgfdw_health_check_interval
+ */
+static bool
+check_pgfdw_health_check_interval(int *newval, void **extra, GucSource source)
+{
+ if (!WaitEventSetCanReportClosed() && *newval != 0)
+ {
+ GUC_check_errdetail("postgres_fdw.health_check_interval must be set to 0 on this platform");
+ return false;
+ }
+ return true;
+}
+
+/*
+ * Assign hook for pgfdw_health_check_interval
+ */
+static void
+assign_pgfdw_health_check_interval(int newval, void *extra)
+{
+ /* Quick return if timeout is not registered yet. */
+ if (pgfdw_health_check_timeout == MAX_TIMEOUTS)
+ return;
+
+ if (get_timeout_active(pgfdw_health_check_timeout))
+ {
+ if (newval == 0)
+ disable_timeout(pgfdw_health_check_timeout, false);
+
+ /*
+ * we don't have to do anything because
+ * new value will be used in pgfdw_connection_check().
+ */
+ return;
+ }
+
+ /* Start timeout if wants to */
+ if (newval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout, newval);
+}
+
/*
* Module load callback
*/
@@ -543,5 +593,18 @@ _PG_init(void)
NULL,
NULL);
+ DefineCustomIntVariable("postgres_fdw.health_check_interval",
+ "Sets the time interval between checks of remote servers.",
+ NULL,
+ &pgfdw_health_check_interval,
+ 0,
+ 0,
+ INT_MAX,
+ PGC_USERSET,
+ GUC_UNIT_MS,
+ check_pgfdw_health_check_interval,
+ assign_pgfdw_health_check_interval,
+ NULL);
+
MarkGUCPrefixReserved("postgres_fdw");
}
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index 21f2b20ce8..6b13544903 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -18,6 +18,7 @@
#include "libpq-fe.h"
#include "nodes/execnodes.h"
#include "nodes/pathnodes.h"
+#include "utils/timeout.h"
#include "utils/relcache.h"
/*
@@ -151,6 +152,7 @@ extern PGresult *pgfdw_exec_query(PGconn *conn, const char *query,
PgFdwConnState *state);
extern void pgfdw_report_error(int elevel, PGresult *res, PGconn *conn,
bool clear, const char *sql);
+extern TimeoutId pgfdw_health_check_timeout;
/* in option.c */
extern int ExtractConnectionOptions(List *defelems,
@@ -160,6 +162,7 @@ extern List *ExtractExtensionList(const char *extensionsString,
bool warnOnMissing);
extern char *process_pgfdw_appname(const char *appname);
extern char *pgfdw_application_name;
+extern int pgfdw_health_check_interval;
/* in deparse.c */
extern void classifyConditions(PlannerInfo *root,
--
2.27.0
v15-0003-add-doc.patchapplication/octet-stream; name=v15-0003-add-doc.patchDownload
From 4ffb4293db58cdc30af7962db22d95df40331d42 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:47:55 +0000
Subject: [PATCH v15 3/4] add doc
This patch adds descriptions about postgres_fdw.health_check_interval
---
doc/src/sgml/postgres-fdw.sgml | 26 ++++++++++++++++++++++++++
1 file changed, 26 insertions(+)
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index bfd344cdc0..44e4f07dd9 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -1078,6 +1078,32 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</listitem>
</varlistentry>
+ <varlistentry id="guc-pgfdw-health-check-interval" xreflabel="postgres_fdw.health_check_interval">
+ <term>
+ <varname>postgres_fdw.health_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>postgres_fdw.health_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that remote servers
+ are still alive. When losing a remote connection is detected,
+ the running transaction is aborted. This feature is performed
+ by polling the socket.
+ </para>
+ <para>
+ This option relies on kernel events exposed by Linux, macOS,
+ illumos and the BSD family of operating systems, and is not currently available
+ on other systems.
+ </para>
+ <para>
+ If the value is specified without units, it is taken as milliseconds.
+ The default value is <literal>0</literal>, which disables connection
+ checks.
+ </para>
+ </listitem>
+ </varlistentry>
</variablelist>
</sect2>
--
2.27.0
v15-0004-add-test.patchapplication/octet-stream; name=v15-0004-add-test.patchDownload
From 5572c8468059a10dac58e74f7961528ab68f1013 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v15 4/4] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 36 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 26 ++++++++++++++
2 files changed, 62 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 2e4e82a94f..476e4966cc 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11463,3 +11463,39 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for health-check feature
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Set GUC for checking the health of remote servers
+SET postgres_fdw.health_check_interval TO '1s';
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- While sleeping the process down will be detected.
+SELECT pg_sleep(3);
+ERROR: Foreign Server loopback might be down.
+COMMIT;
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index e48ccd286b..1e1f30fc6c 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3682,3 +3682,29 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+
+-- ===================================================================
+-- test for health-check feature
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Set GUC for checking the health of remote servers
+SET postgres_fdw.health_check_interval TO '1s';
+
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+-- While sleeping the process down will be detected.
+SELECT pg_sleep(3);
+COMMIT;
+
+-- Clean up
+RESET debug_discard_caches;
--
2.27.0
Hi,
On 2022-09-21 11:56:56 +0000, kuroda.hayato@fujitsu.com wrote:
PSA rebased patches. I reviewed my myself and they contain changes.
E.g., move GUC-related code to option.c.
This seems to reliably fail on windows. See
https://cirrus-ci.com/task/6454408568373248
https://cirrus-ci.com/github/postgresql-cfbot/postgresql/commitfest/39/3388
diff -w -U3 C:/cirrus/contrib/postgres_fdw/expected/postgres_fdw.out C:/cirrus/build/testrun/postgres_fdw/regress/results/postgres_fdw.out
--- C:/cirrus/contrib/postgres_fdw/expected/postgres_fdw.out 2022-10-02 14:47:24.486355800 +0000
+++ C:/cirrus/build/testrun/postgres_fdw/regress/results/postgres_fdw.out 2022-10-02 15:02:03.039752800 +0000
@@ -11478,6 +11478,8 @@
ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
-- Set GUC for checking the health of remote servers
SET postgres_fdw.health_check_interval TO '1s';
+ERROR: invalid value for parameter "postgres_fdw.health_check_interval": 1000
+DETAIL: postgres_fdw.health_check_interval must be set to 0 on this platform
BEGIN;
SELECT 1 FROM ft1 LIMIT 1;
?column?
@@ -11495,7 +11497,15 @@
-- While sleeping the process down will be detected.
SELECT pg_sleep(3);
-ERROR: Foreign Server loopback might be down.
+ pg_sleep
+----------
+
+(1 row)
+
COMMIT;
+ERROR: server closed the connection unexpectedly
+ This probably means the server terminated abnormally
+ before or while processing the request.
+CONTEXT: remote SQL command: COMMIT TRANSACTION
-- Clean up
RESET debug_discard_caches;
Greetings,
Andres Freund
Dear Andres,
This seems to reliably fail on windows. See
Thanks for reporting. Actually this feature cannot be used on Windows machine.
To check the status of each socket that connects to the foreign server,
the socket event WL_SOCKET_CLOSED is used.
The event is only enabled on some OSes, and Windows machine cannot.
The part must be skipped if the system cannot be used the event, but I was not sure how to do that...
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Hi Hayato Kuroda,
Thanks for the patch. I think there are some non-fdw extensions out there
which could benefit from this logic. That's why I want to first learn some
more about high-level design/goals of the patch a little more.
+/*
+ * Call callbacks for checking remote servers. + */ +void +CallCheckingRemoteServersCallbacks(void)
Why do we run this periodically, but not when a specific connection is
going to be used? Wouldn't running it periodically prevent detecting some
already-closed sockets at the time of the connection used (e.g., we checked
10 seconds ago, the server died 5 seconds ago)?
In other words, what is the trade-off for calling
pgfdw_connection_check_internal() inside GetConnection() when we are about
to use a "cached" connection? I think that might simplify the patch as well.
+/*
+ * Helper function for pgfdw_connection_check + */ +static bool +pgfdw_connection_check_internal(PGconn *conn) +{
Can we have this function/logic on Postgres core, so that other extensions
can also use?
+ AddWaitEventToSet(eventset, WL_SOCKET_CLOSED, PQsocket(conn), NULL,
NULL);
What if PQsocket(conn) returns -1? Maybe we move certain connection state
checks into pgfdw_connection_check_internal() such that it is more generic?
I can think of checks like: conn!=NULL, PQsocket(conn) != PGINVALID_SOCKET,
PQstatus == CONNECTION_OK
+ eventset = CreateWaitEventSet(CurrentMemoryContext, 1);
+ AddWaitEventToSet(eventset, WL_SOCKET_CLOSED, PQsocket(conn), NULL, NULL); + + WaitEventSetWait(eventset, 0, &events, 1, 0); + + if (events.events & WL_SOCKET_CLOSED) + { + FreeWaitEventSet(eventset); + return false; + } + FreeWaitEventSet(eventset);
Do you see any performance implications of creating/freeing waitEventSets
per check? I wonder if we can somehow re-use the same waitEventSet by
modifyWaitEvent? I guess no, but still, if this check causes a performance
implication, can we somehow cache 1 waitEventSet per connection?
Thanks,
Onder KALACI
Developing the Citus extension @Microsoft
Dear Önder,
Thank you for being interest to my patch! Your suggestions will be included to newer version.
In other words, what is the trade-off for calling
pgfdw_connection_check_internal() inside GetConnection() when we are about
to use a "cached" connection? I think that might simplify the patch as well
If the checking function is called not periodically but GetConnection(),
it means that the health of foreign servers will be check only when remote connections are used.
So following workload described in [1]/messages/by-id/TYAPR01MB58662809E678253B90E82CE5F5889@TYAPR01MB5866.jpnprd01.prod.outlook.com cannot handle the issue.
BEGIN --- remote operations--- local operations --- COMMIT
But, yes, I perfectly agreed that it could simplify the code
because we can reduce the timer part. This is second plan of this patch,
I may move on this approach if it is still useful.
Can we have this function/logic on Postgres core, so that other extensions
can also use?
I was not sure about any use-case, but I think it can because it does quite general things.
Is there any good motivation to do that?
What if PQsocket(conn) returns -1? Maybe we move certain connection state
checks into pgfdw_connection_check_internal() such that it is more generic?
I can think of checks like: conn!=NULL, PQsocket(conn) != PGINVALID_SOCKET,
PQstatus == CONNECTION_OK
ereport(ERROR) will be thrown if PQsocket(conn) returns -1.
All of you said should be handled here. I will modify it.
Do you see any performance implications of creating/freeing waitEventSets
per check? I wonder if we can somehow re-use the same waitEventSet by
modifyWaitEvent? I guess no, but still, if this check causes a performance
implication, can we somehow cache 1 waitEventSet per connection?
I have not tested yet, but I agreed this will be caused performance decrease.
In next version first I will re-use the event set anyway, and it must be considered later.
Actually I'm not sure your suggestion,
but you mean to say that we can add a hash table that associates PGconn and WaitEventSet, right?
[1]: /messages/by-id/TYAPR01MB58662809E678253B90E82CE5F5889@TYAPR01MB5866.jpnprd01.prod.outlook.com
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Hi Hayato Kuroda,
If the checking function is called not periodically but GetConnection(),
it means that the health of foreign servers will be check only when remote
connections are used.
So following workload described in [1] cannot handle the issue.BEGIN --- remote operations--- local operations --- COMMIT
As far as I can see this patch is mostly useful for detecting the failures
on the initial remote command. This is especially common when the remote
server does a failover/switchover and postgres_fdw uses a cached connection
to access to the remote server.
The remote server failures within a transaction block sounds like a much
less common problem. Still, you can give a good error message before COMMIT
is sent to the remote server.
I agree that this doesn't solve the issue you described, but I'm not sure
if it is worthwhile to fix such a problem.
Can we have this function/logic on Postgres core, so that other
extensions
can also use?
I was not sure about any use-case, but I think it can because it does
quite general things.
Is there any good motivation to do that?
I think any extension that deals with multiple Postgres nodes can benefit
from such logic. In fact, the reason I realized this patch is that on the
Citus extension, we are trying to solve a similar problem [1]Check WL_SOCKET_CLOSED before using any connection by onderkalaci · Pull Request #6259 · citusdata/citus (github.com) <https://github.com/citusdata/citus/pull/6259>, [2]Add a single connection retry in MULTI_CONNECTION_LOST state by marcocitus · Pull Request #6283 · citusdata/citus (github.com) <https://github.com/citusdata/citus/pull/6283>.
Thinking even more, I think any extension that uses libpq and WaitEventSets
can benefit from such a function.
Do you see any performance implications of creating/freeing waitEventSets
per check? I wonder if we can somehow re-use the same waitEventSet by
modifyWaitEvent? I guess no, but still, if this check causes aperformance
implication, can we somehow cache 1 waitEventSet per connection?
I have not tested yet, but I agreed this will be caused performance
decrease.
In next version first I will re-use the event set anyway, and it must be
considered later.
Actually I'm not sure your suggestion,
but you mean to say that we can add a hash table that associates PGconn
and WaitEventSet, right?
I think it also depends on where you decide to put
pgfdw_connection_check_internal(). If you prefer the postgres_fdw side,
could we maybe use ConnCacheEntry in contrib/postgres_fdw/connection.c?
But if you decide to put it into the Postgres side, the API
for pgfdw_connection_check_internal() -- or equivalent function -- could be
discussed. Do we pass a WaitEventSet and if it is NULL create a new one,
else use what is passed to the function? Not sure, maybe you can come up
with a better API.
Thanks,
Onder KALACI
[1]: Check WL_SOCKET_CLOSED before using any connection by onderkalaci · Pull Request #6259 · citusdata/citus (github.com) <https://github.com/citusdata/citus/pull/6259>
Pull Request #6259 · citusdata/citus (github.com)
<https://github.com/citusdata/citus/pull/6259>
[2]: Add a single connection retry in MULTI_CONNECTION_LOST state by marcocitus · Pull Request #6283 · citusdata/citus (github.com) <https://github.com/citusdata/citus/pull/6283>
marcocitus · Pull Request #6283 · citusdata/citus (github.com)
<https://github.com/citusdata/citus/pull/6283>
Dear Önder,
As far as I can see this patch is mostly useful for detecting the failures
on the initial remote command. This is especially common when the remote
server does a failover/switchover and postgres_fdw uses a cached connection
to access to the remote server.
Sounds reasonable. Do you mean that we can add additional GUC like "postgres_fdw.initial_check",
wait WL_SOCKET_CLOSED if the conneciton is found in the hash table, and do reconnection if it might be closed, right?
I think any extension that deals with multiple Postgres nodes can benefit
from such logic. In fact, the reason I realized this patch is that on the
Citus extension, we are trying to solve a similar problem [1], [2].
Thinking even more, I think any extension that uses libpq and WaitEventSets
can benefit from such a function.
OK, I agreed it may be useful, but where should this function be?
This cannot be used from application, so it should not in interface/libpq dir. So backend/libpq/pqcomm.c?
I think it also depends on where you decide to put
pgfdw_connection_check_internal(). If you prefer the postgres_fdw side,
could we maybe use ConnCacheEntry in contrib/postgres_fdw/connection.c?
But if you decide to put it into the Postgres side, the API
for pgfdw_connection_check_internal() -- or equivalent function -- could be
discussed. Do we pass a WaitEventSet and if it is NULL create a new one,
else use what is passed to the function? Not sure, maybe you can come up
with a better API.
Thank you for describing more detail. I can imagine you said.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Dear Önder, Fujii-san,
Thanks for giving many comments! Based on off and on discussions, I modified my patch.
Note that this patch-set did not contain all of fixes you said.
[Modified]
1.
QueryCancelPending was cleaned up when the query cancel was skipped.
In the previous version the QueryCancelPending was set to true again even if the ereport(ERROR) was skipped.
It was because I thought the transaction that accessed to foreign servers but one of them crashed should be aborted immediately.
But currenlty postgres does not have such "delayed" query cancel mechanism, so I followed the manner.
Another approach is documenting like "If QueryCancelPending is already filled, the callback function must send SIGINT signal".
This seems simpler for us, but it may be troublesome for FDW authors. How do you think?
2.
The new filed servername was added to the hash entry. It was needed
because the server name must be logged in the pgfdw_connection_check(), but according to [1]/messages/by-id/CA+TgmoYW_rSOW4JMQ9_0Df9PKQ=sQDOKUGA4Gc9D8w4wui8fSA@mail.gmail.com,
the catalog should not be read in ProcessInterrupts() to avoid the race condition.
The string is pstrdup()'d when the entry has been created, and replaced when ALTER SERER RENAME has been executed.
3.
The manner to implement the health check function was documented.
4.
raise() was replaced to kill(), because it was not used in core code.
5.
APIs to handle QueryCancelMessage were added to avoid overriding the message.
6.
Some checks for socket was added in the checking function.
[1]: /messages/by-id/CA+TgmoYW_rSOW4JMQ9_0Df9PKQ=sQDOKUGA4Gc9D8w4wui8fSA@mail.gmail.com
[Unmodified]
a.
The checking function is still in the postgres_fdw.
This is because I could not find any good file to move this function.
IIUC this function needs PGconn as an argument,
but it seems that it is declared in libpq-fe.h and it should not be included from core.
b.
In the checking function, the eventset is still created, added, and freed.
Firstly I tried to declare eventset as inner-function static variable and reuse that, but I could not do. This is because:
* The size of eventset cannot be determined when the function is called for the first time.
The size must be set in CreateWaitEventSet(), and it must be more than the number of remote connection.
* To reuse the eventset the added event must be removed every time, but it cannot.
The API ModifyWaitEvent() can be only used for "modifying" the event, not "removing".
If the function is called as events=0, we will get assertion failure in WaitEventAdjustEpoll() or something.
To avoid creating/freeing the event set, hash table must be modified but it has not done yet.
c.
Currently the status of socket is not checked in the GetConnection().
I agreed it may be useful, but I thought it might be out of scope. It could not meet the requirements.
I think it can be added separately.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v16-0002-postgres_fdw-Implement-health-check-feature.patchapplication/octet-stream; name=v16-0002-postgres_fdw-Implement-health-check-feature.patchDownload
From afdf9a6738f54672c3d2767d205e9fa79ca6f6fa Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:30:56 +0000
Subject: [PATCH v16 2/4] postgres_fdw: Implement health check feature
This patch adds a new GUC parameter postgres_fdw.health_check_interval.
This defines a time interval between checking remote servers.
In the checking function we use a socket event WL_SOCKET_CLOSED.
---
contrib/postgres_fdw/connection.c | 170 +++++++++++++++++++++++++++-
contrib/postgres_fdw/option.c | 63 +++++++++++
contrib/postgres_fdw/postgres_fdw.h | 3 +
3 files changed, 233 insertions(+), 3 deletions(-)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 939d114f02..70f87e5d38 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -23,12 +23,14 @@
#include "postgres_fdw.h"
#include "storage/fd.h"
#include "storage/latch.h"
+#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/datetime.h"
#include "utils/hsearch.h"
#include "utils/inval.h"
#include "utils/memutils.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
/*
* Connection cache hash table entry
@@ -63,6 +65,7 @@ typedef struct ConnCacheEntry
bool keep_connections; /* setting value of keep_connections
* server option */
Oid serverid; /* foreign server OID used to get server name */
+ char *servername; /* foreign server name used to report ERROR */
uint32 server_hashvalue; /* hash value of foreign server OID */
uint32 mapping_hashvalue; /* hash value of user mapping OID */
PgFdwConnState state; /* extra per-connection state */
@@ -80,6 +83,9 @@ static unsigned int prep_stmt_number = 0;
/* tracks whether any work is needed in callback functions */
static bool xact_got_connection = false;
+/* Timeout identifier for health check */
+TimeoutId pgfdw_health_check_timeout = MAX_TIMEOUTS;
+
/*
* SQL functions
*/
@@ -117,6 +123,11 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+/* Functions for checking remote servers */
+static void pgfdw_connection_check(void *arg);
+static bool pgfdw_connection_check_internal(PGconn *conn);
+static void pgfdw_checking_remote_servers_timeout_handler(void);
+
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
* server with the user's authorization. A new connection is established
@@ -138,6 +149,8 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
ConnCacheEntry *entry;
ConnCacheKey key;
MemoryContext ccxt = CurrentMemoryContext;
+ MemoryContext old;
+ ForeignServer *server = GetForeignServer(user->serverid);
/* First time through, initialize connection cache hashtable */
if (ConnectionHash == NULL)
@@ -160,6 +173,13 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
pgfdw_inval_callback, (Datum) 0);
CacheRegisterSyscacheCallback(USERMAPPINGOID,
pgfdw_inval_callback, (Datum) 0);
+ CacheRegisterSyscacheCallback(FOREIGNSERVERNAME,
+ pgfdw_inval_callback, (Datum) 0);
+
+ /* Register a timeout and a callback for checking remote servers */
+ pgfdw_health_check_timeout = RegisterTimeout(USER_TIMEOUT,
+ pgfdw_checking_remote_servers_timeout_handler);
+ RegisterCheckingRemoteServersCallback(pgfdw_connection_check, NULL);
}
/* Set flag that we did GetConnection during the current transaction */
@@ -175,10 +195,11 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
if (!found)
{
/*
- * We need only clear "conn" here; remaining fields will be filled
- * later when "conn" is set.
+ * We need clear "conn" and "servername" here; remaining fields will be filled
+ * later when they are set.
*/
entry->conn = NULL;
+ entry->servername = NULL;
}
/* Reject further use of connections which failed abort cleanup. */
@@ -203,6 +224,16 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
if (entry->conn == NULL)
make_new_connection(entry, user);
+ /*
+ * If cache entry doesn't have a name, duplicate it to the TopMemoryContext
+ */
+ if (entry->servername == NULL)
+ {
+ old = MemoryContextSwitchTo(TopMemoryContext);
+ entry->servername = pstrdup(server->servername);
+ MemoryContextSwitchTo(old);
+ }
+
/*
* We check the health of the cached connection here when using it. In
* cases where we're out of all transactions, if a broken connection is
@@ -283,6 +314,12 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
if (state)
*state = &entry->state;
+ /* Start health-check timer if needed */
+ if (pgfdw_health_check_interval > 0 &&
+ !get_timeout_active(pgfdw_health_check_timeout))
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
return entry->conn;
}
@@ -532,6 +569,12 @@ disconnect_pg_server(ConnCacheEntry *entry)
entry->conn = NULL;
ReleaseExternalFD();
}
+
+ if (entry->servername != NULL)
+ {
+ pfree(entry->servername);
+ entry->servername = NULL;
+ }
}
/*
@@ -1040,6 +1083,9 @@ pgfdw_xact_callback(XactEvent event, void *arg)
*/
xact_got_connection = false;
+ /* Stop timer because checking is no more needed. */
+ disable_timeout(pgfdw_health_check_timeout, false);
+
/* Also reset cursor numbering for next transaction */
cursor_number = 0;
}
@@ -1148,7 +1194,7 @@ pgfdw_inval_callback(Datum arg, int cacheid, uint32 hashvalue)
HASH_SEQ_STATUS scan;
ConnCacheEntry *entry;
- Assert(cacheid == FOREIGNSERVEROID || cacheid == USERMAPPINGOID);
+ Assert(cacheid == FOREIGNSERVEROID || cacheid == USERMAPPINGOID || cacheid == FOREIGNSERVERNAME);
/* ConnectionHash must exist already, if we're registered */
hash_seq_init(&scan, ConnectionHash);
@@ -1179,6 +1225,21 @@ pgfdw_inval_callback(Datum arg, int cacheid, uint32 hashvalue)
else
entry->invalidated = true;
}
+
+ /* If ALTER SERVER RENAME is executed, the entry must be also modified. */
+ if (cacheid == FOREIGNSERVERNAME &&
+ entry->server_hashvalue == hashvalue)
+ {
+ ForeignServer *server = GetForeignServer(entry->serverid);
+ MemoryContext old;
+
+ if (entry->servername != NULL)
+ pfree(entry->servername);
+
+ old = MemoryContextSwitchTo(TopMemoryContext);
+ entry->servername = pstrdup(server->servername);
+ MemoryContextSwitchTo(old);
+ }
}
}
@@ -1862,3 +1923,106 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Signal handler for triggering health check
+ */
+static void
+pgfdw_checking_remote_servers_timeout_handler(void)
+{
+ CheckingRemoteServersTimeoutPending = true;
+ InterruptPending = true;
+ SetLatch(MyLatch);
+}
+
+/*
+ * Function for checking remote servers.
+ *
+ * This function searches the hash table from the beginning
+ * and performs a health-check on each entry.
+ *
+ * Raise SIGINT if someone might be down, otherwise do nothing.
+ */
+static void
+pgfdw_connection_check(void *arg)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+
+ Assert(ConnectionHash);
+
+ /*
+ * checking will be done by waiting WL_SOCKET_CLOSED event,
+ * so exit immediately if it cannot be used in this system.
+ */
+ if (!WaitEventSetCanReportClosed())
+ return;
+
+ /* Quick exit if QueryCancelMessage has already set. */
+ if (HasQueryCancelMessage())
+ return;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ if (entry->conn == NULL || entry->xact_depth == 0)
+ continue;
+ if (!pgfdw_connection_check_internal(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so raise SIGINT.
+ * Note that error message is passed to QueryCancelMessage
+ * for reporting error in ProcessInterrupts().
+ */
+ char msg[31 + MAXDATELEN];
+ snprintf(msg, sizeof(msg), "Foreign Server %s might be down.", entry->servername);
+ TrySetQueryCancelMessage(msg);
+
+ disconnect_pg_server(entry);
+ hash_seq_term(&scan);
+
+ kill(MyProcPid, SIGINT);
+ break;
+ }
+ }
+
+ /* re-schedule timer if needed. */
+ if (pgfdw_health_check_interval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
+ return;
+}
+
+/*
+ * Helper function for pgfdw_connection_check
+ */
+static bool
+pgfdw_connection_check_internal(PGconn *conn)
+{
+ WaitEventSet *eventset;
+ WaitEvent events;
+
+ Assert(WaitEventSetCanReportClosed());
+
+ /* Raise an ERROR if invalid socket has come */
+ if (conn == NULL ||
+ PQsocket(conn) == PGINVALID_SOCKET)
+ elog(ERROR, "Invalid connection has been arrived");
+
+ eventset = CreateWaitEventSet(TopMemoryContext, 1);
+
+ (void) AddWaitEventToSet(eventset, WL_SOCKET_CLOSED, PQsocket(conn), NULL, NULL);
+
+ WaitEventSetWait(eventset, 0, &events, 1, 0);
+
+ /* return false is if the socket seems to be closed. */
+ if (events.events & WL_SOCKET_CLOSED)
+ {
+ FreeWaitEventSet(eventset);
+ return false;
+ }
+
+ FreeWaitEventSet(eventset);
+ return true;
+}
diff --git a/contrib/postgres_fdw/option.c b/contrib/postgres_fdw/option.c
index fa80ee2a55..9cd5a32e77 100644
--- a/contrib/postgres_fdw/option.c
+++ b/contrib/postgres_fdw/option.c
@@ -20,6 +20,7 @@
#include "commands/extension.h"
#include "libpq/libpq-be.h"
#include "postgres_fdw.h"
+#include "storage/latch.h"
#include "utils/builtins.h"
#include "utils/guc.h"
#include "utils/varlena.h"
@@ -50,6 +51,7 @@ static PQconninfoOption *libpq_options;
* GUC parameters
*/
char *pgfdw_application_name = NULL;
+int pgfdw_health_check_interval;
/*
* Helper functions
@@ -58,6 +60,13 @@ static void InitPgFdwOptions(void);
static bool is_valid_option(const char *keyword, Oid context);
static bool is_libpq_option(const char *keyword);
+/*
+ * GUC hooks
+ */
+static bool check_pgfdw_health_check_interval(int *newval, void **extra,
+ GucSource source);
+static void assign_pgfdw_health_check_interval(int newval, void *extra);
+
#include "miscadmin.h"
/*
@@ -518,6 +527,47 @@ process_pgfdw_appname(const char *appname)
return buf.data;
}
+/*
+ * Check hook for pgfdw_health_check_interval
+ */
+static bool
+check_pgfdw_health_check_interval(int *newval, void **extra, GucSource source)
+{
+ if (!WaitEventSetCanReportClosed() && *newval != 0)
+ {
+ GUC_check_errdetail("postgres_fdw.health_check_interval must be set to 0 on this platform");
+ return false;
+ }
+ return true;
+}
+
+/*
+ * Assign hook for pgfdw_health_check_interval
+ */
+static void
+assign_pgfdw_health_check_interval(int newval, void *extra)
+{
+ /* Quick return if timeout is not registered yet. */
+ if (pgfdw_health_check_timeout == MAX_TIMEOUTS)
+ return;
+
+ if (get_timeout_active(pgfdw_health_check_timeout))
+ {
+ if (newval == 0)
+ disable_timeout(pgfdw_health_check_timeout, false);
+
+ /*
+ * we don't have to do anything because
+ * new value will be used in pgfdw_connection_check().
+ */
+ return;
+ }
+
+ /* Start timeout if wants to */
+ if (newval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout, newval);
+}
+
/*
* Module load callback
*/
@@ -543,5 +593,18 @@ _PG_init(void)
NULL,
NULL);
+ DefineCustomIntVariable("postgres_fdw.health_check_interval",
+ "Sets the time interval between checks of remote servers.",
+ NULL,
+ &pgfdw_health_check_interval,
+ 0,
+ 0,
+ INT_MAX,
+ PGC_USERSET,
+ GUC_UNIT_MS,
+ check_pgfdw_health_check_interval,
+ assign_pgfdw_health_check_interval,
+ NULL);
+
MarkGUCPrefixReserved("postgres_fdw");
}
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index a11d45bedf..4670e8d391 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -18,6 +18,7 @@
#include "libpq-fe.h"
#include "nodes/execnodes.h"
#include "nodes/pathnodes.h"
+#include "utils/timeout.h"
#include "utils/relcache.h"
/*
@@ -151,6 +152,7 @@ extern PGresult *pgfdw_exec_query(PGconn *conn, const char *query,
PgFdwConnState *state);
extern void pgfdw_report_error(int elevel, PGresult *res, PGconn *conn,
bool clear, const char *sql);
+extern TimeoutId pgfdw_health_check_timeout;
/* in option.c */
extern int ExtractConnectionOptions(List *defelems,
@@ -160,6 +162,7 @@ extern List *ExtractExtensionList(const char *extensionsString,
bool warnOnMissing);
extern char *process_pgfdw_appname(const char *appname);
extern char *pgfdw_application_name;
+extern int pgfdw_health_check_interval;
/* in deparse.c */
extern void classifyConditions(PlannerInfo *root,
--
2.27.0
v16-0003-add-doc.patchapplication/octet-stream; name=v16-0003-add-doc.patchDownload
From c387f441289f6e2895108802d8f6bc5fe6e6ec07 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:47:55 +0000
Subject: [PATCH v16 3/4] add doc
This patch adds descriptions about postgres_fdw.health_check_interval
---
doc/src/sgml/fdwhandler.sgml | 75 ++++++++++++++++++++++++++++++++++
doc/src/sgml/postgres-fdw.sgml | 26 ++++++++++++
2 files changed, 101 insertions(+)
diff --git a/doc/src/sgml/fdwhandler.sgml b/doc/src/sgml/fdwhandler.sgml
index d0b5951019..4c1c252bc1 100644
--- a/doc/src/sgml/fdwhandler.sgml
+++ b/doc/src/sgml/fdwhandler.sgml
@@ -2136,4 +2136,79 @@ GetForeignServerByName(const char *name, bool missing_ok);
</sect1>
+ <sect1 id="fdw-health-check">
+ <title>Health check of Foreign servers</title>
+
+ <para>
+ Additionally, the FDW author can implement a function to check health of
+ foreign servers. PostgreSQL has a mechanism to call callback functions
+ registered by FDW, and they will be done when flags are set. To enable the
+ feature, FDW authors must 1) implement health check function, 2) register
+ the implemented function as health check callback function, and
+ 3) set flags in arbitrary ways.
+ </para>
+
+ <sect2 id="fdw-health-check-implement">
+ <title>Implement health check function</title>
+
+ <para>
+ The health check function must be defined as following datatype.
+<programlisting>
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+</programlisting>
+ </para>
+
+ <para>
+ When FDW finds disconnections to foreign servers, the function must set
+ an error message and send SIGINT signal to its backend process. To fill
+ and check the message following APIs can be used, which are declared in
+ <filename>tcop/tcopprot.h</filename>.
+
+<programlisting>
+extern bool TrySetQueryCancelMessage(char *message);
+extern bool HasQueryCancelMessage(void);
+</programlisting>
+
+ Note that the message will be duplicated to the transactional memory
+ context. The message does not have to be allocated memory by FDW author.
+ </para>
+
+ </sect2>
+
+ <sect2 id="fdw-health-check-callback">
+ <title>Register a callback</title>
+
+ <para>
+ Authors needs to register the callback function via following API.
+
+<programlisting>
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+</programlisting>
+ </para>
+
+ </sect2>
+
+ <sect2 id="fdw-health-check-timeout">
+ <title>Set flags in arbitrary ways</title>
+
+ <para>
+ Finally, authors must implement a mechanism to fire the health check
+ callbacks. It can be done by setting flags <literal>CheckingRemoteServersTimeoutPending</literal>
+ and <literal>InterruptPending</literal> to true. They are declared in <filename>miscadmin.h</filename>.
+
+<programlisting>
+volatile sig_atomic_t InterruptPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
+</programlisting>
+
+ Typically, the timeout mechanism can be used to set these flags. The
+ detailed description and usage are written in <filename>src/backend/utils/misc/timeout.c</filename>.
+ </para>
+
+ </sect2>
+
+ </sect1>
+
</chapter>
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index bfd344cdc0..44e4f07dd9 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -1078,6 +1078,32 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</listitem>
</varlistentry>
+ <varlistentry id="guc-pgfdw-health-check-interval" xreflabel="postgres_fdw.health_check_interval">
+ <term>
+ <varname>postgres_fdw.health_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>postgres_fdw.health_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that remote servers
+ are still alive. When losing a remote connection is detected,
+ the running transaction is aborted. This feature is performed
+ by polling the socket.
+ </para>
+ <para>
+ This option relies on kernel events exposed by Linux, macOS,
+ illumos and the BSD family of operating systems, and is not currently available
+ on other systems.
+ </para>
+ <para>
+ If the value is specified without units, it is taken as milliseconds.
+ The default value is <literal>0</literal>, which disables connection
+ checks.
+ </para>
+ </listitem>
+ </varlistentry>
</variablelist>
</sect2>
--
2.27.0
v16-0004-add-test.patchapplication/octet-stream; name=v16-0004-add-test.patchDownload
From 4f8eab3117db2c03401f89e07c426041acacf6fd Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v16 4/4] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 37 +
.../postgres_fdw/expected/postgres_fdw_1.out | 11515 ++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 27 +
3 files changed, 11579 insertions(+)
create mode 100644 contrib/postgres_fdw/expected/postgres_fdw_1.out
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index cc9e39c4a5..88c6b9ef21 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11466,3 +11466,40 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for health-check feature
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Set GUC for checking the health of remote servers
+SET postgres_fdw.health_check_interval TO '1s';
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+-- FIXME: this should be skipped in some platforms
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- While sleeping the process down will be detected.
+SELECT pg_sleep(3);
+ERROR: Foreign Server loopback might be down.
+COMMIT;
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/expected/postgres_fdw_1.out b/contrib/postgres_fdw/expected/postgres_fdw_1.out
new file mode 100644
index 0000000000..d1670c6702
--- /dev/null
+++ b/contrib/postgres_fdw/expected/postgres_fdw_1.out
@@ -0,0 +1,11515 @@
+-- ===================================================================
+-- create FDW objects
+-- ===================================================================
+CREATE EXTENSION postgres_fdw;
+CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw;
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback2 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback3 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+CREATE USER MAPPING FOR public SERVER testserver1
+ OPTIONS (user 'value', password 'value');
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback2;
+CREATE USER MAPPING FOR public SERVER loopback3;
+-- ===================================================================
+-- create objects used through FDW loopback server
+-- ===================================================================
+CREATE TYPE user_enum AS ENUM ('foo', 'bar', 'buz');
+CREATE SCHEMA "S 1";
+CREATE TABLE "S 1"."T 1" (
+ "C 1" int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10),
+ c8 user_enum,
+ CONSTRAINT t1_pkey PRIMARY KEY ("C 1")
+);
+CREATE TABLE "S 1"."T 2" (
+ c1 int NOT NULL,
+ c2 text,
+ CONSTRAINT t2_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 3" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t3_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 4" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t4_pkey PRIMARY KEY (c1)
+);
+-- Disable autovacuum for these tables to avoid unexpected effects of that
+ALTER TABLE "S 1"."T 1" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 2" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 3" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 4" SET (autovacuum_enabled = 'false');
+INSERT INTO "S 1"."T 1"
+ SELECT id,
+ id % 10,
+ to_char(id, 'FM00000'),
+ '1970-01-01'::timestamptz + ((id % 100) || ' days')::interval,
+ '1970-01-01'::timestamp + ((id % 100) || ' days')::interval,
+ id % 10,
+ id % 10,
+ 'foo'::user_enum
+ FROM generate_series(1, 1000) id;
+INSERT INTO "S 1"."T 2"
+ SELECT id,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+INSERT INTO "S 1"."T 3"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 3" WHERE c1 % 2 != 0; -- delete for outer join tests
+INSERT INTO "S 1"."T 4"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests
+ANALYZE "S 1"."T 1";
+ANALYZE "S 1"."T 2";
+ANALYZE "S 1"."T 3";
+ANALYZE "S 1"."T 4";
+-- ===================================================================
+-- create foreign tables
+-- ===================================================================
+CREATE FOREIGN TABLE ft1 (
+ c0 int,
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft1 DROP COLUMN c0;
+CREATE FOREIGN TABLE ft2 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ cx int,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft2',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft2 DROP COLUMN cx;
+CREATE FOREIGN TABLE ft4 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 3');
+CREATE FOREIGN TABLE ft5 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft6 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback2 OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft7 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback3 OPTIONS (schema_name 'S 1', table_name 'T 4');
+-- ===================================================================
+-- tests for validator
+-- ===================================================================
+-- requiressl and some other parameters are omitted because
+-- valid values for them depend on configure options
+ALTER SERVER testserver1 OPTIONS (
+ use_remote_estimate 'false',
+ updatable 'true',
+ fdw_startup_cost '123.456',
+ fdw_tuple_cost '0.123',
+ service 'value',
+ connect_timeout 'value',
+ dbname 'value',
+ host 'value',
+ hostaddr 'value',
+ port 'value',
+ --client_encoding 'value',
+ application_name 'value',
+ --fallback_application_name 'value',
+ keepalives 'value',
+ keepalives_idle 'value',
+ keepalives_interval 'value',
+ tcp_user_timeout 'value',
+ -- requiressl 'value',
+ sslcompression 'value',
+ sslmode 'value',
+ sslcert 'value',
+ sslkey 'value',
+ sslrootcert 'value',
+ sslcrl 'value',
+ --requirepeer 'value',
+ krbsrvname 'value',
+ gsslib 'value'
+ --replication 'value'
+);
+-- Error, invalid list syntax
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo; bar');
+ERROR: parameter "extensions" must be a list of extension names
+-- OK but gets a warning
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo, bar');
+WARNING: extension "foo" is not installed
+WARNING: extension "bar" is not installed
+ALTER SERVER testserver1 OPTIONS (DROP extensions);
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (DROP user, DROP password);
+-- Attempt to add a valid option that's not allowed in a user mapping
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslmode 'require');
+ERROR: invalid option "sslmode"
+-- But we can add valid ones fine
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslpassword 'dummy');
+-- Ensure valid options we haven't used in a user mapping yet are
+-- permitted to check validation.
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslkey 'value', ADD sslcert 'value');
+ALTER FOREIGN TABLE ft1 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft2 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+ALTER FOREIGN TABLE ft2 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+\det+
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------+-------+-----------+---------------------------------------+-------------
+ public | ft1 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft2 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft4 | loopback | (schema_name 'S 1', table_name 'T 3') |
+ public | ft5 | loopback | (schema_name 'S 1', table_name 'T 4') |
+ public | ft6 | loopback2 | (schema_name 'S 1', table_name 'T 4') |
+ public | ft7 | loopback3 | (schema_name 'S 1', table_name 'T 4') |
+(6 rows)
+
+-- Test that alteration of server options causes reconnection
+-- Remote's errors might be non-English, so hide them to ensure stable results
+\set VERBOSITY terse
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET dbname 'no such database');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+DO $d$
+ BEGIN
+ EXECUTE $$ALTER SERVER loopback
+ OPTIONS (SET dbname '$$||current_database()||$$')$$;
+ END;
+$d$;
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+-- Test that alteration of user mapping options causes reconnection
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (ADD user 'no such user');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (DROP user);
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+\set VERBOSITY default
+-- Now we should be able to run ANALYZE.
+-- To exercise multiple code paths, we use local stats on ft1
+-- and remote-estimate mode on ft2.
+ANALYZE ft1;
+ALTER FOREIGN TABLE ft2 OPTIONS (use_remote_estimate 'true');
+-- ===================================================================
+-- test error case for create publication on foreign table
+-- ===================================================================
+CREATE PUBLICATION testpub_ftbl FOR TABLE ft1; -- should fail
+ERROR: cannot add relation "ft1" to publication
+DETAIL: This operation is not supported for foreign tables.
+-- ===================================================================
+-- simple queries
+-- ===================================================================
+-- single table without alias
+EXPLAIN (COSTS OFF) SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------
+ Foreign Scan on ft1
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- single table with alias - also test that tableoid sort is not pushed to remote side
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ -> Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Sort Key: t1.c3, t1.c1, t1.tableoid
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(8 rows)
+
+SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF) SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: t1.*, c3, c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c3 ASC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(3 rows)
+
+SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ t1
+--------------------------------------------------------------------------------------------
+ (101,1,00101,"Fri Jan 02 00:00:00 1970 PST","Fri Jan 02 00:00:00 1970",1,"1 ",foo)
+ (102,2,00102,"Sat Jan 03 00:00:00 1970 PST","Sat Jan 03 00:00:00 1970",2,"2 ",foo)
+ (103,3,00103,"Sun Jan 04 00:00:00 1970 PST","Sun Jan 04 00:00:00 1970",3,"3 ",foo)
+ (104,4,00104,"Mon Jan 05 00:00:00 1970 PST","Mon Jan 05 00:00:00 1970",4,"4 ",foo)
+ (105,5,00105,"Tue Jan 06 00:00:00 1970 PST","Tue Jan 06 00:00:00 1970",5,"5 ",foo)
+ (106,6,00106,"Wed Jan 07 00:00:00 1970 PST","Wed Jan 07 00:00:00 1970",6,"6 ",foo)
+ (107,7,00107,"Thu Jan 08 00:00:00 1970 PST","Thu Jan 08 00:00:00 1970",7,"7 ",foo)
+ (108,8,00108,"Fri Jan 09 00:00:00 1970 PST","Fri Jan 09 00:00:00 1970",8,"8 ",foo)
+ (109,9,00109,"Sat Jan 10 00:00:00 1970 PST","Sat Jan 10 00:00:00 1970",9,"9 ",foo)
+ (110,0,00110,"Sun Jan 11 00:00:00 1970 PST","Sun Jan 11 00:00:00 1970",0,"0 ",foo)
+(10 rows)
+
+-- empty result
+SELECT * FROM ft1 WHERE false;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- with WHERE clause
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c7 >= '1')) AND (("C 1" = 101)) AND ((c6 = '1'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- with FOR UPDATE/SHARE
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 101)) FOR UPDATE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 102)) FOR SHARE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+-- aggregate
+SELECT COUNT(*) FROM ft1 t1;
+ count
+-------
+ 1000
+(1 row)
+
+-- subquery
+SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- subquery+MAX
+SELECT * FROM ft1 t1 WHERE t1.c3 = (SELECT MAX(c3) FROM ft2 t2) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+(1 row)
+
+-- used in CTE
+WITH t1 AS (SELECT * FROM ft1 WHERE c1 <= 10) SELECT t2.c1, t2.c2, t2.c3, t2.c4 FROM t1, ft2 t2 WHERE t1.c1 = t2.c1 ORDER BY t1.c1;
+ c1 | c2 | c3 | c4
+----+----+-------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+(10 rows)
+
+-- fixed values
+SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1;
+ ?column? | ?column?
+----------+----------
+ fixed |
+(1 row)
+
+-- Test forcing the remote server to produce sorted data for a merge join.
+SET enable_hashjoin TO false;
+SET enable_nestloop TO false;
+-- inner join; expressions in the clauses appear in the equivalence class list
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Left Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- A join between local table and foreign join. ORDER BY clause is added to the
+-- foreign join so that the local table can be joined using merge join strategy.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Merge Right Join
+ Output: t1."C 1"
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r3."C 1" FROM ("S 1"."T 1" r2 INNER JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r2."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- Test similar to above, except that the full join prevents any equivalence
+-- classes from being merged. This produces single relation equivalence classes
+-- included in join restrictions.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Right Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1, t2.c1
+ Relations: (public.ft2 t3) LEFT JOIN (public.ft1 t2)
+ Remote SQL: SELECT r3."C 1", r2."C 1" FROM ("S 1"."T 1" r3 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+-- Test similar to above with all full outer joins
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Full Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) FULL JOIN (public.ft2 t3)
+ Remote SQL: SELECT r2."C 1", r3."C 1" FROM ("S 1"."T 1" r2 FULL JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test executing assertion in estimate_path_cost_size() that makes sure that
+-- retrieved_rows for foreign rel re-used to cost pre-sorted foreign paths is
+-- a sensible value even when the rel has tuples=0
+CREATE TABLE loct_empty (c1 int NOT NULL, c2 text);
+CREATE FOREIGN TABLE ft_empty (c1 int NOT NULL, c2 text)
+ SERVER loopback OPTIONS (table_name 'loct_empty');
+INSERT INTO loct_empty
+ SELECT id, 'AAA' || to_char(id, 'FM000') FROM generate_series(1, 100) id;
+DELETE FROM loct_empty;
+ANALYZE ft_empty;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Foreign Scan on public.ft_empty
+ Output: c1, c2
+ Remote SQL: SELECT c1, c2 FROM public.loct_empty ORDER BY c1 ASC NULLS LAST
+(3 rows)
+
+-- ===================================================================
+-- WHERE with remotely-executable conditions
+-- ===================================================================
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1; -- Var, OpExpr(b), Const
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL; -- NullTest
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL; -- NullTest
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((round(abs("C 1"), 0) = 1::numeric))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1; -- OpExpr(l)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = (- "C 1")))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" IS NOT NULL) IS DISTINCT FROM ("C 1" IS NOT NULL)))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]); -- ScalarArrayOpExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ANY (ARRAY[c2, 1, ("C 1" + 0)])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1]; -- SubscriptingRef
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ((ARRAY["C 1", c2, 3])[1])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar'; -- check special chars
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c6 = E'foo''s\\bar'))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c8 = 'foo'; -- can't be sent to remote
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- parameterized remote path for foreign table
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM "S 1"."T 1" a, ft2 b WHERE a."C 1" = 47 AND b.c1 = a.c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Index Scan using t1_pkey on "S 1"."T 1" a
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Index Cond: (a."C 1" = 47)
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(8 rows)
+
+SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 47 | 7 | 00047 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo | 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+(1 row)
+
+-- check both safe and unsafe join conditions
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 a, ft2 b
+ WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Foreign Scan on public.ft2 a
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Filter: (a.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c2 = 6))
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Filter: (upper((a.c7)::text) = (b.c7)::text)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(10 rows)
+
+SELECT * FROM ft2 a, ft2 b
+WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+(100 rows)
+
+-- bug before 9.3.5 due to sloppy handling of remote-estimate parameters
+SELECT * FROM ft1 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft2 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+SELECT * FROM ft2 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft1 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+-- we should not push order by clause with volatile expressions or unsafe
+-- collations
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, random();
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, (random())
+ Sort Key: ft2.c1, (random())
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, random()
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, ft2.c3 collate "C";
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, ((c3)::text)
+ Sort Key: ft2.c1, ft2.c3 COLLATE "C"
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- user-defined operator/function
+CREATE FUNCTION postgres_fdw_abs(int) RETURNS int AS $$
+BEGIN
+RETURN abs($1);
+END
+$$ LANGUAGE plpgsql IMMUTABLE;
+CREATE OPERATOR === (
+ LEFTARG = int,
+ RIGHTARG = int,
+ PROCEDURE = int4eq,
+ COMMUTATOR = ===
+);
+-- built-in operators and functions can be shipped for remote execution
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ QUERY PLAN
+----------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- by default, user-defined ones cannot
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 = postgres_fdw_abs(t1.c2))
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- ORDER BY can be shipped, though
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- but let's put them in an extension ...
+ALTER EXTENSION postgres_fdw ADD FUNCTION postgres_fdw_abs(int);
+ALTER EXTENSION postgres_fdw ADD OPERATOR === (int, int);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- ... now they can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- and both ORDER BY and LIMIT can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2)) ORDER BY c2 ASC NULLS LAST LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- Test CASE pushdown
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE WHEN ("C 1" > 990) THEN "C 1" ELSE NULL::integer END) < 1000)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ c1 | c2 | c3
+-----+----+-------
+ 991 | 1 | 00991
+ 992 | 2 | 00992
+ 993 | 3 | 00993
+ 994 | 4 | 00994
+ 995 | 5 | 00995
+ 996 | 6 | 00996
+ 997 | 7 | 00997
+ 998 | 8 | 00998
+ 999 | 9 | 00999
+(9 rows)
+
+-- Nested CASE
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE (CASE WHEN (c2 > 0) THEN c2 ELSE NULL::integer END) WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END) > 600)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ c1 | c2 | c3
+----+----+----
+(0 rows)
+
+-- CASE arg WHEN
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE mod(c1, 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" > (CASE mod("C 1", 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)))
+(3 rows)
+
+-- CASE cannot be pushed down because of unshippable arg clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE random()::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (ft1.c1 > CASE (random())::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- these are shippable
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c6 WHEN 'foo' THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c6 WHEN 'foo'::text THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c3 WHEN c6 THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+-- but this is not because of collation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 COLLATE "C" WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: CASE (ft1.c3)::text WHEN ft1.c6 THEN true ELSE (ft1.c3 < 'bar'::text) END
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- a regconfig constant referring to this text search configuration
+-- is initially unshippable
+CREATE TEXT SEARCH CONFIGURATION public.custom_search
+ (COPY = pg_catalog.english);
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Filter: (length(to_tsvector('custom_search'::regconfig, ft1.c3)) > 0)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642))
+(4 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- but if it's in a shippable extension, it can be shipped
+ALTER EXTENSION postgres_fdw ADD TEXT SEARCH CONFIGURATION public.custom_search;
+-- however, that doesn't flush the shippability cache, so do a quick reconnect
+\c -
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642)) AND ((length(to_tsvector('public.custom_search'::regconfig, c3)) > 0))
+(3 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- ===================================================================
+-- JOIN queries
+-- ===================================================================
+-- Analyze ft4 and ft5 so that we have better statistics. These tables do not
+-- have use_remote_estimate set.
+ANALYZE ft4;
+ANALYZE ft5;
+-- join two tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3, t1.c3
+ Relations: ((public.ft1 t1) INNER JOIN (public.ft2 t2)) INNER JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3, r1.c3 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) INNER JOIN "S 1"."T 3" r4 ON (((r1."C 1" = r4.c1)))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 22 |
+ 24 | 24
+ 26 |
+ 28 |
+ 30 | 30
+ 32 |
+ 34 |
+ 36 | 36
+ 38 |
+ 40 |
+(10 rows)
+
+-- left outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + placement of clauses.
+-- clauses within the nullable side are not pulled up, but top level clause on
+-- non-nullable side is pushed into non-nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- clauses within the nullable side are not pulled up, but the top level clause
+-- on nullable side is not pushed down into nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE (((r4.c1 < 10) OR (r4.c1 IS NULL))) AND ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t2) LEFT JOIN (public.ft5 t1)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r1 ON (((r1.c1 = r2.c1)))) ORDER BY r2.c1 ASC NULLS LAST, r1.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ | 22
+ 24 | 24
+ | 26
+ | 28
+ 30 | 30
+ | 32
+ | 34
+ 36 | 36
+ | 38
+ | 40
+(10 rows)
+
+-- right outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 45::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ c1 | c1
+-----+----
+ 92 |
+ 94 |
+ 96 | 96
+ 98 |
+ 100 |
+ | 3
+ | 9
+ | 15
+ | 21
+ | 27
+(10 rows)
+
+-- full outer join with restrictions on the joining relations
+-- a. the joining relations are both base relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s4.c1, s5.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s5.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ c1 | c1
+----+----
+ 50 |
+ 52 |
+ 54 | 54
+ 56 |
+ 58 |
+ 60 | 60
+ | 51
+ | 57
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: 1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT NULL FROM ((SELECT NULL FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4 FULL JOIN (SELECT NULL FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5 ON (TRUE)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ ?column?
+----------
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- b. one of the joining relations is a base relation and the other is a join
+-- relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c1, t3.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 t2) LEFT JOIN (public.ft5 t3))
+ Remote SQL: SELECT s4.c1, s8.c1, s8.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT r5.c1, r6.c1 FROM ("S 1"."T 3" r5 LEFT JOIN "S 1"."T 4" r6 ON (((r5.c1 = r6.c1)))) WHERE ((r5.c1 >= 50)) AND ((r5.c1 <= 60))) s8(c1, c2) ON (((s4.c1 = s8.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s8.c1 ASC NULLS LAST, s8.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+(6 rows)
+
+-- c. test deparsing the remote query as nested subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft4_1.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 ft4_1) FULL JOIN (public.ft5))
+ Remote SQL: SELECT s4.c1, s10.c1, s10.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT s8.c1, s9.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL)))) s10(c1, c2) ON (((s4.c1 = s10.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s10.c1 ASC NULLS LAST, s10.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+ | | 51
+ | | 57
+(8 rows)
+
+-- d. test deparsing rowmarked relations as subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Nested Loop
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Foreign Scan
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s8.c1, s8.c2, s9.c1, s9.c2 FROM ((SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1, c2) FULL JOIN (SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1, c2) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL))) ORDER BY s8.c1 ASC NULLS LAST, s9.c1 ASC NULLS LAST
+ -> Sort
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Full Join
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Hash Cond: (ft4.c1 = ft5.c1)
+ Filter: ((ft4.c1 IS NULL) OR (ft4.c1 IS NOT NULL))
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Hash
+ Output: ft5.c1, ft5.*
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Materialize
+ Output: "T 3".c1, "T 3".ctid
+ -> Seq Scan on "S 1"."T 3"
+ Output: "T 3".c1, "T 3".ctid
+ Filter: ("T 3".c1 = 50)
+(28 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 50 | 52 |
+ 50 | 54 | 54
+ 50 | 56 |
+ 50 | 58 |
+ 50 | 60 | 60
+ 50 | | 51
+ 50 | | 57
+(8 rows)
+
+-- full outer join + inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t3.c1
+ Relations: ((public.ft4 t1) INNER JOIN (public.ft5 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1.c1, r2.c1, r4.c1 FROM (("S 1"."T 3" r1 INNER JOIN "S 1"."T 4" r2 ON (((r1.c1 = (r2.c1 + 1))) AND ((r1.c1 >= 50)) AND ((r1.c1 <= 60)))) FULL JOIN "S 1"."T 3" r4 ON (((r2.c1 = r4.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST, r4.c1 ASC NULLS LAST LIMIT 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ c1 | c1 | c1
+----+----+----
+ 52 | 51 |
+ 58 | 57 |
+ | | 2
+ | | 4
+ | | 6
+ | | 8
+ | | 10
+ | | 12
+ | | 14
+ | | 16
+(10 rows)
+
+-- full outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- right outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+SET enable_memoize TO off;
+-- right outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+RESET enable_memoize;
+-- left outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: (public.ft4 t3) LEFT JOIN ((public.ft2 t1) INNER JOIN (public.ft2 t2))
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM ("S 1"."T 3" r4 LEFT JOIN ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join + WHERE clause, only matched rows
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 = r2.c1) OR (r1.c1 IS NULL)))
+(9 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 66 | 66
+ 72 | 72
+ 78 | 78
+ 84 | 84
+ 90 | 90
+ 96 | 96
+ | 3
+ | 9
+ | 15
+ | 21
+(10 rows)
+
+-- full outer join + WHERE clause with shippable extensions set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) WHERE ((public.postgres_fdw_abs(r1."C 1") > 0)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+-- full outer join + WHERE clause with shippable extensions not set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c2, t1.c3
+ -> Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Filter: (postgres_fdw_abs(t1.c1) > 0)
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- join two tables with FOR UPDATE clause
+-- tests whole-row reference for row marks
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1 FOR UPDATE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join two tables with FOR SHARE clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1 FOR SHARE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join in CTE
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t.c1_1, t.c2_1, t.c1_3
+ CTE t
+ -> Foreign Scan
+ Output: t1.c1, t1.c3, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r1.c3, r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+ -> Sort
+ Output: t.c1_1, t.c2_1, t.c1_3
+ Sort Key: t.c1_3, t.c1_1
+ -> CTE Scan on t
+ Output: t.c1_1, t.c2_1, t.c1_3
+(12 rows)
+
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ c1_1 | c2_1
+------+------
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- ctid with whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.ctid, t1.*, t2.*, t1.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r1."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+-- SEMI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Semi Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c1)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- ANTI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Anti Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c2)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 110
+ 111
+ 112
+ 113
+ 114
+ 115
+ 116
+ 117
+ 118
+ 119
+(10 rows)
+
+-- CROSS JOIN can be pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (TRUE)) ORDER BY r1."C 1" ASC NULLS LAST, r2."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- different server, not pushed down. No result expected.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Merge Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft6 t2
+ Output: t2.c1, t2.c2, t2.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+ -> Materialize
+ Output: t1.c1, t1.c2, t1.c3
+ -> Foreign Scan on public.ft5 t1
+ Output: t1.c1, t1.c2, t1.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+(13 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+----
+(0 rows)
+
+-- unsafe join conditions (c8 has a UDT), not pushed down. Practically a CROSS
+-- JOIN since c8 in both tables has same value.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Merge Left Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t1.c8 = t2.c8)
+ -> Sort
+ Output: t1.c1, t1.c8
+ Sort Key: t1.c8
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+ -> Sort
+ Output: t2.c1, t2.c8
+ Sort Key: t2.c8
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1, t2.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+(20 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- unsafe conditions on one side (c8 has a UDT), not pushed down.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Hash Right Join
+ Output: t1.c1, t2.c1, t1.c3
+ Hash Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+ -> Hash
+ Output: t1.c1, t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c3
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c3, c8 FROM "S 1"."T 1"
+(17 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join where unsafe to pushdown condition in WHERE clause has a column not
+-- in the SELECT clause. In this test unsafe clause needs to have column
+-- references from both joining sides so that the clause is not pushed down
+-- into one of the joining sides.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Filter: (t1.c8 = t2.c8)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, r1.c8, r2.c8 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(10 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- Aggregate after UNION, for testing setrefs
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ -> Sort
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ Sort Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, avg((t1.c1 + t2.c1))
+ Group Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, t2.c1
+ Group Key: t1.c1, t2.c1
+ -> Append
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+ -> Foreign Scan
+ Output: t1_1.c1, t2_1.c1
+ Relations: (public.ft1 t1_1) INNER JOIN (public.ft2 t2_1)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(20 rows)
+
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ t1c1 | avg
+------+----------------------
+ 101 | 202.0000000000000000
+ 102 | 204.0000000000000000
+ 103 | 206.0000000000000000
+ 104 | 208.0000000000000000
+ 105 | 210.0000000000000000
+ 106 | 212.0000000000000000
+ 107 | 214.0000000000000000
+ 108 | 216.0000000000000000
+ 109 | 218.0000000000000000
+ 110 | 220.0000000000000000
+(10 rows)
+
+-- join with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Nested Loop
+ Output: t1."C 1"
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ -> Memoize
+ Cache Key: t1.c2
+ Cache Mode: binary
+ -> Subquery Scan on q
+ -> HashAggregate
+ Output: t2.c1, t3.c1
+ Group Key: t2.c1, t3.c1
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r1.c2 = $1::integer))))
+(17 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ C 1
+-----
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- non-Var items in targetlist of the nullable rel of a join preventing
+-- push-down in some cases
+-- unable to push {ft1, ft2}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: (13), ft2.c1
+ Join Filter: (13 = ft2.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" WHERE (("C 1" >= 10)) AND (("C 1" <= 15)) ORDER BY "C 1" ASC NULLS LAST
+ -> Materialize
+ Output: (13)
+ -> Foreign Scan on public.ft1
+ Output: 13
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 13))
+(11 rows)
+
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ a | c1
+----+----
+ | 10
+ | 11
+ | 12
+ 13 | 13
+ | 14
+ | 15
+(6 rows)
+
+-- ok to push {ft1, ft2} but not {ft1, ft2, ft4}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: ft4.c1, (13), ft1.c1, ft2.c1
+ Join Filter: (ft4.c1 = ft1.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
+ -> Materialize
+ Output: ft1.c1, ft2.c1, (13)
+ -> Foreign Scan
+ Output: ft1.c1, ft2.c1, 13
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r5."C 1" FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = 12)) AND ((r4."C 1" = 12)))) ORDER BY r4."C 1" ASC NULLS LAST
+(12 rows)
+
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ c1 | a | b | c
+----+----+----+----
+ 10 | | |
+ 12 | 13 | 12 | 12
+ 14 | | |
+(3 rows)
+
+-- join with nullable side with some columns with null values
+UPDATE ft5 SET c3 = null where c1 % 9 = 0;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2
+ Relations: (public.ft5) INNER JOIN (public.ft4)
+ Remote SQL: SELECT CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1.c1, r1.c2, r1.c3) END, r1.c1, r1.c2, r1.c3, r2.c1, r2.c2 FROM ("S 1"."T 4" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c1 = r2.c1)) AND ((r2.c1 >= 10)) AND ((r2.c1 <= 30)))) ORDER BY r1.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ ft5 | c1 | c2 | c3 | c1 | c2
+----------------+----+----+--------+----+----
+ (12,13,AAA012) | 12 | 13 | AAA012 | 12 | 13
+ (18,19,) | 18 | 19 | | 18 | 19
+ (24,25,AAA024) | 24 | 25 | AAA024 | 24 | 25
+ (30,31,AAA030) | 30 | 31 | AAA030 | 30 | 31
+(4 rows)
+
+-- multi-way join involving multiple merge joins
+-- (this case used to have EPQ-related planning problems)
+CREATE TABLE local_tbl (c1 int NOT NULL, c2 int NOT NULL, c3 text, CONSTRAINT local_tbl_pkey PRIMARY KEY (c1));
+INSERT INTO local_tbl SELECT id, id % 10, to_char(id, 'FM0000') FROM generate_series(1, 1000) id;
+ANALYZE local_tbl;
+SET enable_nestloop TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ Inner Unique: true
+ Merge Cond: (ft1.c2 = local_tbl.c1)
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Relations: (((public.ft1) INNER JOIN (public.ft2)) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r3.c1, r3.c2, r3.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r4.c1, r4.c2, r4.c3, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4.c1, r4.c2, r4.c3) END FROM ((("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r2."C 1" < 100)) AND ((r1."C 1" < 100)))) INNER JOIN "S 1"."T 3" r3 ON (((r1.c2 = r3.c1)))) INNER JOIN "S 1"."T 4" r4 ON (((r1.c2 = r4.c1)))) ORDER BY r1.c2 ASC NULLS LAST FOR UPDATE OF r1 FOR UPDATE OF r2 FOR UPDATE OF r3 FOR UPDATE OF r4
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Merge Cond: (ft1.c2 = ft5.c1)
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Merge Cond: (ft1.c2 = ft4.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Sort Key: ft1.c2
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Merge Cond: (ft1.c1 = ft2.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) FOR UPDATE
+ -> Materialize
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Sort
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Sort Key: ft4.c1
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" FOR UPDATE
+ -> Sort
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Sort Key: ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" FOR UPDATE
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+(47 rows)
+
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3 | c1 | c2 | c3
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+--------+----+----+--------+----+----+------
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+(10 rows)
+
+RESET enable_nestloop;
+RESET enable_hashjoin;
+-- test that add_paths_with_pathkeys_for_rel() arranges for the epq_path to
+-- return columns needed by the parent ForeignScan node
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.*, COALESCE(ft1.c3 || ft2.c3, 'foobar') FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100)) ss ON (local_tbl.c1 = ss.c1) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ -> Merge Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ Merge Cond: (local_tbl.c1 = ft1.c1)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text))
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c3 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r4."C 1" = r5."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4."C 1" ASC NULLS LAST
+ -> Result
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c3
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), ft2.c3
+ Sort Key: ft1.c1
+ -> Hash Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text), ft2.c3
+ Hash Cond: (ft1.c1 = ft2.c1)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Hash
+ Output: ft2.*, ft2.c1, ft2.c3
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(29 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD fdw_startup_cost '10000.0');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.* FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100 AND ft1.c1 = postgres_fdw_abs(ft2.c2))) ss ON (local_tbl.c3 = ss.c3) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ -> Nested Loop Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ Join Filter: (local_tbl.c3 = ft1.c3)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ Filter: (ft1.c1 = postgres_fdw_abs(ft2.c2))
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c2 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r4."C 1" = r5."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4.c3 ASC NULLS LAST
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Sort Key: ft1.c3
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Merge Cond: ((ft1.c1 = (postgres_fdw_abs(ft2.c2))) AND (ft1.c1 = ft2.c1))
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Sort
+ Output: ft2.*, ft2.c1, ft2.c2, (postgres_fdw_abs(ft2.c2))
+ Sort Key: (postgres_fdw_abs(ft2.c2)), ft2.c1
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, postgres_fdw_abs(ft2.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(32 rows)
+
+ALTER SERVER loopback OPTIONS (DROP fdw_startup_cost);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+DROP TABLE local_tbl;
+-- check join pushdown in situations where multiple userids are involved
+CREATE ROLE regress_view_owner SUPERUSER;
+CREATE USER MAPPING FOR regress_view_owner SERVER loopback;
+GRANT SELECT ON ft4 TO regress_view_owner;
+GRANT SELECT ON ft5 TO regress_view_owner;
+CREATE VIEW v4 AS SELECT * FROM ft4;
+CREATE VIEW v5 AS SELECT * FROM ft5;
+ALTER VIEW v5 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, different view owners
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, ft5.c2, ft5.c1
+ -> Sort
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Left Join
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.c2, ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c2, ft5.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r6.c1, r9.c2, r9.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r9 ON (((r6.c1 = r9.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r9.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, view owner not current user
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, t2.c2, t2.c1
+ -> Sort
+ Output: ft4.c1, t2.c2, t2.c1
+ Sort Key: ft4.c1, t2.c1
+ -> Hash Left Join
+ Output: ft4.c1, t2.c2, t2.c1
+ Hash Cond: (ft4.c1 = t2.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: t2.c2, t2.c1
+ -> Foreign Scan on public.ft5 t2
+ Output: t2.c2, t2.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO CURRENT_USER;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c2, t2.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r6.c1, r2.c2, r2.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r2 ON (((r6.c1 = r2.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+-- cleanup
+DROP OWNED BY regress_view_owner;
+DROP ROLE regress_view_owner;
+-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+------+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+ 100 | 49700 | 497.0000000000000000 | 2 | 992 | 0 | 49700
+ 100 | 49800 | 498.0000000000000000 | 3 | 993 | 0 | 49800
+ 100 | 49900 | 499.0000000000000000 | 4 | 994 | 0 | 49900
+ 100 | 50500 | 505.0000000000000000 | 0 | 1000 | 0 | 50500
+(5 rows)
+
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST LIMIT 1::bigint
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+-----+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+(1 row)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * (random() <= 1)::int) as sum, avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Aggregate
+ Output: sum((c1 * ((random() <= '1'::double precision))::integer)), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT count(*), sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ count | sum | avg
+-------+---------+----------------------
+ 10000 | 5010000 | 501.0000000000000000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where ((t1.c1 * t2.c1)/(t1.c1 * t2.c1)) * random() <= 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(t1.c1), count(t2.c1)
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Filter: (((((t1.c1 * t2.c1) / (t1.c1 * t2.c1)))::double precision * random()) <= '1'::double precision)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY 1 ORDER BY (c2 / 2) ASC NULLS LAST
+(4 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 500
+ 2 | 1800
+ 3 | 3900
+ 4 | 6800
+(5 rows)
+
+-- Aggregates in subquery are pushed down.
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 ORDER BY c2 ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(6 rows)
+
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+------
+ 1000 | 4500
+(1 row)
+
+-- Aggregate is still pushed down by taking unshippable expression out
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer)), ((sum(c1) * c2)), c2
+ Sort Key: ((ft1.c2 * ((random() <= '1'::double precision))::integer)), ((sum(ft1.c1) * ft1.c2))
+ -> Foreign Scan
+ Output: (c2 * ((random() <= '1'::double precision))::integer), ((sum(c1) * c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum("C 1") * c2), c2 FROM "S 1"."T 1" GROUP BY 2
+(7 rows)
+
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ sum1 | sum2
+------+--------
+ 0 | 0
+ 1 | 49600
+ 2 | 99400
+ 3 | 149400
+ 4 | 199600
+ 5 | 250000
+ 6 | 300600
+ 7 | 351400
+ 8 | 402400
+ 9 | 453600
+(10 rows)
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::int order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Sort Key: ((ft2.c2 * ((random() <= '1'::double precision))::integer))
+ -> HashAggregate
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Group Key: (ft2.c2 * ((random() <= '1'::double precision))::integer)
+ -> Foreign Scan on public.ft2
+ Output: (c2 * ((random() <= '1'::double precision))::integer)
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- GROUP BY clause in various forms, cardinal, alias and constant expression
+explain (verbose, costs off)
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), c2, 5, 7.0, 9 FROM "S 1"."T 1" GROUP BY 2, 3, 5
+(7 rows)
+
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ w | x | y | z
+-----+---+---+-----
+ 100 | 0 | 5 | 7.0
+ 100 | 1 | 5 | 7.0
+ 100 | 2 | 5 | 7.0
+ 100 | 3 | 5 | 7.0
+ 100 | 4 | 5 | 7.0
+ 100 | 5 | 5 | 7.0
+ 100 | 6 | 5 | 7.0
+ 100 | 7 | 5 | 7.0
+ 100 | 8 | 5 | 7.0
+ 100 | 9 | 5 | 7.0
+(10 rows)
+
+-- GROUP BY clause referring to same column multiple times
+-- Also, ORDER BY contains an aggregate function
+explain (verbose, costs off)
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, c2, (sum(c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, c2, sum("C 1") FROM "S 1"."T 1" WHERE ((c2 > 6)) GROUP BY 1, 2 ORDER BY sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ c2 | c2
+----+----
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(3 rows)
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 49800)) ORDER BY c2 ASC NULLS LAST
+(4 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ c2 | sum
+----+-------
+ 1 | 49600
+ 2 | 49700
+(2 rows)
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, NULL::bigint, (sqrt((ft1.c2)::double precision))
+ Filter: (((((avg(ft1.c1)) / (avg(ft1.c1))))::double precision * random()) <= '1'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ count
+-------
+ 49
+(1 row)
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * (random() <= 1)::int) > 100 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1)), c2
+ Sort Key: (sum(ft1.c1))
+ -> HashAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Filter: (avg((ft1.c1 * ((random() <= '1'::double precision))::integer)) > '100'::numeric)
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(10 rows)
+
+-- Remote aggregate in combination with a local Param (for the output
+-- of an initplan) can be trouble, per bug #15781
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ QUERY PLAN
+--------------------------------------------------
+ Foreign Scan
+ Output: $0, (sum(ft1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1"
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+(6 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ QUERY PLAN
+---------------------------------------------------
+ GroupAggregate
+ Output: ($0), sum(ft1.c1)
+ Group Key: $0
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+ -> Foreign Scan on public.ft1
+ Output: $0, ft1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(8 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY 2 ORDER BY array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1,11,21,31,41,51,61,71,81,91}
+ {2,12,22,32,42,52,62,72,82,92}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {5,15,25,35,45,55,65,75,85,95}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+(10 rows)
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5)) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY 2 ORDER BY sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))) ASC NULLS LAST
+(4 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+(10 rows)
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3) ORDER BY (("C 1" % 3)) ASC NULLS LAST) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY 3
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft2 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where (c1 / c1) * random() <= 1) from ft1 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((((ft1.c1 / ft1.c1))::double precision * random()) <= '1'::double precision)))
+ -> HashAggregate
+ Output: sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST), percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
+(7 rows)
+
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | rank | percentile_cont
+----+------+-----------------
+ 0 | 101 | 10
+ 1 | 101 | 100
+ 2 | 1 | 200
+ 3 | 1 | 300
+ 4 | 1 | 400
+(5 rows)
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY 1, 3
+(4 rows)
+
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ c1 | rank
+----+------
+ 6 | 1
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Disable hash aggregation for plan stability.
+set enable_hashagg to false;
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY 1
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 0 | 10
+ 1 | 1
+ 2 | 2
+ 3 | 3
+ 4 | 4
+ 5 | 5
+ 6 | 6
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(10 rows)
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Cleanup
+reset enable_hashagg;
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+create operator family my_op_family using btree;
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- This should not be pushed either.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- Update local stats on ft2
+ANALYZE ft2;
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now this will be pushed as sort operator is part of the extension.
+alter server loopback options (add fdw_tuple_cost '0.5');
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY 2
+(4 rows)
+
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+alter server loopback options (drop fdw_tuple_cost);
+-- This should be pushed too.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST
+(3 rows)
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft2 t1 left join ft2 t2 on (t1.c1 = random() * t2.c2);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop Left Join
+ Output: t1.c3
+ Join Filter: ((t1.c1)::double precision = (random() * (t2.c2)::double precision))
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c3, t1.c1
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1"
+ -> Materialize
+ Output: t2.c2
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(13 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Inner Unique: true
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1 ft1_1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1
+(21 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 100 | 49600
+ 100 | 49700
+ 100 | 49800
+ 100 | 49900
+ 100 | 50000
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(10 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY 3 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL))) ORDER BY avg(r1.c1) ASC NULLS LAST, sum(r2.c1) ASC NULLS LAST
+(4 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- Aggregate over FULL join needing to deparse the joining relations as
+-- subqueries.
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(ft4.c1)), (avg(ft5.c1))
+ Relations: Aggregate on ((public.ft4) FULL JOIN (public.ft5))
+ Remote SQL: SELECT count(*), sum(s4.c1), avg(s5.c1) FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ count | sum | avg
+-------+-----+---------------------
+ 8 | 330 | 55.5000000000000000
+(1 row)
+
+-- ORDER BY expression is part of the target list but not pushed down to
+-- foreign server.
+explain (verbose, costs off)
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: (((sum(c2)) * ((random() <= '1'::double precision))::integer))
+ Sort Key: (((sum(ft1.c2)) * ((random() <= '1'::double precision))::integer))
+ -> Foreign Scan
+ Output: ((sum(c2)) * ((random() <= '1'::double precision))::integer)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
+(7 rows)
+
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ sum
+------
+ 4500
+(1 row)
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c2, qry.sum
+ Sort Key: t1.c2
+ -> Nested Loop
+ Output: t1.c2, qry.sum
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Index Cond: (t1."C 1" < 100)
+ Filter: (t1.c2 < 3)
+ -> Subquery Scan on qry
+ Output: qry.sum, t2.c1
+ Filter: ((t1.c2 * 2) = qry.sum)
+ -> Foreign Scan
+ Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY 2
+(16 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ c2 | sum
+----+-----
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+reset enable_hashagg;
+-- bug #15613: bad plan for foreign table scan with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: ref_0.c2, ref_0."C 1", (ref_0.c2), ref_1.c3, ref_0."C 1"
+ -> Nested Loop
+ Output: ref_0.c2, ref_0."C 1", ref_1.c3, (ref_0.c2)
+ -> Index Scan using t1_pkey on "S 1"."T 1" ref_0
+ Output: ref_0."C 1", ref_0.c2, ref_0.c3, ref_0.c4, ref_0.c5, ref_0.c6, ref_0.c7, ref_0.c8
+ Index Cond: (ref_0."C 1" < 10)
+ -> Foreign Scan on public.ft1 ref_1
+ Output: ref_1.c3, ref_0.c2
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+ -> Materialize
+ Output: ref_3.c3
+ -> Foreign Scan on public.ft2 ref_3
+ Output: ref_3.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+(15 rows)
+
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ c2 | c1 | c2 | c3
+----+----+----+-------
+ 1 | 1 | 1 | 00001
+ 2 | 2 | 2 | 00001
+ 3 | 3 | 3 | 00001
+ 4 | 4 | 4 | 00001
+ 5 | 5 | 5 | 00001
+ 6 | 6 | 6 | 00001
+ 7 | 7 | 7 | 00001
+ 8 | 8 | 8 | 00001
+ 9 | 9 | 9 | 00001
+(9 rows)
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(q.a), count(q.b)
+ -> Nested Loop Left Join
+ Output: q.a, q.b
+ Inner Unique: true
+ Join Filter: ((ft4.c1)::numeric <= q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Materialize
+ Output: q.a, q.b
+ -> Subquery Scan on q
+ Output: q.a, q.b
+ -> Foreign Scan
+ Output: 13, (avg(ft1.c1)), NULL::bigint
+ Relations: Aggregate on ((public.ft2) LEFT JOIN (public.ft1))
+ Remote SQL: SELECT 13, avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1"))))
+(17 rows)
+
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ sum | count
+-----+-------
+ 650 | 50
+(1 row)
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: c2, c6, (sum(c1))
+ Sort Key: ft1.c2, ft1.c6
+ -> HashAggregate
+ Output: c2, c6, sum(c1)
+ Hash Key: ft1.c2
+ Hash Key: ft1.c6
+ -> Foreign Scan on public.ft1
+ Output: c2, c6, c1
+ Remote SQL: SELECT "C 1", c2, c6 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 0 | | 50500
+ 1 | | 49600
+ 2 | | 49700
+ | 0 | 50500
+ | 1 | 49600
+ | 2 | 49700
+(6 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1)), (GROUPING(c2))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, sum(c1), GROUPING(c2)
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(9 rows)
+
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 0 | 50500 | 0
+ 1 | 49600 | 0
+ 2 | 49700 | 0
+(3 rows)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((sum(c1) / 1000)), c2
+ -> Sort
+ Output: ((sum(c1) / 1000)), c2
+ Sort Key: ((sum(ft2.c1) / 1000))
+ -> Foreign Scan
+ Output: ((sum(c1) / 1000)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT (sum("C 1") / 1000), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY 2
+(9 rows)
+
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ s
+----
+ 49
+ 50
+(2 rows)
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2)), (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, (sum(c2)), count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ c2 | sum | count
+----+-----+-------
+ 0 | 0 | 5
+ 1 | 100 | 5
+ 2 | 200 | 5
+ 3 | 300 | 5
+ 4 | 400 | 5
+ 5 | 500 | 5
+ 6 | 600 | 5
+ 7 | 700 | 5
+ 8 | 800 | 5
+ 9 | 900 | 5
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2 DESC
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {8,6,4,2,0}
+ 1 | {9,7,5,3,1}
+ 2 | {8,6,4,2}
+ 3 | {9,7,5,3}
+ 4 | {8,6,4}
+ 5 | {9,7,5}
+ 6 | {8,6}
+ 7 | {9,7}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {0,2,4,6,8}
+ 1 | {1,3,5,7,9}
+ 2 | {2,4,6,8}
+ 3 | {3,5,7,9}
+ 4 | {4,6,8}
+ 5 | {5,7,9}
+ 6 | {6,8}
+ 7 | {7,9}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+-- ===================================================================
+-- parameterized queries
+-- ===================================================================
+-- simple join
+PREPARE st1(int, int) AS SELECT t1.c3, t2.c3 FROM ft1 t1, ft2 t2 WHERE t1.c1 = $1 AND t2.c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st1(1, 2);
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c3, t2.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.c3, r2.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 2)) AND ((r1."C 1" = 1))))
+(4 rows)
+
+EXECUTE st1(1, 1);
+ c3 | c3
+-------+-------
+ 00001 | 00001
+(1 row)
+
+EXECUTE st1(101, 101);
+ c3 | c3
+-------+-------
+ 00101 | 00101
+(1 row)
+
+-- subquery using stable function (can't be sent to remote)
+PREPARE st2(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c4) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st2(10, 20);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t1.c3 = t2.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Filter: (date(t2.c4) = '01-17-1970'::date)
+ Remote SQL: SELECT c3, c4 FROM "S 1"."T 1" WHERE (("C 1" > 10))
+(15 rows)
+
+EXECUTE st2(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st2(101, 121);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+-- subquery using immutable function (can be sent to remote)
+PREPARE st3(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c5) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st3(10, 20);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t1.c3 = t2.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" > 10)) AND ((date(c5) = '1970-01-17'::date))
+(14 rows)
+
+EXECUTE st3(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st3(20, 30);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- custom plan should be chosen initially
+PREPARE st4(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 = $1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+-- once we try it enough times, should switch to generic plan
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(3 rows)
+
+-- value of $1 should not be sent to remote
+PREPARE st5(user_enum,int) AS SELECT * FROM ft1 t1 WHERE c8 = $1 and c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = $1)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(4 rows)
+
+EXECUTE st5('foo', 1);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- altering FDW options requires replanning
+PREPARE st6 AS SELECT * FROM ft1 t1 WHERE t1.c1 = t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(3 rows)
+
+PREPARE st7 AS INSERT INTO ft1 (c1,c2,c3) VALUES (1001,101,'foo');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 1" RENAME TO "T 0";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 0');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 0" WHERE (("C 1" = c2))
+(3 rows)
+
+EXECUTE st6;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 0"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 0" RENAME TO "T 1";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 1');
+PREPARE st8 AS SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+EXECUTE st8;
+ count
+-------
+ 9
+(1 row)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- cleanup
+DEALLOCATE st1;
+DEALLOCATE st2;
+DEALLOCATE st3;
+DEALLOCATE st4;
+DEALLOCATE st5;
+DEALLOCATE st6;
+DEALLOCATE st7;
+DEALLOCATE st8;
+-- System columns, except ctid and oid, should not be sent to remote
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'pg_class'::regclass LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.tableoid = '1259'::oid)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'ft1'::regclass LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: (tableoid)::regclass, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ tableoid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ ft1 | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((ctid = '(0,2)'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: ctid, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ ctid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ (0,1) | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- ===================================================================
+-- used in PL/pgSQL function
+-- ===================================================================
+CREATE OR REPLACE FUNCTION f_test(p_c1 int) RETURNS int AS $$
+DECLARE
+ v_c1 int;
+BEGIN
+ SELECT c1 INTO v_c1 FROM ft1 WHERE c1 = p_c1 LIMIT 1;
+ PERFORM c1 FROM ft1 WHERE c1 = p_c1 AND p_c1 = v_c1 LIMIT 1;
+ RETURN v_c1;
+END;
+$$ LANGUAGE plpgsql;
+SELECT f_test(100);
+ f_test
+--------
+ 100
+(1 row)
+
+DROP FUNCTION f_test(int);
+-- ===================================================================
+-- REINDEX
+-- ===================================================================
+-- remote table is not created here
+CREATE FOREIGN TABLE reindex_foreign (c1 int, c2 int)
+ SERVER loopback2 OPTIONS (table_name 'reindex_local');
+REINDEX TABLE reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+REINDEX TABLE CONCURRENTLY reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+DROP FOREIGN TABLE reindex_foreign;
+-- partitions and foreign tables
+CREATE TABLE reind_fdw_parent (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE reind_fdw_0_10 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (0) TO (10);
+CREATE FOREIGN TABLE reind_fdw_10_20 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (10) TO (20)
+ SERVER loopback OPTIONS (table_name 'reind_local_10_20');
+REINDEX TABLE reind_fdw_parent; -- ok
+REINDEX TABLE CONCURRENTLY reind_fdw_parent; -- ok
+DROP TABLE reind_fdw_parent;
+-- ===================================================================
+-- conversion error
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int;
+SELECT * FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8) WHERE x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx.x8 FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: whole-row reference to foreign table "ftx"
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: processing expression at position 2 in select list
+ANALYZE ft1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "c8" of foreign table "ft1"
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- local type can be different from remote type in some cases,
+-- in particular if similarly-named operators do equivalent things
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE text;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 = 'foo')) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (('foo' = c8)) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- we declared c8 to be text locally, but it's still the same type on
+-- the remote which will balk if we try to do anything incompatible
+-- with that remote type
+SELECT * FROM ft1 WHERE c8 LIKE 'foo' LIMIT 1; -- ERROR
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+SELECT * FROM ft1 WHERE c8::text LIKE 'foo' LIMIT 1; -- ERROR; cast not pushed down
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- subtransaction
+-- + local/remote error doesn't break cursor
+-- ===================================================================
+BEGIN;
+DECLARE c CURSOR FOR SELECT * FROM ft1 ORDER BY c1;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+SAVEPOINT s;
+ERROR OUT; -- ERROR
+ERROR: syntax error at or near "ERROR"
+LINE 1: ERROR OUT;
+ ^
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+SAVEPOINT s;
+SELECT * FROM ft1 WHERE 1 / (c1 - 1) > 0; -- ERROR
+ERROR: division by zero
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (((1 / ("C 1" - 1)) > 0))
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c1 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+COMMIT;
+-- ===================================================================
+-- test handling of collations
+-- ===================================================================
+create table loct3 (f1 text collate "C" unique, f2 text, f3 varchar(10) unique);
+create foreign table ft3 (f1 text collate "C", f2 text, f3 varchar(10))
+ server loopback options (table_name 'loct3', use_remote_estimate 'true');
+-- can be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "C" = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f2 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f3 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 and l.f1 = 'foo';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE (($1::character varying(10) = f3))
+(8 rows)
+
+-- can't be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "POSIX" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f1)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f1 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 COLLATE "C" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f2)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f2 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 COLLATE "POSIX" and l.f1 = 'foo';
+ QUERY PLAN
+-------------------------------------------------------------
+ Hash Join
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ Inner Unique: true
+ Hash Cond: ((f.f3)::text = (l.f3)::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+ -> Hash
+ Output: l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+(12 rows)
+
+-- ===================================================================
+-- test writable foreign table stuff
+-- ===================================================================
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Subquery Scan on "*SELECT*"
+ Output: "*SELECT*"."?column?", "*SELECT*"."?column?_1", NULL::integer, "*SELECT*"."?column?_2", NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+ -> Foreign Scan on public.ft2 ft2_1
+ Output: (ft2_1.c1 + 1000), (ft2_1.c2 + 100), (ft2_1.c3 || ft2_1.c3)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" LIMIT 20::bigint
+(8 rows)
+
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+INSERT INTO ft2 (c1,c2,c3)
+ VALUES (1101,201,'aaa'), (1102,202,'bbb'), (1103,203,'ccc') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----+----+----+----+------------+----
+ 1101 | 201 | aaa | | | | ft2 |
+ 1102 | 202 | bbb | | | | ft2 |
+ 1103 | 203 | ccc | | | | ft2 |
+(3 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1104,204,'ddd'), (1105,205,'eee');
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 300), c3 = (c3 || '_update3') WHERE ((("C 1" % 10) = 3))
+(3 rows)
+
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 400), c3 = (c3 || '_update7') WHERE ((("C 1" % 10) = 7)) RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+(4 rows)
+
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+----+------------+-----
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 1007 | 507 | 0000700007_update7 | | | | ft2 |
+ 1017 | 507 | 0001700017_update7 | | | | ft2 |
+(102 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9; -- can be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c2 = (r1.c2 + 500), c3 = (r1.c3 || '_update9'), c7 = 'ft2 '::character(10) FROM "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 9))
+(3 rows)
+
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9;
+EXPLAIN (verbose, costs off)
+ DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: c1, c4
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 5)) RETURNING "C 1", c4
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4;
+ c1 | c4
+------+------------------------------
+ 5 | Tue Jan 06 00:00:00 1970 PST
+ 15 | Fri Jan 16 00:00:00 1970 PST
+ 25 | Mon Jan 26 00:00:00 1970 PST
+ 35 | Thu Feb 05 00:00:00 1970 PST
+ 45 | Sun Feb 15 00:00:00 1970 PST
+ 55 | Wed Feb 25 00:00:00 1970 PST
+ 65 | Sat Mar 07 00:00:00 1970 PST
+ 75 | Tue Mar 17 00:00:00 1970 PST
+ 85 | Fri Mar 27 00:00:00 1970 PST
+ 95 | Mon Apr 06 00:00:00 1970 PST
+ 105 | Tue Jan 06 00:00:00 1970 PST
+ 115 | Fri Jan 16 00:00:00 1970 PST
+ 125 | Mon Jan 26 00:00:00 1970 PST
+ 135 | Thu Feb 05 00:00:00 1970 PST
+ 145 | Sun Feb 15 00:00:00 1970 PST
+ 155 | Wed Feb 25 00:00:00 1970 PST
+ 165 | Sat Mar 07 00:00:00 1970 PST
+ 175 | Tue Mar 17 00:00:00 1970 PST
+ 185 | Fri Mar 27 00:00:00 1970 PST
+ 195 | Mon Apr 06 00:00:00 1970 PST
+ 205 | Tue Jan 06 00:00:00 1970 PST
+ 215 | Fri Jan 16 00:00:00 1970 PST
+ 225 | Mon Jan 26 00:00:00 1970 PST
+ 235 | Thu Feb 05 00:00:00 1970 PST
+ 245 | Sun Feb 15 00:00:00 1970 PST
+ 255 | Wed Feb 25 00:00:00 1970 PST
+ 265 | Sat Mar 07 00:00:00 1970 PST
+ 275 | Tue Mar 17 00:00:00 1970 PST
+ 285 | Fri Mar 27 00:00:00 1970 PST
+ 295 | Mon Apr 06 00:00:00 1970 PST
+ 305 | Tue Jan 06 00:00:00 1970 PST
+ 315 | Fri Jan 16 00:00:00 1970 PST
+ 325 | Mon Jan 26 00:00:00 1970 PST
+ 335 | Thu Feb 05 00:00:00 1970 PST
+ 345 | Sun Feb 15 00:00:00 1970 PST
+ 355 | Wed Feb 25 00:00:00 1970 PST
+ 365 | Sat Mar 07 00:00:00 1970 PST
+ 375 | Tue Mar 17 00:00:00 1970 PST
+ 385 | Fri Mar 27 00:00:00 1970 PST
+ 395 | Mon Apr 06 00:00:00 1970 PST
+ 405 | Tue Jan 06 00:00:00 1970 PST
+ 415 | Fri Jan 16 00:00:00 1970 PST
+ 425 | Mon Jan 26 00:00:00 1970 PST
+ 435 | Thu Feb 05 00:00:00 1970 PST
+ 445 | Sun Feb 15 00:00:00 1970 PST
+ 455 | Wed Feb 25 00:00:00 1970 PST
+ 465 | Sat Mar 07 00:00:00 1970 PST
+ 475 | Tue Mar 17 00:00:00 1970 PST
+ 485 | Fri Mar 27 00:00:00 1970 PST
+ 495 | Mon Apr 06 00:00:00 1970 PST
+ 505 | Tue Jan 06 00:00:00 1970 PST
+ 515 | Fri Jan 16 00:00:00 1970 PST
+ 525 | Mon Jan 26 00:00:00 1970 PST
+ 535 | Thu Feb 05 00:00:00 1970 PST
+ 545 | Sun Feb 15 00:00:00 1970 PST
+ 555 | Wed Feb 25 00:00:00 1970 PST
+ 565 | Sat Mar 07 00:00:00 1970 PST
+ 575 | Tue Mar 17 00:00:00 1970 PST
+ 585 | Fri Mar 27 00:00:00 1970 PST
+ 595 | Mon Apr 06 00:00:00 1970 PST
+ 605 | Tue Jan 06 00:00:00 1970 PST
+ 615 | Fri Jan 16 00:00:00 1970 PST
+ 625 | Mon Jan 26 00:00:00 1970 PST
+ 635 | Thu Feb 05 00:00:00 1970 PST
+ 645 | Sun Feb 15 00:00:00 1970 PST
+ 655 | Wed Feb 25 00:00:00 1970 PST
+ 665 | Sat Mar 07 00:00:00 1970 PST
+ 675 | Tue Mar 17 00:00:00 1970 PST
+ 685 | Fri Mar 27 00:00:00 1970 PST
+ 695 | Mon Apr 06 00:00:00 1970 PST
+ 705 | Tue Jan 06 00:00:00 1970 PST
+ 715 | Fri Jan 16 00:00:00 1970 PST
+ 725 | Mon Jan 26 00:00:00 1970 PST
+ 735 | Thu Feb 05 00:00:00 1970 PST
+ 745 | Sun Feb 15 00:00:00 1970 PST
+ 755 | Wed Feb 25 00:00:00 1970 PST
+ 765 | Sat Mar 07 00:00:00 1970 PST
+ 775 | Tue Mar 17 00:00:00 1970 PST
+ 785 | Fri Mar 27 00:00:00 1970 PST
+ 795 | Mon Apr 06 00:00:00 1970 PST
+ 805 | Tue Jan 06 00:00:00 1970 PST
+ 815 | Fri Jan 16 00:00:00 1970 PST
+ 825 | Mon Jan 26 00:00:00 1970 PST
+ 835 | Thu Feb 05 00:00:00 1970 PST
+ 845 | Sun Feb 15 00:00:00 1970 PST
+ 855 | Wed Feb 25 00:00:00 1970 PST
+ 865 | Sat Mar 07 00:00:00 1970 PST
+ 875 | Tue Mar 17 00:00:00 1970 PST
+ 885 | Fri Mar 27 00:00:00 1970 PST
+ 895 | Mon Apr 06 00:00:00 1970 PST
+ 905 | Tue Jan 06 00:00:00 1970 PST
+ 915 | Fri Jan 16 00:00:00 1970 PST
+ 925 | Mon Jan 26 00:00:00 1970 PST
+ 935 | Thu Feb 05 00:00:00 1970 PST
+ 945 | Sun Feb 15 00:00:00 1970 PST
+ 955 | Wed Feb 25 00:00:00 1970 PST
+ 965 | Sat Mar 07 00:00:00 1970 PST
+ 975 | Tue Mar 17 00:00:00 1970 PST
+ 985 | Fri Mar 27 00:00:00 1970 PST
+ 995 | Mon Apr 06 00:00:00 1970 PST
+ 1005 |
+ 1015 |
+ 1105 |
+(103 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 2))
+(3 rows)
+
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2;
+SELECT c1,c2,c3,c4 FROM ft2 ORDER BY c1;
+ c1 | c2 | c3 | c4
+------+-----+--------------------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 3 | 303 | 00003_update3 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+ 11 | 1 | 00011 | Mon Jan 12 00:00:00 1970 PST
+ 13 | 303 | 00013_update3 | Wed Jan 14 00:00:00 1970 PST
+ 14 | 4 | 00014 | Thu Jan 15 00:00:00 1970 PST
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST
+ 18 | 8 | 00018 | Mon Jan 19 00:00:00 1970 PST
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST
+ 20 | 0 | 00020 | Wed Jan 21 00:00:00 1970 PST
+ 21 | 1 | 00021 | Thu Jan 22 00:00:00 1970 PST
+ 23 | 303 | 00023_update3 | Sat Jan 24 00:00:00 1970 PST
+ 24 | 4 | 00024 | Sun Jan 25 00:00:00 1970 PST
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST
+ 28 | 8 | 00028 | Thu Jan 29 00:00:00 1970 PST
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST
+ 30 | 0 | 00030 | Sat Jan 31 00:00:00 1970 PST
+ 31 | 1 | 00031 | Sun Feb 01 00:00:00 1970 PST
+ 33 | 303 | 00033_update3 | Tue Feb 03 00:00:00 1970 PST
+ 34 | 4 | 00034 | Wed Feb 04 00:00:00 1970 PST
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST
+ 38 | 8 | 00038 | Sun Feb 08 00:00:00 1970 PST
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST
+ 40 | 0 | 00040 | Tue Feb 10 00:00:00 1970 PST
+ 41 | 1 | 00041 | Wed Feb 11 00:00:00 1970 PST
+ 43 | 303 | 00043_update3 | Fri Feb 13 00:00:00 1970 PST
+ 44 | 4 | 00044 | Sat Feb 14 00:00:00 1970 PST
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST
+ 48 | 8 | 00048 | Wed Feb 18 00:00:00 1970 PST
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST
+ 50 | 0 | 00050 | Fri Feb 20 00:00:00 1970 PST
+ 51 | 1 | 00051 | Sat Feb 21 00:00:00 1970 PST
+ 53 | 303 | 00053_update3 | Mon Feb 23 00:00:00 1970 PST
+ 54 | 4 | 00054 | Tue Feb 24 00:00:00 1970 PST
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST
+ 58 | 8 | 00058 | Sat Feb 28 00:00:00 1970 PST
+ 59 | 509 | 00059_update9 | Sun Mar 01 00:00:00 1970 PST
+ 60 | 0 | 00060 | Mon Mar 02 00:00:00 1970 PST
+ 61 | 1 | 00061 | Tue Mar 03 00:00:00 1970 PST
+ 63 | 303 | 00063_update3 | Thu Mar 05 00:00:00 1970 PST
+ 64 | 4 | 00064 | Fri Mar 06 00:00:00 1970 PST
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST
+ 68 | 8 | 00068 | Tue Mar 10 00:00:00 1970 PST
+ 69 | 509 | 00069_update9 | Wed Mar 11 00:00:00 1970 PST
+ 70 | 0 | 00070 | Thu Mar 12 00:00:00 1970 PST
+ 71 | 1 | 00071 | Fri Mar 13 00:00:00 1970 PST
+ 73 | 303 | 00073_update3 | Sun Mar 15 00:00:00 1970 PST
+ 74 | 4 | 00074 | Mon Mar 16 00:00:00 1970 PST
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST
+ 78 | 8 | 00078 | Fri Mar 20 00:00:00 1970 PST
+ 79 | 509 | 00079_update9 | Sat Mar 21 00:00:00 1970 PST
+ 80 | 0 | 00080 | Sun Mar 22 00:00:00 1970 PST
+ 81 | 1 | 00081 | Mon Mar 23 00:00:00 1970 PST
+ 83 | 303 | 00083_update3 | Wed Mar 25 00:00:00 1970 PST
+ 84 | 4 | 00084 | Thu Mar 26 00:00:00 1970 PST
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST
+ 88 | 8 | 00088 | Mon Mar 30 00:00:00 1970 PST
+ 89 | 509 | 00089_update9 | Tue Mar 31 00:00:00 1970 PST
+ 90 | 0 | 00090 | Wed Apr 01 00:00:00 1970 PST
+ 91 | 1 | 00091 | Thu Apr 02 00:00:00 1970 PST
+ 93 | 303 | 00093_update3 | Sat Apr 04 00:00:00 1970 PST
+ 94 | 4 | 00094 | Sun Apr 05 00:00:00 1970 PST
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST
+ 98 | 8 | 00098 | Thu Apr 09 00:00:00 1970 PST
+ 99 | 509 | 00099_update9 | Fri Apr 10 00:00:00 1970 PST
+ 100 | 0 | 00100 | Thu Jan 01 00:00:00 1970 PST
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST
+ 103 | 303 | 00103_update3 | Sun Jan 04 00:00:00 1970 PST
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST
+ 109 | 509 | 00109_update9 | Sat Jan 10 00:00:00 1970 PST
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST
+ 111 | 1 | 00111 | Mon Jan 12 00:00:00 1970 PST
+ 113 | 303 | 00113_update3 | Wed Jan 14 00:00:00 1970 PST
+ 114 | 4 | 00114 | Thu Jan 15 00:00:00 1970 PST
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST
+ 118 | 8 | 00118 | Mon Jan 19 00:00:00 1970 PST
+ 119 | 509 | 00119_update9 | Tue Jan 20 00:00:00 1970 PST
+ 120 | 0 | 00120 | Wed Jan 21 00:00:00 1970 PST
+ 121 | 1 | 00121 | Thu Jan 22 00:00:00 1970 PST
+ 123 | 303 | 00123_update3 | Sat Jan 24 00:00:00 1970 PST
+ 124 | 4 | 00124 | Sun Jan 25 00:00:00 1970 PST
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST
+ 128 | 8 | 00128 | Thu Jan 29 00:00:00 1970 PST
+ 129 | 509 | 00129_update9 | Fri Jan 30 00:00:00 1970 PST
+ 130 | 0 | 00130 | Sat Jan 31 00:00:00 1970 PST
+ 131 | 1 | 00131 | Sun Feb 01 00:00:00 1970 PST
+ 133 | 303 | 00133_update3 | Tue Feb 03 00:00:00 1970 PST
+ 134 | 4 | 00134 | Wed Feb 04 00:00:00 1970 PST
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST
+ 138 | 8 | 00138 | Sun Feb 08 00:00:00 1970 PST
+ 139 | 509 | 00139_update9 | Mon Feb 09 00:00:00 1970 PST
+ 140 | 0 | 00140 | Tue Feb 10 00:00:00 1970 PST
+ 141 | 1 | 00141 | Wed Feb 11 00:00:00 1970 PST
+ 143 | 303 | 00143_update3 | Fri Feb 13 00:00:00 1970 PST
+ 144 | 4 | 00144 | Sat Feb 14 00:00:00 1970 PST
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST
+ 148 | 8 | 00148 | Wed Feb 18 00:00:00 1970 PST
+ 149 | 509 | 00149_update9 | Thu Feb 19 00:00:00 1970 PST
+ 150 | 0 | 00150 | Fri Feb 20 00:00:00 1970 PST
+ 151 | 1 | 00151 | Sat Feb 21 00:00:00 1970 PST
+ 153 | 303 | 00153_update3 | Mon Feb 23 00:00:00 1970 PST
+ 154 | 4 | 00154 | Tue Feb 24 00:00:00 1970 PST
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST
+ 158 | 8 | 00158 | Sat Feb 28 00:00:00 1970 PST
+ 159 | 509 | 00159_update9 | Sun Mar 01 00:00:00 1970 PST
+ 160 | 0 | 00160 | Mon Mar 02 00:00:00 1970 PST
+ 161 | 1 | 00161 | Tue Mar 03 00:00:00 1970 PST
+ 163 | 303 | 00163_update3 | Thu Mar 05 00:00:00 1970 PST
+ 164 | 4 | 00164 | Fri Mar 06 00:00:00 1970 PST
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST
+ 168 | 8 | 00168 | Tue Mar 10 00:00:00 1970 PST
+ 169 | 509 | 00169_update9 | Wed Mar 11 00:00:00 1970 PST
+ 170 | 0 | 00170 | Thu Mar 12 00:00:00 1970 PST
+ 171 | 1 | 00171 | Fri Mar 13 00:00:00 1970 PST
+ 173 | 303 | 00173_update3 | Sun Mar 15 00:00:00 1970 PST
+ 174 | 4 | 00174 | Mon Mar 16 00:00:00 1970 PST
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST
+ 178 | 8 | 00178 | Fri Mar 20 00:00:00 1970 PST
+ 179 | 509 | 00179_update9 | Sat Mar 21 00:00:00 1970 PST
+ 180 | 0 | 00180 | Sun Mar 22 00:00:00 1970 PST
+ 181 | 1 | 00181 | Mon Mar 23 00:00:00 1970 PST
+ 183 | 303 | 00183_update3 | Wed Mar 25 00:00:00 1970 PST
+ 184 | 4 | 00184 | Thu Mar 26 00:00:00 1970 PST
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST
+ 188 | 8 | 00188 | Mon Mar 30 00:00:00 1970 PST
+ 189 | 509 | 00189_update9 | Tue Mar 31 00:00:00 1970 PST
+ 190 | 0 | 00190 | Wed Apr 01 00:00:00 1970 PST
+ 191 | 1 | 00191 | Thu Apr 02 00:00:00 1970 PST
+ 193 | 303 | 00193_update3 | Sat Apr 04 00:00:00 1970 PST
+ 194 | 4 | 00194 | Sun Apr 05 00:00:00 1970 PST
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST
+ 198 | 8 | 00198 | Thu Apr 09 00:00:00 1970 PST
+ 199 | 509 | 00199_update9 | Fri Apr 10 00:00:00 1970 PST
+ 200 | 0 | 00200 | Thu Jan 01 00:00:00 1970 PST
+ 201 | 1 | 00201 | Fri Jan 02 00:00:00 1970 PST
+ 203 | 303 | 00203_update3 | Sun Jan 04 00:00:00 1970 PST
+ 204 | 4 | 00204 | Mon Jan 05 00:00:00 1970 PST
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST
+ 208 | 8 | 00208 | Fri Jan 09 00:00:00 1970 PST
+ 209 | 509 | 00209_update9 | Sat Jan 10 00:00:00 1970 PST
+ 210 | 0 | 00210 | Sun Jan 11 00:00:00 1970 PST
+ 211 | 1 | 00211 | Mon Jan 12 00:00:00 1970 PST
+ 213 | 303 | 00213_update3 | Wed Jan 14 00:00:00 1970 PST
+ 214 | 4 | 00214 | Thu Jan 15 00:00:00 1970 PST
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST
+ 218 | 8 | 00218 | Mon Jan 19 00:00:00 1970 PST
+ 219 | 509 | 00219_update9 | Tue Jan 20 00:00:00 1970 PST
+ 220 | 0 | 00220 | Wed Jan 21 00:00:00 1970 PST
+ 221 | 1 | 00221 | Thu Jan 22 00:00:00 1970 PST
+ 223 | 303 | 00223_update3 | Sat Jan 24 00:00:00 1970 PST
+ 224 | 4 | 00224 | Sun Jan 25 00:00:00 1970 PST
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST
+ 228 | 8 | 00228 | Thu Jan 29 00:00:00 1970 PST
+ 229 | 509 | 00229_update9 | Fri Jan 30 00:00:00 1970 PST
+ 230 | 0 | 00230 | Sat Jan 31 00:00:00 1970 PST
+ 231 | 1 | 00231 | Sun Feb 01 00:00:00 1970 PST
+ 233 | 303 | 00233_update3 | Tue Feb 03 00:00:00 1970 PST
+ 234 | 4 | 00234 | Wed Feb 04 00:00:00 1970 PST
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST
+ 238 | 8 | 00238 | Sun Feb 08 00:00:00 1970 PST
+ 239 | 509 | 00239_update9 | Mon Feb 09 00:00:00 1970 PST
+ 240 | 0 | 00240 | Tue Feb 10 00:00:00 1970 PST
+ 241 | 1 | 00241 | Wed Feb 11 00:00:00 1970 PST
+ 243 | 303 | 00243_update3 | Fri Feb 13 00:00:00 1970 PST
+ 244 | 4 | 00244 | Sat Feb 14 00:00:00 1970 PST
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST
+ 248 | 8 | 00248 | Wed Feb 18 00:00:00 1970 PST
+ 249 | 509 | 00249_update9 | Thu Feb 19 00:00:00 1970 PST
+ 250 | 0 | 00250 | Fri Feb 20 00:00:00 1970 PST
+ 251 | 1 | 00251 | Sat Feb 21 00:00:00 1970 PST
+ 253 | 303 | 00253_update3 | Mon Feb 23 00:00:00 1970 PST
+ 254 | 4 | 00254 | Tue Feb 24 00:00:00 1970 PST
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST
+ 258 | 8 | 00258 | Sat Feb 28 00:00:00 1970 PST
+ 259 | 509 | 00259_update9 | Sun Mar 01 00:00:00 1970 PST
+ 260 | 0 | 00260 | Mon Mar 02 00:00:00 1970 PST
+ 261 | 1 | 00261 | Tue Mar 03 00:00:00 1970 PST
+ 263 | 303 | 00263_update3 | Thu Mar 05 00:00:00 1970 PST
+ 264 | 4 | 00264 | Fri Mar 06 00:00:00 1970 PST
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST
+ 268 | 8 | 00268 | Tue Mar 10 00:00:00 1970 PST
+ 269 | 509 | 00269_update9 | Wed Mar 11 00:00:00 1970 PST
+ 270 | 0 | 00270 | Thu Mar 12 00:00:00 1970 PST
+ 271 | 1 | 00271 | Fri Mar 13 00:00:00 1970 PST
+ 273 | 303 | 00273_update3 | Sun Mar 15 00:00:00 1970 PST
+ 274 | 4 | 00274 | Mon Mar 16 00:00:00 1970 PST
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST
+ 278 | 8 | 00278 | Fri Mar 20 00:00:00 1970 PST
+ 279 | 509 | 00279_update9 | Sat Mar 21 00:00:00 1970 PST
+ 280 | 0 | 00280 | Sun Mar 22 00:00:00 1970 PST
+ 281 | 1 | 00281 | Mon Mar 23 00:00:00 1970 PST
+ 283 | 303 | 00283_update3 | Wed Mar 25 00:00:00 1970 PST
+ 284 | 4 | 00284 | Thu Mar 26 00:00:00 1970 PST
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST
+ 288 | 8 | 00288 | Mon Mar 30 00:00:00 1970 PST
+ 289 | 509 | 00289_update9 | Tue Mar 31 00:00:00 1970 PST
+ 290 | 0 | 00290 | Wed Apr 01 00:00:00 1970 PST
+ 291 | 1 | 00291 | Thu Apr 02 00:00:00 1970 PST
+ 293 | 303 | 00293_update3 | Sat Apr 04 00:00:00 1970 PST
+ 294 | 4 | 00294 | Sun Apr 05 00:00:00 1970 PST
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST
+ 298 | 8 | 00298 | Thu Apr 09 00:00:00 1970 PST
+ 299 | 509 | 00299_update9 | Fri Apr 10 00:00:00 1970 PST
+ 300 | 0 | 00300 | Thu Jan 01 00:00:00 1970 PST
+ 301 | 1 | 00301 | Fri Jan 02 00:00:00 1970 PST
+ 303 | 303 | 00303_update3 | Sun Jan 04 00:00:00 1970 PST
+ 304 | 4 | 00304 | Mon Jan 05 00:00:00 1970 PST
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST
+ 308 | 8 | 00308 | Fri Jan 09 00:00:00 1970 PST
+ 309 | 509 | 00309_update9 | Sat Jan 10 00:00:00 1970 PST
+ 310 | 0 | 00310 | Sun Jan 11 00:00:00 1970 PST
+ 311 | 1 | 00311 | Mon Jan 12 00:00:00 1970 PST
+ 313 | 303 | 00313_update3 | Wed Jan 14 00:00:00 1970 PST
+ 314 | 4 | 00314 | Thu Jan 15 00:00:00 1970 PST
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST
+ 318 | 8 | 00318 | Mon Jan 19 00:00:00 1970 PST
+ 319 | 509 | 00319_update9 | Tue Jan 20 00:00:00 1970 PST
+ 320 | 0 | 00320 | Wed Jan 21 00:00:00 1970 PST
+ 321 | 1 | 00321 | Thu Jan 22 00:00:00 1970 PST
+ 323 | 303 | 00323_update3 | Sat Jan 24 00:00:00 1970 PST
+ 324 | 4 | 00324 | Sun Jan 25 00:00:00 1970 PST
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST
+ 328 | 8 | 00328 | Thu Jan 29 00:00:00 1970 PST
+ 329 | 509 | 00329_update9 | Fri Jan 30 00:00:00 1970 PST
+ 330 | 0 | 00330 | Sat Jan 31 00:00:00 1970 PST
+ 331 | 1 | 00331 | Sun Feb 01 00:00:00 1970 PST
+ 333 | 303 | 00333_update3 | Tue Feb 03 00:00:00 1970 PST
+ 334 | 4 | 00334 | Wed Feb 04 00:00:00 1970 PST
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST
+ 338 | 8 | 00338 | Sun Feb 08 00:00:00 1970 PST
+ 339 | 509 | 00339_update9 | Mon Feb 09 00:00:00 1970 PST
+ 340 | 0 | 00340 | Tue Feb 10 00:00:00 1970 PST
+ 341 | 1 | 00341 | Wed Feb 11 00:00:00 1970 PST
+ 343 | 303 | 00343_update3 | Fri Feb 13 00:00:00 1970 PST
+ 344 | 4 | 00344 | Sat Feb 14 00:00:00 1970 PST
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST
+ 348 | 8 | 00348 | Wed Feb 18 00:00:00 1970 PST
+ 349 | 509 | 00349_update9 | Thu Feb 19 00:00:00 1970 PST
+ 350 | 0 | 00350 | Fri Feb 20 00:00:00 1970 PST
+ 351 | 1 | 00351 | Sat Feb 21 00:00:00 1970 PST
+ 353 | 303 | 00353_update3 | Mon Feb 23 00:00:00 1970 PST
+ 354 | 4 | 00354 | Tue Feb 24 00:00:00 1970 PST
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST
+ 358 | 8 | 00358 | Sat Feb 28 00:00:00 1970 PST
+ 359 | 509 | 00359_update9 | Sun Mar 01 00:00:00 1970 PST
+ 360 | 0 | 00360 | Mon Mar 02 00:00:00 1970 PST
+ 361 | 1 | 00361 | Tue Mar 03 00:00:00 1970 PST
+ 363 | 303 | 00363_update3 | Thu Mar 05 00:00:00 1970 PST
+ 364 | 4 | 00364 | Fri Mar 06 00:00:00 1970 PST
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST
+ 368 | 8 | 00368 | Tue Mar 10 00:00:00 1970 PST
+ 369 | 509 | 00369_update9 | Wed Mar 11 00:00:00 1970 PST
+ 370 | 0 | 00370 | Thu Mar 12 00:00:00 1970 PST
+ 371 | 1 | 00371 | Fri Mar 13 00:00:00 1970 PST
+ 373 | 303 | 00373_update3 | Sun Mar 15 00:00:00 1970 PST
+ 374 | 4 | 00374 | Mon Mar 16 00:00:00 1970 PST
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST
+ 378 | 8 | 00378 | Fri Mar 20 00:00:00 1970 PST
+ 379 | 509 | 00379_update9 | Sat Mar 21 00:00:00 1970 PST
+ 380 | 0 | 00380 | Sun Mar 22 00:00:00 1970 PST
+ 381 | 1 | 00381 | Mon Mar 23 00:00:00 1970 PST
+ 383 | 303 | 00383_update3 | Wed Mar 25 00:00:00 1970 PST
+ 384 | 4 | 00384 | Thu Mar 26 00:00:00 1970 PST
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST
+ 388 | 8 | 00388 | Mon Mar 30 00:00:00 1970 PST
+ 389 | 509 | 00389_update9 | Tue Mar 31 00:00:00 1970 PST
+ 390 | 0 | 00390 | Wed Apr 01 00:00:00 1970 PST
+ 391 | 1 | 00391 | Thu Apr 02 00:00:00 1970 PST
+ 393 | 303 | 00393_update3 | Sat Apr 04 00:00:00 1970 PST
+ 394 | 4 | 00394 | Sun Apr 05 00:00:00 1970 PST
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST
+ 398 | 8 | 00398 | Thu Apr 09 00:00:00 1970 PST
+ 399 | 509 | 00399_update9 | Fri Apr 10 00:00:00 1970 PST
+ 400 | 0 | 00400 | Thu Jan 01 00:00:00 1970 PST
+ 401 | 1 | 00401 | Fri Jan 02 00:00:00 1970 PST
+ 403 | 303 | 00403_update3 | Sun Jan 04 00:00:00 1970 PST
+ 404 | 4 | 00404 | Mon Jan 05 00:00:00 1970 PST
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST
+ 408 | 8 | 00408 | Fri Jan 09 00:00:00 1970 PST
+ 409 | 509 | 00409_update9 | Sat Jan 10 00:00:00 1970 PST
+ 410 | 0 | 00410 | Sun Jan 11 00:00:00 1970 PST
+ 411 | 1 | 00411 | Mon Jan 12 00:00:00 1970 PST
+ 413 | 303 | 00413_update3 | Wed Jan 14 00:00:00 1970 PST
+ 414 | 4 | 00414 | Thu Jan 15 00:00:00 1970 PST
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST
+ 418 | 8 | 00418 | Mon Jan 19 00:00:00 1970 PST
+ 419 | 509 | 00419_update9 | Tue Jan 20 00:00:00 1970 PST
+ 420 | 0 | 00420 | Wed Jan 21 00:00:00 1970 PST
+ 421 | 1 | 00421 | Thu Jan 22 00:00:00 1970 PST
+ 423 | 303 | 00423_update3 | Sat Jan 24 00:00:00 1970 PST
+ 424 | 4 | 00424 | Sun Jan 25 00:00:00 1970 PST
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST
+ 428 | 8 | 00428 | Thu Jan 29 00:00:00 1970 PST
+ 429 | 509 | 00429_update9 | Fri Jan 30 00:00:00 1970 PST
+ 430 | 0 | 00430 | Sat Jan 31 00:00:00 1970 PST
+ 431 | 1 | 00431 | Sun Feb 01 00:00:00 1970 PST
+ 433 | 303 | 00433_update3 | Tue Feb 03 00:00:00 1970 PST
+ 434 | 4 | 00434 | Wed Feb 04 00:00:00 1970 PST
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST
+ 438 | 8 | 00438 | Sun Feb 08 00:00:00 1970 PST
+ 439 | 509 | 00439_update9 | Mon Feb 09 00:00:00 1970 PST
+ 440 | 0 | 00440 | Tue Feb 10 00:00:00 1970 PST
+ 441 | 1 | 00441 | Wed Feb 11 00:00:00 1970 PST
+ 443 | 303 | 00443_update3 | Fri Feb 13 00:00:00 1970 PST
+ 444 | 4 | 00444 | Sat Feb 14 00:00:00 1970 PST
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST
+ 448 | 8 | 00448 | Wed Feb 18 00:00:00 1970 PST
+ 449 | 509 | 00449_update9 | Thu Feb 19 00:00:00 1970 PST
+ 450 | 0 | 00450 | Fri Feb 20 00:00:00 1970 PST
+ 451 | 1 | 00451 | Sat Feb 21 00:00:00 1970 PST
+ 453 | 303 | 00453_update3 | Mon Feb 23 00:00:00 1970 PST
+ 454 | 4 | 00454 | Tue Feb 24 00:00:00 1970 PST
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST
+ 458 | 8 | 00458 | Sat Feb 28 00:00:00 1970 PST
+ 459 | 509 | 00459_update9 | Sun Mar 01 00:00:00 1970 PST
+ 460 | 0 | 00460 | Mon Mar 02 00:00:00 1970 PST
+ 461 | 1 | 00461 | Tue Mar 03 00:00:00 1970 PST
+ 463 | 303 | 00463_update3 | Thu Mar 05 00:00:00 1970 PST
+ 464 | 4 | 00464 | Fri Mar 06 00:00:00 1970 PST
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST
+ 468 | 8 | 00468 | Tue Mar 10 00:00:00 1970 PST
+ 469 | 509 | 00469_update9 | Wed Mar 11 00:00:00 1970 PST
+ 470 | 0 | 00470 | Thu Mar 12 00:00:00 1970 PST
+ 471 | 1 | 00471 | Fri Mar 13 00:00:00 1970 PST
+ 473 | 303 | 00473_update3 | Sun Mar 15 00:00:00 1970 PST
+ 474 | 4 | 00474 | Mon Mar 16 00:00:00 1970 PST
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST
+ 478 | 8 | 00478 | Fri Mar 20 00:00:00 1970 PST
+ 479 | 509 | 00479_update9 | Sat Mar 21 00:00:00 1970 PST
+ 480 | 0 | 00480 | Sun Mar 22 00:00:00 1970 PST
+ 481 | 1 | 00481 | Mon Mar 23 00:00:00 1970 PST
+ 483 | 303 | 00483_update3 | Wed Mar 25 00:00:00 1970 PST
+ 484 | 4 | 00484 | Thu Mar 26 00:00:00 1970 PST
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST
+ 488 | 8 | 00488 | Mon Mar 30 00:00:00 1970 PST
+ 489 | 509 | 00489_update9 | Tue Mar 31 00:00:00 1970 PST
+ 490 | 0 | 00490 | Wed Apr 01 00:00:00 1970 PST
+ 491 | 1 | 00491 | Thu Apr 02 00:00:00 1970 PST
+ 493 | 303 | 00493_update3 | Sat Apr 04 00:00:00 1970 PST
+ 494 | 4 | 00494 | Sun Apr 05 00:00:00 1970 PST
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST
+ 498 | 8 | 00498 | Thu Apr 09 00:00:00 1970 PST
+ 499 | 509 | 00499_update9 | Fri Apr 10 00:00:00 1970 PST
+ 500 | 0 | 00500 | Thu Jan 01 00:00:00 1970 PST
+ 501 | 1 | 00501 | Fri Jan 02 00:00:00 1970 PST
+ 503 | 303 | 00503_update3 | Sun Jan 04 00:00:00 1970 PST
+ 504 | 4 | 00504 | Mon Jan 05 00:00:00 1970 PST
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST
+ 508 | 8 | 00508 | Fri Jan 09 00:00:00 1970 PST
+ 509 | 509 | 00509_update9 | Sat Jan 10 00:00:00 1970 PST
+ 510 | 0 | 00510 | Sun Jan 11 00:00:00 1970 PST
+ 511 | 1 | 00511 | Mon Jan 12 00:00:00 1970 PST
+ 513 | 303 | 00513_update3 | Wed Jan 14 00:00:00 1970 PST
+ 514 | 4 | 00514 | Thu Jan 15 00:00:00 1970 PST
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST
+ 518 | 8 | 00518 | Mon Jan 19 00:00:00 1970 PST
+ 519 | 509 | 00519_update9 | Tue Jan 20 00:00:00 1970 PST
+ 520 | 0 | 00520 | Wed Jan 21 00:00:00 1970 PST
+ 521 | 1 | 00521 | Thu Jan 22 00:00:00 1970 PST
+ 523 | 303 | 00523_update3 | Sat Jan 24 00:00:00 1970 PST
+ 524 | 4 | 00524 | Sun Jan 25 00:00:00 1970 PST
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST
+ 528 | 8 | 00528 | Thu Jan 29 00:00:00 1970 PST
+ 529 | 509 | 00529_update9 | Fri Jan 30 00:00:00 1970 PST
+ 530 | 0 | 00530 | Sat Jan 31 00:00:00 1970 PST
+ 531 | 1 | 00531 | Sun Feb 01 00:00:00 1970 PST
+ 533 | 303 | 00533_update3 | Tue Feb 03 00:00:00 1970 PST
+ 534 | 4 | 00534 | Wed Feb 04 00:00:00 1970 PST
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST
+ 538 | 8 | 00538 | Sun Feb 08 00:00:00 1970 PST
+ 539 | 509 | 00539_update9 | Mon Feb 09 00:00:00 1970 PST
+ 540 | 0 | 00540 | Tue Feb 10 00:00:00 1970 PST
+ 541 | 1 | 00541 | Wed Feb 11 00:00:00 1970 PST
+ 543 | 303 | 00543_update3 | Fri Feb 13 00:00:00 1970 PST
+ 544 | 4 | 00544 | Sat Feb 14 00:00:00 1970 PST
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST
+ 548 | 8 | 00548 | Wed Feb 18 00:00:00 1970 PST
+ 549 | 509 | 00549_update9 | Thu Feb 19 00:00:00 1970 PST
+ 550 | 0 | 00550 | Fri Feb 20 00:00:00 1970 PST
+ 551 | 1 | 00551 | Sat Feb 21 00:00:00 1970 PST
+ 553 | 303 | 00553_update3 | Mon Feb 23 00:00:00 1970 PST
+ 554 | 4 | 00554 | Tue Feb 24 00:00:00 1970 PST
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST
+ 558 | 8 | 00558 | Sat Feb 28 00:00:00 1970 PST
+ 559 | 509 | 00559_update9 | Sun Mar 01 00:00:00 1970 PST
+ 560 | 0 | 00560 | Mon Mar 02 00:00:00 1970 PST
+ 561 | 1 | 00561 | Tue Mar 03 00:00:00 1970 PST
+ 563 | 303 | 00563_update3 | Thu Mar 05 00:00:00 1970 PST
+ 564 | 4 | 00564 | Fri Mar 06 00:00:00 1970 PST
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST
+ 568 | 8 | 00568 | Tue Mar 10 00:00:00 1970 PST
+ 569 | 509 | 00569_update9 | Wed Mar 11 00:00:00 1970 PST
+ 570 | 0 | 00570 | Thu Mar 12 00:00:00 1970 PST
+ 571 | 1 | 00571 | Fri Mar 13 00:00:00 1970 PST
+ 573 | 303 | 00573_update3 | Sun Mar 15 00:00:00 1970 PST
+ 574 | 4 | 00574 | Mon Mar 16 00:00:00 1970 PST
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST
+ 578 | 8 | 00578 | Fri Mar 20 00:00:00 1970 PST
+ 579 | 509 | 00579_update9 | Sat Mar 21 00:00:00 1970 PST
+ 580 | 0 | 00580 | Sun Mar 22 00:00:00 1970 PST
+ 581 | 1 | 00581 | Mon Mar 23 00:00:00 1970 PST
+ 583 | 303 | 00583_update3 | Wed Mar 25 00:00:00 1970 PST
+ 584 | 4 | 00584 | Thu Mar 26 00:00:00 1970 PST
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST
+ 588 | 8 | 00588 | Mon Mar 30 00:00:00 1970 PST
+ 589 | 509 | 00589_update9 | Tue Mar 31 00:00:00 1970 PST
+ 590 | 0 | 00590 | Wed Apr 01 00:00:00 1970 PST
+ 591 | 1 | 00591 | Thu Apr 02 00:00:00 1970 PST
+ 593 | 303 | 00593_update3 | Sat Apr 04 00:00:00 1970 PST
+ 594 | 4 | 00594 | Sun Apr 05 00:00:00 1970 PST
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST
+ 598 | 8 | 00598 | Thu Apr 09 00:00:00 1970 PST
+ 599 | 509 | 00599_update9 | Fri Apr 10 00:00:00 1970 PST
+ 600 | 0 | 00600 | Thu Jan 01 00:00:00 1970 PST
+ 601 | 1 | 00601 | Fri Jan 02 00:00:00 1970 PST
+ 603 | 303 | 00603_update3 | Sun Jan 04 00:00:00 1970 PST
+ 604 | 4 | 00604 | Mon Jan 05 00:00:00 1970 PST
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST
+ 608 | 8 | 00608 | Fri Jan 09 00:00:00 1970 PST
+ 609 | 509 | 00609_update9 | Sat Jan 10 00:00:00 1970 PST
+ 610 | 0 | 00610 | Sun Jan 11 00:00:00 1970 PST
+ 611 | 1 | 00611 | Mon Jan 12 00:00:00 1970 PST
+ 613 | 303 | 00613_update3 | Wed Jan 14 00:00:00 1970 PST
+ 614 | 4 | 00614 | Thu Jan 15 00:00:00 1970 PST
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST
+ 618 | 8 | 00618 | Mon Jan 19 00:00:00 1970 PST
+ 619 | 509 | 00619_update9 | Tue Jan 20 00:00:00 1970 PST
+ 620 | 0 | 00620 | Wed Jan 21 00:00:00 1970 PST
+ 621 | 1 | 00621 | Thu Jan 22 00:00:00 1970 PST
+ 623 | 303 | 00623_update3 | Sat Jan 24 00:00:00 1970 PST
+ 624 | 4 | 00624 | Sun Jan 25 00:00:00 1970 PST
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST
+ 628 | 8 | 00628 | Thu Jan 29 00:00:00 1970 PST
+ 629 | 509 | 00629_update9 | Fri Jan 30 00:00:00 1970 PST
+ 630 | 0 | 00630 | Sat Jan 31 00:00:00 1970 PST
+ 631 | 1 | 00631 | Sun Feb 01 00:00:00 1970 PST
+ 633 | 303 | 00633_update3 | Tue Feb 03 00:00:00 1970 PST
+ 634 | 4 | 00634 | Wed Feb 04 00:00:00 1970 PST
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST
+ 638 | 8 | 00638 | Sun Feb 08 00:00:00 1970 PST
+ 639 | 509 | 00639_update9 | Mon Feb 09 00:00:00 1970 PST
+ 640 | 0 | 00640 | Tue Feb 10 00:00:00 1970 PST
+ 641 | 1 | 00641 | Wed Feb 11 00:00:00 1970 PST
+ 643 | 303 | 00643_update3 | Fri Feb 13 00:00:00 1970 PST
+ 644 | 4 | 00644 | Sat Feb 14 00:00:00 1970 PST
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST
+ 648 | 8 | 00648 | Wed Feb 18 00:00:00 1970 PST
+ 649 | 509 | 00649_update9 | Thu Feb 19 00:00:00 1970 PST
+ 650 | 0 | 00650 | Fri Feb 20 00:00:00 1970 PST
+ 651 | 1 | 00651 | Sat Feb 21 00:00:00 1970 PST
+ 653 | 303 | 00653_update3 | Mon Feb 23 00:00:00 1970 PST
+ 654 | 4 | 00654 | Tue Feb 24 00:00:00 1970 PST
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST
+ 658 | 8 | 00658 | Sat Feb 28 00:00:00 1970 PST
+ 659 | 509 | 00659_update9 | Sun Mar 01 00:00:00 1970 PST
+ 660 | 0 | 00660 | Mon Mar 02 00:00:00 1970 PST
+ 661 | 1 | 00661 | Tue Mar 03 00:00:00 1970 PST
+ 663 | 303 | 00663_update3 | Thu Mar 05 00:00:00 1970 PST
+ 664 | 4 | 00664 | Fri Mar 06 00:00:00 1970 PST
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST
+ 668 | 8 | 00668 | Tue Mar 10 00:00:00 1970 PST
+ 669 | 509 | 00669_update9 | Wed Mar 11 00:00:00 1970 PST
+ 670 | 0 | 00670 | Thu Mar 12 00:00:00 1970 PST
+ 671 | 1 | 00671 | Fri Mar 13 00:00:00 1970 PST
+ 673 | 303 | 00673_update3 | Sun Mar 15 00:00:00 1970 PST
+ 674 | 4 | 00674 | Mon Mar 16 00:00:00 1970 PST
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST
+ 678 | 8 | 00678 | Fri Mar 20 00:00:00 1970 PST
+ 679 | 509 | 00679_update9 | Sat Mar 21 00:00:00 1970 PST
+ 680 | 0 | 00680 | Sun Mar 22 00:00:00 1970 PST
+ 681 | 1 | 00681 | Mon Mar 23 00:00:00 1970 PST
+ 683 | 303 | 00683_update3 | Wed Mar 25 00:00:00 1970 PST
+ 684 | 4 | 00684 | Thu Mar 26 00:00:00 1970 PST
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST
+ 688 | 8 | 00688 | Mon Mar 30 00:00:00 1970 PST
+ 689 | 509 | 00689_update9 | Tue Mar 31 00:00:00 1970 PST
+ 690 | 0 | 00690 | Wed Apr 01 00:00:00 1970 PST
+ 691 | 1 | 00691 | Thu Apr 02 00:00:00 1970 PST
+ 693 | 303 | 00693_update3 | Sat Apr 04 00:00:00 1970 PST
+ 694 | 4 | 00694 | Sun Apr 05 00:00:00 1970 PST
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST
+ 698 | 8 | 00698 | Thu Apr 09 00:00:00 1970 PST
+ 699 | 509 | 00699_update9 | Fri Apr 10 00:00:00 1970 PST
+ 700 | 0 | 00700 | Thu Jan 01 00:00:00 1970 PST
+ 701 | 1 | 00701 | Fri Jan 02 00:00:00 1970 PST
+ 703 | 303 | 00703_update3 | Sun Jan 04 00:00:00 1970 PST
+ 704 | 4 | 00704 | Mon Jan 05 00:00:00 1970 PST
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST
+ 708 | 8 | 00708 | Fri Jan 09 00:00:00 1970 PST
+ 709 | 509 | 00709_update9 | Sat Jan 10 00:00:00 1970 PST
+ 710 | 0 | 00710 | Sun Jan 11 00:00:00 1970 PST
+ 711 | 1 | 00711 | Mon Jan 12 00:00:00 1970 PST
+ 713 | 303 | 00713_update3 | Wed Jan 14 00:00:00 1970 PST
+ 714 | 4 | 00714 | Thu Jan 15 00:00:00 1970 PST
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST
+ 718 | 8 | 00718 | Mon Jan 19 00:00:00 1970 PST
+ 719 | 509 | 00719_update9 | Tue Jan 20 00:00:00 1970 PST
+ 720 | 0 | 00720 | Wed Jan 21 00:00:00 1970 PST
+ 721 | 1 | 00721 | Thu Jan 22 00:00:00 1970 PST
+ 723 | 303 | 00723_update3 | Sat Jan 24 00:00:00 1970 PST
+ 724 | 4 | 00724 | Sun Jan 25 00:00:00 1970 PST
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST
+ 728 | 8 | 00728 | Thu Jan 29 00:00:00 1970 PST
+ 729 | 509 | 00729_update9 | Fri Jan 30 00:00:00 1970 PST
+ 730 | 0 | 00730 | Sat Jan 31 00:00:00 1970 PST
+ 731 | 1 | 00731 | Sun Feb 01 00:00:00 1970 PST
+ 733 | 303 | 00733_update3 | Tue Feb 03 00:00:00 1970 PST
+ 734 | 4 | 00734 | Wed Feb 04 00:00:00 1970 PST
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST
+ 738 | 8 | 00738 | Sun Feb 08 00:00:00 1970 PST
+ 739 | 509 | 00739_update9 | Mon Feb 09 00:00:00 1970 PST
+ 740 | 0 | 00740 | Tue Feb 10 00:00:00 1970 PST
+ 741 | 1 | 00741 | Wed Feb 11 00:00:00 1970 PST
+ 743 | 303 | 00743_update3 | Fri Feb 13 00:00:00 1970 PST
+ 744 | 4 | 00744 | Sat Feb 14 00:00:00 1970 PST
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST
+ 748 | 8 | 00748 | Wed Feb 18 00:00:00 1970 PST
+ 749 | 509 | 00749_update9 | Thu Feb 19 00:00:00 1970 PST
+ 750 | 0 | 00750 | Fri Feb 20 00:00:00 1970 PST
+ 751 | 1 | 00751 | Sat Feb 21 00:00:00 1970 PST
+ 753 | 303 | 00753_update3 | Mon Feb 23 00:00:00 1970 PST
+ 754 | 4 | 00754 | Tue Feb 24 00:00:00 1970 PST
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST
+ 758 | 8 | 00758 | Sat Feb 28 00:00:00 1970 PST
+ 759 | 509 | 00759_update9 | Sun Mar 01 00:00:00 1970 PST
+ 760 | 0 | 00760 | Mon Mar 02 00:00:00 1970 PST
+ 761 | 1 | 00761 | Tue Mar 03 00:00:00 1970 PST
+ 763 | 303 | 00763_update3 | Thu Mar 05 00:00:00 1970 PST
+ 764 | 4 | 00764 | Fri Mar 06 00:00:00 1970 PST
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST
+ 768 | 8 | 00768 | Tue Mar 10 00:00:00 1970 PST
+ 769 | 509 | 00769_update9 | Wed Mar 11 00:00:00 1970 PST
+ 770 | 0 | 00770 | Thu Mar 12 00:00:00 1970 PST
+ 771 | 1 | 00771 | Fri Mar 13 00:00:00 1970 PST
+ 773 | 303 | 00773_update3 | Sun Mar 15 00:00:00 1970 PST
+ 774 | 4 | 00774 | Mon Mar 16 00:00:00 1970 PST
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST
+ 778 | 8 | 00778 | Fri Mar 20 00:00:00 1970 PST
+ 779 | 509 | 00779_update9 | Sat Mar 21 00:00:00 1970 PST
+ 780 | 0 | 00780 | Sun Mar 22 00:00:00 1970 PST
+ 781 | 1 | 00781 | Mon Mar 23 00:00:00 1970 PST
+ 783 | 303 | 00783_update3 | Wed Mar 25 00:00:00 1970 PST
+ 784 | 4 | 00784 | Thu Mar 26 00:00:00 1970 PST
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST
+ 788 | 8 | 00788 | Mon Mar 30 00:00:00 1970 PST
+ 789 | 509 | 00789_update9 | Tue Mar 31 00:00:00 1970 PST
+ 790 | 0 | 00790 | Wed Apr 01 00:00:00 1970 PST
+ 791 | 1 | 00791 | Thu Apr 02 00:00:00 1970 PST
+ 793 | 303 | 00793_update3 | Sat Apr 04 00:00:00 1970 PST
+ 794 | 4 | 00794 | Sun Apr 05 00:00:00 1970 PST
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST
+ 798 | 8 | 00798 | Thu Apr 09 00:00:00 1970 PST
+ 799 | 509 | 00799_update9 | Fri Apr 10 00:00:00 1970 PST
+ 800 | 0 | 00800 | Thu Jan 01 00:00:00 1970 PST
+ 801 | 1 | 00801 | Fri Jan 02 00:00:00 1970 PST
+ 803 | 303 | 00803_update3 | Sun Jan 04 00:00:00 1970 PST
+ 804 | 4 | 00804 | Mon Jan 05 00:00:00 1970 PST
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST
+ 808 | 8 | 00808 | Fri Jan 09 00:00:00 1970 PST
+ 809 | 509 | 00809_update9 | Sat Jan 10 00:00:00 1970 PST
+ 810 | 0 | 00810 | Sun Jan 11 00:00:00 1970 PST
+ 811 | 1 | 00811 | Mon Jan 12 00:00:00 1970 PST
+ 813 | 303 | 00813_update3 | Wed Jan 14 00:00:00 1970 PST
+ 814 | 4 | 00814 | Thu Jan 15 00:00:00 1970 PST
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST
+ 818 | 8 | 00818 | Mon Jan 19 00:00:00 1970 PST
+ 819 | 509 | 00819_update9 | Tue Jan 20 00:00:00 1970 PST
+ 820 | 0 | 00820 | Wed Jan 21 00:00:00 1970 PST
+ 821 | 1 | 00821 | Thu Jan 22 00:00:00 1970 PST
+ 823 | 303 | 00823_update3 | Sat Jan 24 00:00:00 1970 PST
+ 824 | 4 | 00824 | Sun Jan 25 00:00:00 1970 PST
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST
+ 828 | 8 | 00828 | Thu Jan 29 00:00:00 1970 PST
+ 829 | 509 | 00829_update9 | Fri Jan 30 00:00:00 1970 PST
+ 830 | 0 | 00830 | Sat Jan 31 00:00:00 1970 PST
+ 831 | 1 | 00831 | Sun Feb 01 00:00:00 1970 PST
+ 833 | 303 | 00833_update3 | Tue Feb 03 00:00:00 1970 PST
+ 834 | 4 | 00834 | Wed Feb 04 00:00:00 1970 PST
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST
+ 838 | 8 | 00838 | Sun Feb 08 00:00:00 1970 PST
+ 839 | 509 | 00839_update9 | Mon Feb 09 00:00:00 1970 PST
+ 840 | 0 | 00840 | Tue Feb 10 00:00:00 1970 PST
+ 841 | 1 | 00841 | Wed Feb 11 00:00:00 1970 PST
+ 843 | 303 | 00843_update3 | Fri Feb 13 00:00:00 1970 PST
+ 844 | 4 | 00844 | Sat Feb 14 00:00:00 1970 PST
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST
+ 848 | 8 | 00848 | Wed Feb 18 00:00:00 1970 PST
+ 849 | 509 | 00849_update9 | Thu Feb 19 00:00:00 1970 PST
+ 850 | 0 | 00850 | Fri Feb 20 00:00:00 1970 PST
+ 851 | 1 | 00851 | Sat Feb 21 00:00:00 1970 PST
+ 853 | 303 | 00853_update3 | Mon Feb 23 00:00:00 1970 PST
+ 854 | 4 | 00854 | Tue Feb 24 00:00:00 1970 PST
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST
+ 858 | 8 | 00858 | Sat Feb 28 00:00:00 1970 PST
+ 859 | 509 | 00859_update9 | Sun Mar 01 00:00:00 1970 PST
+ 860 | 0 | 00860 | Mon Mar 02 00:00:00 1970 PST
+ 861 | 1 | 00861 | Tue Mar 03 00:00:00 1970 PST
+ 863 | 303 | 00863_update3 | Thu Mar 05 00:00:00 1970 PST
+ 864 | 4 | 00864 | Fri Mar 06 00:00:00 1970 PST
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST
+ 868 | 8 | 00868 | Tue Mar 10 00:00:00 1970 PST
+ 869 | 509 | 00869_update9 | Wed Mar 11 00:00:00 1970 PST
+ 870 | 0 | 00870 | Thu Mar 12 00:00:00 1970 PST
+ 871 | 1 | 00871 | Fri Mar 13 00:00:00 1970 PST
+ 873 | 303 | 00873_update3 | Sun Mar 15 00:00:00 1970 PST
+ 874 | 4 | 00874 | Mon Mar 16 00:00:00 1970 PST
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST
+ 878 | 8 | 00878 | Fri Mar 20 00:00:00 1970 PST
+ 879 | 509 | 00879_update9 | Sat Mar 21 00:00:00 1970 PST
+ 880 | 0 | 00880 | Sun Mar 22 00:00:00 1970 PST
+ 881 | 1 | 00881 | Mon Mar 23 00:00:00 1970 PST
+ 883 | 303 | 00883_update3 | Wed Mar 25 00:00:00 1970 PST
+ 884 | 4 | 00884 | Thu Mar 26 00:00:00 1970 PST
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST
+ 888 | 8 | 00888 | Mon Mar 30 00:00:00 1970 PST
+ 889 | 509 | 00889_update9 | Tue Mar 31 00:00:00 1970 PST
+ 890 | 0 | 00890 | Wed Apr 01 00:00:00 1970 PST
+ 891 | 1 | 00891 | Thu Apr 02 00:00:00 1970 PST
+ 893 | 303 | 00893_update3 | Sat Apr 04 00:00:00 1970 PST
+ 894 | 4 | 00894 | Sun Apr 05 00:00:00 1970 PST
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST
+ 898 | 8 | 00898 | Thu Apr 09 00:00:00 1970 PST
+ 899 | 509 | 00899_update9 | Fri Apr 10 00:00:00 1970 PST
+ 900 | 0 | 00900 | Thu Jan 01 00:00:00 1970 PST
+ 901 | 1 | 00901 | Fri Jan 02 00:00:00 1970 PST
+ 903 | 303 | 00903_update3 | Sun Jan 04 00:00:00 1970 PST
+ 904 | 4 | 00904 | Mon Jan 05 00:00:00 1970 PST
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST
+ 908 | 8 | 00908 | Fri Jan 09 00:00:00 1970 PST
+ 909 | 509 | 00909_update9 | Sat Jan 10 00:00:00 1970 PST
+ 910 | 0 | 00910 | Sun Jan 11 00:00:00 1970 PST
+ 911 | 1 | 00911 | Mon Jan 12 00:00:00 1970 PST
+ 913 | 303 | 00913_update3 | Wed Jan 14 00:00:00 1970 PST
+ 914 | 4 | 00914 | Thu Jan 15 00:00:00 1970 PST
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST
+ 918 | 8 | 00918 | Mon Jan 19 00:00:00 1970 PST
+ 919 | 509 | 00919_update9 | Tue Jan 20 00:00:00 1970 PST
+ 920 | 0 | 00920 | Wed Jan 21 00:00:00 1970 PST
+ 921 | 1 | 00921 | Thu Jan 22 00:00:00 1970 PST
+ 923 | 303 | 00923_update3 | Sat Jan 24 00:00:00 1970 PST
+ 924 | 4 | 00924 | Sun Jan 25 00:00:00 1970 PST
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST
+ 928 | 8 | 00928 | Thu Jan 29 00:00:00 1970 PST
+ 929 | 509 | 00929_update9 | Fri Jan 30 00:00:00 1970 PST
+ 930 | 0 | 00930 | Sat Jan 31 00:00:00 1970 PST
+ 931 | 1 | 00931 | Sun Feb 01 00:00:00 1970 PST
+ 933 | 303 | 00933_update3 | Tue Feb 03 00:00:00 1970 PST
+ 934 | 4 | 00934 | Wed Feb 04 00:00:00 1970 PST
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST
+ 938 | 8 | 00938 | Sun Feb 08 00:00:00 1970 PST
+ 939 | 509 | 00939_update9 | Mon Feb 09 00:00:00 1970 PST
+ 940 | 0 | 00940 | Tue Feb 10 00:00:00 1970 PST
+ 941 | 1 | 00941 | Wed Feb 11 00:00:00 1970 PST
+ 943 | 303 | 00943_update3 | Fri Feb 13 00:00:00 1970 PST
+ 944 | 4 | 00944 | Sat Feb 14 00:00:00 1970 PST
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST
+ 948 | 8 | 00948 | Wed Feb 18 00:00:00 1970 PST
+ 949 | 509 | 00949_update9 | Thu Feb 19 00:00:00 1970 PST
+ 950 | 0 | 00950 | Fri Feb 20 00:00:00 1970 PST
+ 951 | 1 | 00951 | Sat Feb 21 00:00:00 1970 PST
+ 953 | 303 | 00953_update3 | Mon Feb 23 00:00:00 1970 PST
+ 954 | 4 | 00954 | Tue Feb 24 00:00:00 1970 PST
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST
+ 958 | 8 | 00958 | Sat Feb 28 00:00:00 1970 PST
+ 959 | 509 | 00959_update9 | Sun Mar 01 00:00:00 1970 PST
+ 960 | 0 | 00960 | Mon Mar 02 00:00:00 1970 PST
+ 961 | 1 | 00961 | Tue Mar 03 00:00:00 1970 PST
+ 963 | 303 | 00963_update3 | Thu Mar 05 00:00:00 1970 PST
+ 964 | 4 | 00964 | Fri Mar 06 00:00:00 1970 PST
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST
+ 968 | 8 | 00968 | Tue Mar 10 00:00:00 1970 PST
+ 969 | 509 | 00969_update9 | Wed Mar 11 00:00:00 1970 PST
+ 970 | 0 | 00970 | Thu Mar 12 00:00:00 1970 PST
+ 971 | 1 | 00971 | Fri Mar 13 00:00:00 1970 PST
+ 973 | 303 | 00973_update3 | Sun Mar 15 00:00:00 1970 PST
+ 974 | 4 | 00974 | Mon Mar 16 00:00:00 1970 PST
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST
+ 978 | 8 | 00978 | Fri Mar 20 00:00:00 1970 PST
+ 979 | 509 | 00979_update9 | Sat Mar 21 00:00:00 1970 PST
+ 980 | 0 | 00980 | Sun Mar 22 00:00:00 1970 PST
+ 981 | 1 | 00981 | Mon Mar 23 00:00:00 1970 PST
+ 983 | 303 | 00983_update3 | Wed Mar 25 00:00:00 1970 PST
+ 984 | 4 | 00984 | Thu Mar 26 00:00:00 1970 PST
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST
+ 988 | 8 | 00988 | Mon Mar 30 00:00:00 1970 PST
+ 989 | 509 | 00989_update9 | Tue Mar 31 00:00:00 1970 PST
+ 990 | 0 | 00990 | Wed Apr 01 00:00:00 1970 PST
+ 991 | 1 | 00991 | Thu Apr 02 00:00:00 1970 PST
+ 993 | 303 | 00993_update3 | Sat Apr 04 00:00:00 1970 PST
+ 994 | 4 | 00994 | Sun Apr 05 00:00:00 1970 PST
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST
+ 998 | 8 | 00998 | Thu Apr 09 00:00:00 1970 PST
+ 999 | 509 | 00999_update9 | Fri Apr 10 00:00:00 1970 PST
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST
+ 1001 | 101 | 0000100001 |
+ 1003 | 403 | 0000300003_update3 |
+ 1004 | 104 | 0000400004 |
+ 1006 | 106 | 0000600006 |
+ 1007 | 507 | 0000700007_update7 |
+ 1008 | 108 | 0000800008 |
+ 1009 | 609 | 0000900009_update9 |
+ 1010 | 100 | 0001000010 |
+ 1011 | 101 | 0001100011 |
+ 1013 | 403 | 0001300013_update3 |
+ 1014 | 104 | 0001400014 |
+ 1016 | 106 | 0001600016 |
+ 1017 | 507 | 0001700017_update7 |
+ 1018 | 108 | 0001800018 |
+ 1019 | 609 | 0001900019_update9 |
+ 1020 | 100 | 0002000020 |
+ 1101 | 201 | aaa |
+ 1103 | 503 | ccc_update3 |
+ 1104 | 204 | ddd |
+(819 rows)
+
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Output: (ft2.tableoid)::regclass
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: 1200, 999, NULL::integer, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+(6 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = 'bar'::text WHERE (("C 1" = 1200))
+(4 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------
+ Delete on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE (("C 1" = 1200))
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+-- Test UPDATE/DELETE with RETURNING on a three-table join
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id - 1200, to_char(id, 'FM00000') FROM generate_series(1201, 1300) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.*, ft4.c1, ft4.c2, ft4.c3
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c3 = 'foo'::text FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (TRUE)) WHERE ((r2.c1 = r3.c1)) AND ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) RETURNING r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3
+(4 rows)
+
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*;
+ ft2 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | ft4 | c1 | c2 | c3
+--------------------------------+------+----+-----+----+----+----+------------+----+----------------+----+----+--------
+ (1206,6,foo,,,,"ft2 ",) | 1206 | 6 | foo | | | | ft2 | | (6,7,AAA006) | 6 | 7 | AAA006
+ (1212,12,foo,,,,"ft2 ",) | 1212 | 12 | foo | | | | ft2 | | (12,13,AAA012) | 12 | 13 | AAA012
+ (1218,18,foo,,,,"ft2 ",) | 1218 | 18 | foo | | | | ft2 | | (18,19,AAA018) | 18 | 19 | AAA018
+ (1224,24,foo,,,,"ft2 ",) | 1224 | 24 | foo | | | | ft2 | | (24,25,AAA024) | 24 | 25 | AAA024
+ (1230,30,foo,,,,"ft2 ",) | 1230 | 30 | foo | | | | ft2 | | (30,31,AAA030) | 30 | 31 | AAA030
+ (1236,36,foo,,,,"ft2 ",) | 1236 | 36 | foo | | | | ft2 | | (36,37,AAA036) | 36 | 37 | AAA036
+ (1242,42,foo,,,,"ft2 ",) | 1242 | 42 | foo | | | | ft2 | | (42,43,AAA042) | 42 | 43 | AAA042
+ (1248,48,foo,,,,"ft2 ",) | 1248 | 48 | foo | | | | ft2 | | (48,49,AAA048) | 48 | 49 | AAA048
+ (1254,54,foo,,,,"ft2 ",) | 1254 | 54 | foo | | | | ft2 | | (54,55,AAA054) | 54 | 55 | AAA054
+ (1260,60,foo,,,,"ft2 ",) | 1260 | 60 | foo | | | | ft2 | | (60,61,AAA060) | 60 | 61 | AAA060
+ (1266,66,foo,,,,"ft2 ",) | 1266 | 66 | foo | | | | ft2 | | (66,67,AAA066) | 66 | 67 | AAA066
+ (1272,72,foo,,,,"ft2 ",) | 1272 | 72 | foo | | | | ft2 | | (72,73,AAA072) | 72 | 73 | AAA072
+ (1278,78,foo,,,,"ft2 ",) | 1278 | 78 | foo | | | | ft2 | | (78,79,AAA078) | 78 | 79 | AAA078
+ (1284,84,foo,,,,"ft2 ",) | 1284 | 84 | foo | | | | ft2 | | (84,85,AAA084) | 84 | 85 | AAA084
+ (1290,90,foo,,,,"ft2 ",) | 1290 | 90 | foo | | | | ft2 | | (90,91,AAA090) | 90 | 91 | AAA090
+ (1296,96,foo,,,,"ft2 ",) | 1296 | 96 | foo | | | | ft2 | | (96,97,AAA096) | 96 | 97 | AAA096
+(16 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: 100
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1)))) WHERE ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) AND (((r1."C 1" % 10) = 0))
+(4 rows)
+
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100;
+ ?column?
+----------
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+(10 rows)
+
+DELETE FROM ft2 WHERE ft2.c1 > 1200;
+-- Test UPDATE with a MULTIEXPR sub-select
+-- (maybe someday this'll be remotely executable, but not today)
+EXPLAIN (verbose, costs off)
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 target
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2, c7 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.ft2 target
+ Output: $1, $2, (SubPlan 1 (returns $1,$2)), target.ctid, target.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1100)) FOR UPDATE
+ SubPlan 1 (returns $1,$2)
+ -> Foreign Scan on public.ft2 src
+ Output: (src.c2 * 10), src.c7
+ Remote SQL: SELECT c2, c7 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(9 rows)
+
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+UPDATE ft2 AS target SET (c2) = (
+ SELECT c2 / 10
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+-- Test UPDATE involving a join that can be pushed down,
+-- but a SET clause that can't be
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 d
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2 WHERE ctid = $1
+ -> Foreign Scan
+ Output: CASE WHEN (random() >= '0'::double precision) THEN d.c2 ELSE 0 END, d.ctid, d.*, t.*
+ Relations: (public.ft2 d) INNER JOIN (public.ft2 t)
+ Remote SQL: SELECT r1.c2, r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r1."C 1" > 1000)))) FOR UPDATE OF r1
+ -> Hash Join
+ Output: d.c2, d.ctid, d.*, t.*
+ Hash Cond: (d.c1 = t.c1)
+ -> Foreign Scan on public.ft2 d
+ Output: d.c2, d.ctid, d.*, d.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1000)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Hash
+ Output: t.*, t.c1
+ -> Foreign Scan on public.ft2 t
+ Output: t.*, t.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(17 rows)
+
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+-- Test UPDATE/DELETE with WHERE or JOIN/ON conditions containing
+-- user-defined operators/functions
+ALTER SERVER loopback OPTIONS (DROP extensions);
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id % 10, to_char(id, 'FM00000') FROM generate_series(2001, 2010) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft2
+ Output: 'bar'::text, ctid, ft2.*
+ Filter: (postgres_fdw_abs(ft2.c1) > 2000)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" FOR UPDATE
+(7 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-----+----+----+----+------------+----
+ 2001 | 1 | bar | | | | ft2 |
+ 2002 | 2 | bar | | | | ft2 |
+ 2003 | 3 | bar | | | | ft2 |
+ 2004 | 4 | bar | | | | ft2 |
+ 2005 | 5 | bar | | | | ft2 |
+ 2006 | 6 | bar | | | | ft2 |
+ 2007 | 7 | bar | | | | ft2 |
+ 2008 | 8 | bar | | | | ft2 |
+ 2009 | 9 | bar | | | | ft2 |
+ 2010 | 0 | bar | | | | ft2 |
+(10 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Nested Loop
+ Output: 'baz'::text, ft2.ctid, ft2.*, ft4.*, ft5.*, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Join Filter: (ft2.c2 === ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.*, ft2.c2
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Relations: (public.ft4) INNER JOIN (public.ft5)
+ Remote SQL: SELECT CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r3.c1, r3.c2, r3.c3 FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1))))
+ -> Hash Join
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(24 rows)
+
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3
+------+----+-----+----+----+----+------------+----+----+----+--------+----+----+--------
+ 2006 | 6 | baz | | | | ft2 | | 6 | 7 | AAA006 | 6 | 7 | AAA006
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ctid = $1 RETURNING "C 1", c2, c3
+ -> Foreign Scan
+ Output: ft2.ctid, ft4.*, ft5.*
+ Filter: (ft4.c1 === ft5.c1)
+ Relations: ((public.ft2) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r2.c1, r3.c1 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c2 = r2.c1)) AND ((r1."C 1" > 2000)))) INNER JOIN "S 1"."T 4" r3 ON (TRUE)) FOR UPDATE OF r1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft5.*, ft4.c1, ft5.c1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft4.c1
+ Join Filter: (ft2.c2 = ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.c2
+ Remote SQL: SELECT c2, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(22 rows)
+
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3;
+ c1 | c2 | c3
+------+----+-----
+ 2006 | 6 | baz
+(1 row)
+
+DELETE FROM ft2 WHERE ft2.c1 > 2000;
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- Test that trigger on remote table works as expected
+CREATE OR REPLACE FUNCTION "S 1".F_BRTRIG() RETURNS trigger AS $$
+BEGIN
+ NEW.c3 = NEW.c3 || '_trig_update';
+ RETURN NEW;
+END;
+$$ LANGUAGE plpgsql;
+CREATE TRIGGER t1_br_insert BEFORE INSERT OR UPDATE
+ ON "S 1"."T 1" FOR EACH ROW EXECUTE PROCEDURE "S 1".F_BRTRIG();
+INSERT INTO ft2 (c1,c2,c3) VALUES (1208, 818, 'fff') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+----+------------+----
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+(1 row)
+
+INSERT INTO ft2 (c1,c2,c3,c6) VALUES (1218, 818, 'ggg', '(--;') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+------+------------+----
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+(1 row)
+
+UPDATE ft2 SET c2 = c2 + 600 WHERE c1 % 10 = 8 AND c1 < 1200 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+------------------------+------------------------------+--------------------------+----+------------+-----
+ 8 | 608 | 00008_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 18 | 608 | 00018_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 28 | 608 | 00028_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 38 | 608 | 00038_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 48 | 608 | 00048_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 58 | 608 | 00058_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 68 | 608 | 00068_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 78 | 608 | 00078_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 88 | 608 | 00088_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 98 | 608 | 00098_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 108 | 608 | 00108_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 118 | 608 | 00118_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 128 | 608 | 00128_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 138 | 608 | 00138_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 148 | 608 | 00148_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 158 | 608 | 00158_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 168 | 608 | 00168_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 178 | 608 | 00178_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 188 | 608 | 00188_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 198 | 608 | 00198_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 208 | 608 | 00208_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 218 | 608 | 00218_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 228 | 608 | 00228_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 238 | 608 | 00238_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 248 | 608 | 00248_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 258 | 608 | 00258_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 268 | 608 | 00268_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 278 | 608 | 00278_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 288 | 608 | 00288_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 298 | 608 | 00298_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 308 | 608 | 00308_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 318 | 608 | 00318_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 328 | 608 | 00328_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 338 | 608 | 00338_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 348 | 608 | 00348_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 358 | 608 | 00358_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 368 | 608 | 00368_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 378 | 608 | 00378_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 388 | 608 | 00388_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 398 | 608 | 00398_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 408 | 608 | 00408_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 418 | 608 | 00418_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 428 | 608 | 00428_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 438 | 608 | 00438_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 448 | 608 | 00448_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 458 | 608 | 00458_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 468 | 608 | 00468_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 478 | 608 | 00478_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 488 | 608 | 00488_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 498 | 608 | 00498_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 508 | 608 | 00508_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 518 | 608 | 00518_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 528 | 608 | 00528_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 538 | 608 | 00538_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 548 | 608 | 00548_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 558 | 608 | 00558_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 568 | 608 | 00568_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 578 | 608 | 00578_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 588 | 608 | 00588_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 598 | 608 | 00598_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 608 | 608 | 00608_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 618 | 608 | 00618_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 628 | 608 | 00628_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 638 | 608 | 00638_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 648 | 608 | 00648_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 658 | 608 | 00658_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 668 | 608 | 00668_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 678 | 608 | 00678_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 688 | 608 | 00688_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 698 | 608 | 00698_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 708 | 608 | 00708_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 718 | 608 | 00718_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 728 | 608 | 00728_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 738 | 608 | 00738_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 748 | 608 | 00748_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 758 | 608 | 00758_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 768 | 608 | 00768_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 778 | 608 | 00778_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 788 | 608 | 00788_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 798 | 608 | 00798_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 808 | 608 | 00808_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 818 | 608 | 00818_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 828 | 608 | 00828_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 838 | 608 | 00838_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 848 | 608 | 00848_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 858 | 608 | 00858_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 868 | 608 | 00868_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 878 | 608 | 00878_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 888 | 608 | 00888_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 898 | 608 | 00898_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 908 | 608 | 00908_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 918 | 608 | 00918_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 928 | 608 | 00928_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 938 | 608 | 00938_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 948 | 608 | 00948_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 958 | 608 | 00958_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 968 | 608 | 00968_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 978 | 608 | 00978_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 988 | 608 | 00988_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 998 | 608 | 00998_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 1008 | 708 | 0000800008_trig_update | | | | ft2 |
+ 1018 | 708 | 0001800018_trig_update | | | | ft2 |
+(102 rows)
+
+-- Test errors thrown on remote side during update
+ALTER TABLE "S 1"."T 1" ADD CONSTRAINT c2positive CHECK (c2 >= 0);
+INSERT INTO ft1(c1, c2) VALUES(11, 12); -- duplicate key
+ERROR: duplicate key value violates unique constraint "t1_pkey"
+DETAIL: Key ("C 1")=(11) already exists.
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT DO NOTHING; -- works
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO NOTHING; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO UPDATE SET c3 = 'ffg'; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+-- Test savepoint/rollback behavior
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+begin;
+update ft2 set c2 = 42 where c2 = 0;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 42 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s1;
+update ft2 set c2 = 44 where c2 = 4;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s1;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s2;
+update ft2 set c2 = 46 where c2 = 6;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 42 | 100
+ 44 | 100
+ 46 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+rollback to savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s3;
+update ft2 set c2 = -2 where c2 = 42 and c1 = 10; -- fail on remote side
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (10, -2, 00010_trig_update_trig_update, 1970-01-11 08:00:00+00, 1970-01-11 00:00:00, 0, 0 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (-2) WHERE ((c2 = 42)) AND (("C 1" = 10))
+rollback to savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+-- none of the above is committed yet remotely
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+commit;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+VACUUM ANALYZE "S 1"."T 1";
+-- Above DMLs add data with c6 as NULL in ft1, so test ORDER BY NULLS LAST and NULLs
+-- FIRST behavior here.
+-- ORDER BY DESC NULLS LAST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 795::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+------+------------+-----
+ 960 | 42 | 00960_trig_update | Mon Mar 02 00:00:00 1970 PST | Mon Mar 02 00:00:00 1970 | 0 | 0 | foo
+ 970 | 42 | 00970_trig_update | Thu Mar 12 00:00:00 1970 PST | Thu Mar 12 00:00:00 1970 | 0 | 0 | foo
+ 980 | 42 | 00980_trig_update | Sun Mar 22 00:00:00 1970 PST | Sun Mar 22 00:00:00 1970 | 0 | 0 | foo
+ 990 | 42 | 00990_trig_update | Wed Apr 01 00:00:00 1970 PST | Wed Apr 01 00:00:00 1970 | 0 | 0 | foo
+ 1000 | 42 | 01000_trig_update | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 1001 | 101 | 0000100001 | | | | ft2 |
+ 1003 | 403 | 0000300003_update3 | | | | ft2 |
+ 1004 | 104 | 0000400004 | | | | ft2 |
+ 1006 | 106 | 0000600006 | | | | ft2 |
+(10 rows)
+
+-- ORDER BY DESC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+------------------------------+--------------------------+----+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | ft2 | foo
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST | Tue Jan 20 00:00:00 1970 | 9 | ft2 | foo
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST | Fri Jan 30 00:00:00 1970 | 9 | ft2 | foo
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST | Mon Feb 09 00:00:00 1970 | 9 | ft2 | foo
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST | Thu Feb 19 00:00:00 1970 | 9 | ft2 | foo
+(10 rows)
+
+-- ORDER BY ASC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 ASC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-------------------+------------------------------+--------------------------+------+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 10 | 42 | 00010_trig_update | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+ 20 | 42 | 00020_trig_update | Wed Jan 21 00:00:00 1970 PST | Wed Jan 21 00:00:00 1970 | 0 | 0 | foo
+ 30 | 42 | 00030_trig_update | Sat Jan 31 00:00:00 1970 PST | Sat Jan 31 00:00:00 1970 | 0 | 0 | foo
+ 40 | 42 | 00040_trig_update | Tue Feb 10 00:00:00 1970 PST | Tue Feb 10 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- ===================================================================
+-- test check constraints
+-- ===================================================================
+-- Consistent check constraints provide consistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- check constraint is enforced on the remote side, not locally
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
+-- But inconsistent check constraints provide inconsistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 821
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- local check constraint is not actually enforced
+INSERT INTO ft1(c1, c2) VALUES(1111, 2);
+UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
+-- ===================================================================
+-- test WITH CHECK OPTION constraints
+-- ===================================================================
+CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
+CREATE TABLE base_tbl (a int, b int);
+ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE VIEW rw_view AS SELECT * FROM foreign_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT foreign_tbl.a,
+ foreign_tbl.b
+ FROM foreign_tbl
+ WHERE foreign_tbl.a < foreign_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 5
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 15
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 5), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 15), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP TRIGGER row_before_insupd_trigger ON base_tbl;
+DROP TABLE base_tbl;
+-- test WCO for partitions
+CREATE TABLE child_tbl (a int, b int);
+ALTER TABLE child_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON child_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'child_tbl');
+CREATE TABLE parent_tbl (a int, b int) PARTITION BY RANGE(a);
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+-- Detach and re-attach once, to stress the concurrent detach case.
+ALTER TABLE parent_tbl DETACH PARTITION foreign_tbl CONCURRENTLY;
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+CREATE VIEW rw_view AS SELECT * FROM parent_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT parent_tbl.a,
+ parent_tbl.b
+ FROM parent_tbl
+ WHERE parent_tbl.a < parent_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 5
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 15
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 5), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 15), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------
+ Insert on public.parent_tbl
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+DROP TRIGGER row_before_insupd_trigger ON child_tbl;
+DROP TABLE parent_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP FUNCTION row_before_insupd_trigfunc;
+-- ===================================================================
+-- test serial columns (ie, sequence-based defaults)
+-- ===================================================================
+create table loc1 (f1 serial, f2 text);
+alter table loc1 set (autovacuum_enabled = 'false');
+create foreign table rem1 (f1 serial, f2 text)
+ server loopback options(table_name 'loc1');
+select pg_catalog.setval('rem1_f1_seq', 10, false);
+ setval
+--------
+ 10
+(1 row)
+
+insert into loc1(f2) values('hi');
+insert into rem1(f2) values('hi remote');
+insert into loc1(f2) values('bye');
+insert into rem1(f2) values('bye remote');
+select * from loc1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+select * from rem1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+-- ===================================================================
+-- test generated columns
+-- ===================================================================
+create table gloc1 (
+ a int,
+ b int generated always as (a * 2) stored);
+alter table gloc1 set (autovacuum_enabled = 'false');
+create foreign table grem1 (
+ a int,
+ b int generated always as (a * 2) stored)
+ server loopback options(table_name 'gloc1');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+explain (verbose, costs off)
+update grem1 set a = 22 where a = 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.grem1
+ Remote SQL: UPDATE public.gloc1 SET a = $2, b = DEFAULT WHERE ctid = $1
+ -> Foreign Scan on public.grem1
+ Output: 22, ctid, grem1.*
+ Remote SQL: SELECT a, b, ctid FROM public.gloc1 WHERE ((a = 2)) FOR UPDATE
+(5 rows)
+
+update grem1 set a = 22 where a = 2;
+select * from gloc1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+select * from grem1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+delete from grem1;
+-- test copy from
+copy grem1 from stdin;
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+-- test batch insert
+alter server loopback options (add batch_size '10');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 10
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test local triggers
+-- ===================================================================
+-- Trigger functions "borrowed" from triggers regress test.
+CREATE FUNCTION trigger_func() RETURNS trigger LANGUAGE plpgsql AS $$
+BEGIN
+ RAISE NOTICE 'trigger_func(%) called: action = %, when = %, level = %',
+ TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN NULL;
+END;$$;
+CREATE TRIGGER trig_stmt_before BEFORE DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE TRIGGER trig_stmt_after AFTER DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE OR REPLACE FUNCTION trigger_data() RETURNS trigger
+LANGUAGE plpgsql AS $$
+
+declare
+ oldnew text[];
+ relid text;
+ argstr text;
+begin
+
+ relid := TG_relid::regclass;
+ argstr := '';
+ for i in 0 .. TG_nargs - 1 loop
+ if i > 0 then
+ argstr := argstr || ', ';
+ end if;
+ argstr := argstr || TG_argv[i];
+ end loop;
+
+ RAISE NOTICE '%(%) % % % ON %',
+ tg_name, argstr, TG_when, TG_level, TG_OP, relid;
+ oldnew := '{}'::text[];
+ if TG_OP != 'INSERT' then
+ oldnew := array_append(oldnew, format('OLD: %s', OLD));
+ end if;
+
+ if TG_OP != 'DELETE' then
+ oldnew := array_append(oldnew, format('NEW: %s', NEW));
+ end if;
+
+ RAISE NOTICE '%', array_to_string(oldnew, ',');
+
+ if TG_OP = 'DELETE' then
+ return OLD;
+ else
+ return NEW;
+ end if;
+end;
+$$;
+-- Test basic functionality
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+delete from rem1;
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = AFTER, level = STATEMENT
+insert into rem1 values(1,'insert');
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+update rem1 set f2 = f2 || f2;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+truncate rem1;
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = BEFORE, level = STATEMENT
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = AFTER, level = STATEMENT
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_stmt_before ON rem1;
+DROP TRIGGER trig_stmt_after ON rem1;
+DELETE from rem1;
+-- Test multiple AFTER ROW triggers on a foreign table
+CREATE TRIGGER trig_row_after1
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after2
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+insert into rem1 values(1,'insert');
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+update rem1 set f2 = f2 || f2;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+delete from rem1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+-- cleanup
+DROP TRIGGER trig_row_after1 ON rem1;
+DROP TRIGGER trig_row_after2 ON rem1;
+-- Test WHEN conditions
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_insupd
+AFTER INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Insert or update not matching: nothing happens
+INSERT INTO rem1 values(1, 'insert');
+UPDATE rem1 set f2 = 'test';
+-- Insert or update matching: triggers are fired
+INSERT INTO rem1 values(2, 'update');
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+UPDATE rem1 set f2 = 'update update' where f1 = '2';
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Trigger is fired for f1=2, not for f1=1
+DELETE FROM rem1;
+NOTICE: trig_row_before_delete(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+NOTICE: trig_row_after_delete(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+-- cleanup
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_after_insupd ON rem1;
+DROP TRIGGER trig_row_before_delete ON rem1;
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- Test various RETURN statements in BEFORE triggers.
+CREATE FUNCTION trig_row_before_insupdate() RETURNS TRIGGER AS $$
+ BEGIN
+ NEW.f2 := NEW.f2 || ' triggered !';
+ RETURN NEW;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+-- The new values should have 'triggered' appended
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------
+ insert triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+ 2 | insert triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------
+ 1 | triggered !
+ 2 | triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------
+ skidoo triggered !
+ skidoo triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | skidoo triggered !
+ 2 | skidoo triggered !
+(2 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f1 = 10; -- all columns should be transmitted
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: 10, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+UPDATE rem1 set f1 = 10;
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 10 | skidoo triggered ! triggered !
+ 10 | skidoo triggered ! triggered !
+(2 rows)
+
+DELETE FROM rem1;
+-- Add a second trigger, to check that the changes are propagated correctly
+-- from trigger to trigger
+CREATE TRIGGER trig_row_before_insupd2
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------------------
+ insert triggered ! triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+ 2 | insert triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------
+ 1 | triggered ! triggered !
+ 2 | triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------------------
+ skidoo triggered ! triggered !
+ skidoo triggered ! triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | skidoo triggered ! triggered !
+ 2 | skidoo triggered ! triggered !
+(2 rows)
+
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_before_insupd2 ON rem1;
+DELETE from rem1;
+INSERT INTO rem1 VALUES (1, 'test');
+-- Test with a trigger returning NULL
+CREATE FUNCTION trig_null() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_null
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_null();
+-- Nothing should have changed.
+INSERT INTO rem1 VALUES (2, 'test2');
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+UPDATE rem1 SET f2 = 'test2';
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DELETE from rem1;
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DROP TRIGGER trig_null ON rem1;
+DELETE from rem1;
+-- Test a combination of local and remote triggers
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_local_before BEFORE INSERT OR UPDATE ON loc1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1(f2) VALUES ('test');
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (12,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (12,"test triggered !")
+UPDATE rem1 SET f2 = 'testo';
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,testo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,"testo triggered !")
+-- Test returning a system attribute
+INSERT INTO rem1(f2) VALUES ('test') RETURNING ctid;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (13,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (13,"test triggered !")
+ ctid
+--------
+ (0,25)
+(1 row)
+
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_local_before ON loc1;
+-- Test direct foreign table modification functionality
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1 WHERE false; -- currently can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Result
+ Output: ctid
+ One-Time Filter: false
+(5 rows)
+
+-- Test with statement-level triggers
+CREATE TRIGGER trig_stmt_before
+ BEFORE DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_before ON rem1;
+CREATE TRIGGER trig_stmt_after
+ AFTER DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_after ON rem1;
+-- Test with row-level ON INSERT triggers
+CREATE TRIGGER trig_row_before_insert
+BEFORE INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_insert ON rem1;
+CREATE TRIGGER trig_row_after_insert
+AFTER INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_insert ON rem1;
+-- Test with row-level ON UPDATE triggers
+CREATE TRIGGER trig_row_before_update
+BEFORE UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_update ON rem1;
+CREATE TRIGGER trig_row_after_update
+AFTER UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = $2 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_update ON rem1;
+-- Test with row-level ON DELETE triggers
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_before_delete ON rem1;
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- ===================================================================
+-- test inheritance features
+-- ===================================================================
+CREATE TABLE a (aa TEXT);
+CREATE TABLE loct (aa TEXT, bb TEXT);
+ALTER TABLE a SET (autovacuum_enabled = 'false');
+ALTER TABLE loct SET (autovacuum_enabled = 'false');
+CREATE FOREIGN TABLE b (bb TEXT) INHERITS (a)
+ SERVER loopback OPTIONS (table_name 'loct');
+INSERT INTO a(aa) VALUES('aaa');
+INSERT INTO a(aa) VALUES('aaaa');
+INSERT INTO a(aa) VALUES('aaaaa');
+INSERT INTO b(aa) VALUES('bbb');
+INSERT INTO b(aa) VALUES('bbbb');
+INSERT INTO b(aa) VALUES('bbbbb');
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+(3 rows)
+
+UPDATE a SET aa = 'zzzzzz' WHERE aa LIKE 'aaaa%';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE b SET aa = 'new';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | new
+ b | new
+ b | new
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-----+----
+ b | new |
+ b | new |
+ b | new |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE a SET aa = 'newtoo';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+ b | newtoo
+ b | newtoo
+ b | newtoo
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+--------+----
+ b | newtoo |
+ b | newtoo |
+ b | newtoo |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+(3 rows)
+
+DELETE FROM a;
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+----+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+DROP TABLE a CASCADE;
+NOTICE: drop cascades to foreign table b
+DROP TABLE loct;
+-- Check SELECT FOR UPDATE/SHARE with an inherited source table
+create table loct1 (f1 int, f2 int, f3 int);
+create table loct2 (f1 int, f2 int, f3 int);
+alter table loct1 set (autovacuum_enabled = 'false');
+alter table loct2 set (autovacuum_enabled = 'false');
+create table foo (f1 int, f2 int);
+create foreign table foo2 (f3 int) inherits (foo)
+ server loopback options (table_name 'loct1');
+create table bar (f1 int, f2 int);
+create foreign table bar2 (f3 int) inherits (bar)
+ server loopback options (table_name 'loct2');
+alter table foo set (autovacuum_enabled = 'false');
+alter table bar set (autovacuum_enabled = 'false');
+insert into foo values(1,1);
+insert into foo values(3,3);
+insert into foo2 values(2,2,2);
+insert into foo2 values(4,4,4);
+insert into bar values(1,11);
+insert into bar values(2,22);
+insert into bar values(6,66);
+insert into bar2 values(3,33,33);
+insert into bar2 values(4,44,44);
+insert into bar2 values(7,77,77);
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for update;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for update;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for share;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for share;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+-- Now check SELECT FOR UPDATE/SHARE with an inherited source table,
+-- where the parent is itself a foreign table
+create table loct4 (f1 int, f2 int, f3 int);
+create foreign table foo2child (f3 int) inherits (foo2)
+ server loopback options (table_name 'loct4');
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct1
+ -> Foreign Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct4
+(24 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop foreign table foo2child;
+-- And with a local child relation of the foreign table parent
+create table foo2child (f3 int) inherits (foo2);
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.ctid, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+ -> Seq Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.ctid, foo2_2.tableoid
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop table foo2child;
+-- Check UPDATE with inherited target and an inherited source table
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Hash Join
+ Output: (bar.f2 + 100), foo.ctid, bar.tableoid, bar.ctid, (NULL::record), foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(25 rows)
+
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 111
+ bar | 2 | 122
+ bar | 6 | 66
+ bar2 | 3 | 133
+ bar2 | 4 | 144
+ bar2 | 7 | 77
+(6 rows)
+
+-- Check UPDATE with inherited target and an appendrel subquery
+explain (verbose, costs off)
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Merge Join
+ Output: (bar.f2 + 100), (ROW(foo.f1)), bar.tableoid, bar.ctid, (NULL::record)
+ Merge Cond: (bar.f1 = foo.f1)
+ -> Sort
+ Output: bar.f2, bar.f1, bar.tableoid, bar.ctid, (NULL::record)
+ Sort Key: bar.f1
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Sort
+ Output: (ROW(foo.f1)), foo.f1
+ Sort Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: ROW(foo.f1), foo.f1
+ -> Foreign Scan on public.foo2 foo_1
+ Output: ROW(foo_1.f1), foo_1.f1
+ Remote SQL: SELECT f1 FROM public.loct1
+ -> Seq Scan on public.foo foo_2
+ Output: ROW((foo_2.f1 + 3)), (foo_2.f1 + 3)
+ -> Foreign Scan on public.foo2 foo_3
+ Output: ROW((foo_3.f1 + 3)), (foo_3.f1 + 3)
+ Remote SQL: SELECT f1 FROM public.loct1
+(30 rows)
+
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 211
+ bar | 2 | 222
+ bar | 6 | 166
+ bar2 | 3 | 233
+ bar2 | 4 | 244
+ bar2 | 7 | 177
+(6 rows)
+
+-- Test forcing the remote server to produce sorted data for a merge join,
+-- but the foreign table is an inheritance child.
+truncate table loct1;
+truncate table only foo;
+\set num_rows_foo 2000
+insert into loct1 select generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2);
+insert into foo select generate_series(1, :num_rows_foo, 2), generate_series(1, :num_rows_foo, 2);
+SET enable_hashjoin to false;
+SET enable_nestloop to false;
+alter foreign table foo2 options (use_remote_estimate 'true');
+create index i_loct1_f1 on loct1(f1);
+create index i_foo_f1 on foo(f1);
+analyze foo;
+analyze loct1;
+-- inner join; expressions in the clauses appear in the equivalence class list
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 20 | 20
+ 22 | 22
+ 24 | 24
+ 26 | 26
+ 28 | 28
+ 30 | 30
+ 32 | 32
+ 34 | 34
+ 36 | 36
+ 38 | 38
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Left Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 10 | 10
+ 11 |
+ 12 | 12
+ 13 |
+ 14 | 14
+ 15 |
+ 16 | 16
+ 17 |
+ 18 | 18
+ 19 |
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test that WHERE CURRENT OF is not supported
+begin;
+declare c cursor for select * from bar where f1 = 7;
+fetch from c;
+ f1 | f2
+----+-----
+ 7 | 177
+(1 row)
+
+update bar set f2 = null where current of c;
+ERROR: WHERE CURRENT OF is not supported for this table type
+rollback;
+explain (verbose, costs off)
+delete from foo where f1 < 5 returning *;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Delete on public.foo
+ Output: foo_1.f1, foo_1.f2
+ Delete on public.foo foo_1
+ Foreign Delete on public.foo2 foo_2
+ -> Append
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.tableoid, foo_1.ctid
+ Index Cond: (foo_1.f1 < 5)
+ -> Foreign Delete on public.foo2 foo_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ((f1 < 5)) RETURNING f1, f2
+(10 rows)
+
+delete from foo where f1 < 5 returning *;
+ f1 | f2
+----+----
+ 1 | 1
+ 3 | 3
+ 0 | 0
+ 2 | 2
+ 4 | 4
+(5 rows)
+
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Update on public.bar
+ Output: bar_1.f1, bar_1.f2
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = (f2 + 100) RETURNING f1, f2
+(11 rows)
+
+update bar set f2 = f2 + 100 returning *;
+ f1 | f2
+----+-----
+ 1 | 311
+ 2 | 322
+ 6 | 266
+ 3 | 333
+ 4 | 344
+ 7 | 277
+(6 rows)
+
+-- Test that UPDATE/DELETE with inherited target works with row-level triggers
+CREATE TRIGGER trig_row_before
+BEFORE UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+explain (verbose, costs off)
+update bar set f2 = f2 + 100;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f1 = $2, f2 = $3, f3 = $4 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+(12 rows)
+
+update bar set f2 = f2 + 100;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+explain (verbose, costs off)
+delete from bar where f2 < 400;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Delete on public.bar
+ Delete on public.bar bar_1
+ Foreign Delete on public.bar2 bar_2
+ Remote SQL: DELETE FROM public.loct2 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.tableoid, bar_1.ctid, NULL::record
+ Filter: (bar_1.f2 < 400)
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 WHERE ((f2 < 400)) FOR UPDATE
+(11 rows)
+
+delete from bar where f2 < 400;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+-- cleanup
+drop table foo cascade;
+NOTICE: drop cascades to foreign table foo2
+drop table bar cascade;
+NOTICE: drop cascades to foreign table bar2
+drop table loct1;
+drop table loct2;
+-- Test pushing down UPDATE/DELETE joins to the remote server
+create table parent (a int, b text);
+create table loct1 (a int, b text);
+create table loct2 (a int, b text);
+create foreign table remt1 (a int, b text)
+ server loopback options (table_name 'loct1');
+create foreign table remt2 (a int, b text)
+ server loopback options (table_name 'loct2');
+alter foreign table remt1 inherit parent;
+insert into remt1 values (1, 'foo');
+insert into remt1 values (2, 'bar');
+insert into remt2 values (1, 'foo');
+insert into remt2 values (2, 'bar');
+analyze remt1;
+analyze remt2;
+explain (verbose, costs off)
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.parent
+ Output: parent_1.a, parent_1.b, remt2.a, remt2.b
+ Update on public.parent parent_1
+ Foreign Update on public.remt1 parent_2
+ Remote SQL: UPDATE public.loct1 SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: (parent.b || remt2.b), remt2.*, remt2.a, remt2.b, parent.tableoid, parent.ctid, (NULL::record)
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.b, parent_1.a, parent_1.tableoid, parent_1.ctid, NULL::record
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.b, parent_2.a, parent_2.tableoid, parent_2.ctid, parent_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.b, remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.b, remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ a | b | a | b
+---+--------+---+-----
+ 1 | foofoo | 1 | foo
+ 2 | barbar | 2 | bar
+(2 rows)
+
+explain (verbose, costs off)
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Delete on public.parent
+ Output: parent_1.*
+ Delete on public.parent parent_1
+ Foreign Delete on public.remt1 parent_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: remt2.*, parent.tableoid, parent.ctid
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.a, parent_1.tableoid, parent_1.ctid
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.a, parent_2.tableoid, parent_2.ctid
+ Remote SQL: SELECT a, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ parent
+------------
+ (1,foofoo)
+ (2,barbar)
+(2 rows)
+
+-- cleanup
+drop foreign table remt1;
+drop foreign table remt2;
+drop table loct1;
+drop table loct2;
+drop table parent;
+-- ===================================================================
+-- test tuple routing for foreign-table partitions
+-- ===================================================================
+-- Test insert tuple routing
+create table itrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table itrtest attach partition remp1 for values in (1);
+alter table itrtest attach partition remp2 for values in (2);
+insert into itrtest values (1, 'foo');
+insert into itrtest values (1, 'bar') returning *;
+ a | b
+---+-----
+ 1 | bar
+(1 row)
+
+insert into itrtest values (2, 'baz');
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----
+ 2 | qux
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------
+ 1 | test1
+ 2 | test2
+(2 rows)
+
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from itrtest;
+create unique index loct1_idx on loct1 (a);
+-- DO NOTHING without an inference specification is supported
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+-----
+ 1 | foo
+(1 row)
+
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+---
+(0 rows)
+
+-- But other cases are not supported
+insert into itrtest values (1, 'bar') on conflict (a) do nothing;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+insert into itrtest values (1, 'bar') on conflict (a) do update set b = excluded.b;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+delete from itrtest;
+drop index loct1_idx;
+-- Test that remote triggers work with insert tuple routing
+create function br_insert_trigfunc() returns trigger as $$
+begin
+ new.b := new.b || ' triggered !';
+ return new;
+end
+$$ language plpgsql;
+create trigger loct1_br_insert_trigger before insert on loct1
+ for each row execute procedure br_insert_trigfunc();
+create trigger loct2_br_insert_trigger before insert on loct2
+ for each row execute procedure br_insert_trigfunc();
+-- The new values are concatenated with ' triggered !'
+insert into itrtest values (1, 'foo') returning *;
+ a | b
+---+-----------------
+ 1 | foo triggered !
+(1 row)
+
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----------------
+ 2 | qux triggered !
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+with result as (insert into itrtest values (1, 'test1'), (2, 'test2') returning *) select * from result;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+drop trigger loct1_br_insert_trigger on loct1;
+drop trigger loct2_br_insert_trigger on loct2;
+drop table itrtest;
+drop table loct1;
+drop table loct2;
+-- Test update tuple routing
+create table utrtest (a int, b text) partition by list (a);
+create table loct (a int check (a in (1)), b text);
+create foreign table remp (a int check (a in (1)), b text) server loopback options (table_name 'loct');
+create table locp (a int check (a in (2)), b text);
+alter table utrtest attach partition remp for values in (1);
+alter table utrtest attach partition locp for values in (2);
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- It's not allowed to move a row from a partition that is foreign to another
+update utrtest set a = 2 where b = 'foo' returning *;
+ERROR: new row for relation "loct" violates check constraint "loct_a_check"
+DETAIL: Failing row contains (2, foo).
+CONTEXT: remote SQL command: UPDATE public.loct SET a = 2 WHERE ((b = 'foo')) RETURNING a, b
+-- But the reverse is allowed
+update utrtest set a = 1 where b = 'qux' returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- The executor should not let unexercised FDWs shut down
+update utrtest set a = 1 where b = 'foo';
+-- Test that remote triggers work with update tuple routing
+create trigger loct_br_insert_trigger before insert on loct
+ for each row execute procedure br_insert_trigfunc();
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition is a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 WHERE (((a = 1) OR (a = 2))) RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ Filter: ((utrtest_2.a = 1) OR (utrtest_2.a = 2))
+(10 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition isn't a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 2 returning *;
+ QUERY PLAN
+-------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ -> Seq Scan on public.locp utrtest_1
+ Output: 1, utrtest_1.tableoid, utrtest_1.ctid
+ Filter: (utrtest_1.a = 2)
+(6 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 2 returning *;
+ a | b
+---+-----------------
+ 1 | qux triggered !
+(1 row)
+
+drop trigger loct_br_insert_trigger on loct;
+-- We can move rows to a foreign partition that has been updated already,
+-- but can't move rows to a foreign partition that hasn't been updated yet
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- Test the former case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+(9 rows)
+
+update utrtest set a = 1 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ Update on public.locp utrtest_2
+ -> Hash Join
+ Output: 1, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, utrtest.*
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Foreign Scan on public.remp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, utrtest_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Seq Scan on public.locp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- Change the definition of utrtest so that the foreign partition get updated
+-- after the local partition
+delete from utrtest;
+alter table utrtest detach partition remp;
+drop foreign table remp;
+alter table loct drop constraint loct_a_check;
+alter table loct add check (a in (3));
+create foreign table remp (a int check (a in (3)), b text) server loopback options (table_name 'loct');
+alter table utrtest attach partition remp for values in (3);
+insert into utrtest values (2, 'qux');
+insert into utrtest values (3, 'xyzzy');
+-- Test the latter case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: 3, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = 3 RETURNING a, b
+(9 rows)
+
+update utrtest set a = 3 returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ -> Hash Join
+ Output: 3, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, (NULL::record)
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Scan on public.remp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, utrtest_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+drop table utrtest;
+drop table loct;
+-- Test copy tuple routing
+create table ctrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table ctrtest attach partition remp1 for values in (1);
+alter table ctrtest attach partition remp2 for values in (2);
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp2 | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-----+---
+ remp2 | qux | 2
+(1 row)
+
+-- Copying into foreign partitions directly should work as well
+copy remp1 from stdin;
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+(2 rows)
+
+drop table ctrtest;
+drop table loct1;
+drop table loct2;
+-- ===================================================================
+-- test COPY FROM
+-- ===================================================================
+create table loc2 (f1 int, f2 text);
+alter table loc2 set (autovacuum_enabled = 'false');
+create foreign table rem2 (f1 int, f2 text) server loopback options(table_name 'loc2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2, line 1: "-1 xyzzy"
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test local triggers
+create trigger trig_stmt_before before insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_stmt_after after insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+copy rem2 from stdin;
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop trigger trig_row_before on rem2;
+drop trigger trig_row_after on rem2;
+drop trigger trig_stmt_before on rem2;
+drop trigger trig_stmt_after on rem2;
+delete from rem2;
+create trigger trig_row_before_insert before insert on rem2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on rem2;
+delete from rem2;
+create trigger trig_null before insert on rem2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on rem2;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Test a combination of local and remote triggers
+create trigger rem2_trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger rem2_trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger loc2_trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+copy rem2 from stdin;
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,"foo triggered !")
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,"bar triggered !")
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger rem2_trig_row_before on rem2;
+drop trigger rem2_trig_row_after on rem2;
+drop trigger loc2_trig_row_before_insert on loc2;
+delete from rem2;
+-- test COPY FROM with foreign table created in the same transaction
+create table loc3 (f1 int, f2 text);
+begin;
+create foreign table rem3 (f1 int, f2 text)
+ server loopback options(table_name 'loc3');
+copy rem3 from stdin;
+commit;
+select * from rem3;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop foreign table rem3;
+drop table loc3;
+-- ===================================================================
+-- test for TRUNCATE
+-- ===================================================================
+CREATE TABLE tru_rtable0 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable0');
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(1,10) x);
+CREATE TABLE tru_ptable (id int) PARTITION BY HASH(id);
+CREATE TABLE tru_ptable__p0 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tru_rtable1 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable__p1 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback OPTIONS (table_name 'tru_rtable1');
+INSERT INTO tru_ptable (SELECT x FROM generate_series(11,20) x);
+CREATE TABLE tru_pk_table(id int primary key);
+CREATE TABLE tru_fk_table(fkey int references tru_pk_table(id));
+INSERT INTO tru_pk_table (SELECT x FROM generate_series(1,10) x);
+INSERT INTO tru_fk_table (SELECT x % 10 + 1 FROM generate_series(5,25) x);
+CREATE FOREIGN TABLE tru_pk_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_pk_table');
+CREATE TABLE tru_rtable_parent (id int);
+CREATE TABLE tru_rtable_child (id int);
+CREATE FOREIGN TABLE tru_ftable_parent (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_parent');
+CREATE FOREIGN TABLE tru_ftable_child () INHERITS (tru_ftable_parent)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_child');
+INSERT INTO tru_rtable_parent (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_rtable_child (SELECT x FROM generate_series(10, 18) x);
+-- normal truncate
+SELECT sum(id) FROM tru_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_ftable;
+SELECT count(*) FROM tru_rtable0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'truncatable' option
+ALTER SERVER loopback OPTIONS (ADD truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (ADD truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER SERVER loopback OPTIONS (DROP truncatable);
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+-- partitioned table with both local and foreign tables as partitions
+SELECT sum(id) FROM tru_ptable; -- 155
+ sum
+-----
+ 155
+(1 row)
+
+TRUNCATE tru_ptable;
+SELECT count(*) FROM tru_ptable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ptable__p0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable__p1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_rtable1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'CASCADE' option
+SELECT sum(id) FROM tru_pk_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_pk_ftable; -- failed by FK reference
+ERROR: cannot truncate a table referenced in a foreign key constraint
+DETAIL: Table "tru_fk_table" references "tru_pk_table".
+HINT: Truncate table "tru_fk_table" at the same time, or use TRUNCATE ... CASCADE.
+CONTEXT: remote SQL command: TRUNCATE public.tru_pk_table CONTINUE IDENTITY RESTRICT
+TRUNCATE tru_pk_ftable CASCADE;
+SELECT count(*) FROM tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_fk_table; -- also truncated,0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate two tables at a command
+INSERT INTO tru_ftable (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_pk_ftable (SELECT x FROM generate_series(3,10) x);
+SELECT count(*) from tru_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+TRUNCATE tru_ftable, tru_pk_ftable CASCADE;
+SELECT count(*) from tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate with ONLY clause
+-- Since ONLY is specified, the table tru_ftable_child that inherits
+-- tru_ftable_parent locally is not truncated.
+TRUNCATE ONLY tru_ftable_parent;
+SELECT sum(id) FROM tru_ftable_parent; -- 126
+ sum
+-----
+ 126
+(1 row)
+
+TRUNCATE tru_ftable_parent;
+SELECT count(*) FROM tru_ftable_parent; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- in case when remote table has inherited children
+CREATE TABLE tru_rtable0_child () INHERITS (tru_rtable0);
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(5,9) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(10,14) x);
+SELECT sum(id) FROM tru_ftable; -- 95
+ sum
+-----
+ 95
+(1 row)
+
+-- Both parent and child tables in the foreign server are truncated
+-- even though ONLY is specified because ONLY has no effect
+-- when truncating a foreign table.
+TRUNCATE ONLY tru_ftable;
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(21,25) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(26,30) x);
+SELECT sum(id) FROM tru_ftable; -- 255
+ sum
+-----
+ 255
+(1 row)
+
+TRUNCATE tru_ftable; -- truncate both of parent and child
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- cleanup
+DROP FOREIGN TABLE tru_ftable_parent, tru_ftable_child, tru_pk_ftable,tru_ftable__p1,tru_ftable;
+DROP TABLE tru_rtable0, tru_rtable1, tru_ptable, tru_ptable__p0, tru_pk_table, tru_fk_table,
+tru_rtable_parent,tru_rtable_child, tru_rtable0_child;
+-- ===================================================================
+-- test IMPORT FOREIGN SCHEMA
+-- ===================================================================
+CREATE SCHEMA import_source;
+CREATE TABLE import_source.t1 (c1 int, c2 varchar NOT NULL);
+CREATE TABLE import_source.t2 (c1 int default 42, c2 varchar NULL, c3 text collate "POSIX");
+CREATE TYPE typ1 AS (m1 int, m2 varchar);
+CREATE TABLE import_source.t3 (c1 timestamptz default now(), c2 typ1);
+CREATE TABLE import_source."x 4" (c1 float8, "C 2" text, c3 varchar(42));
+CREATE TABLE import_source."x 5" (c1 float8);
+ALTER TABLE import_source."x 5" DROP COLUMN c1;
+CREATE TABLE import_source."x 6" (c1 int, c2 int generated always as (c1 * 2) stored);
+CREATE TABLE import_source.t4 (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE import_source.t4_part PARTITION OF import_source.t4
+ FOR VALUES FROM (1) TO (100);
+CREATE TABLE import_source.t4_part2 PARTITION OF import_source.t4
+ FOR VALUES FROM (100) TO (200);
+CREATE SCHEMA import_dest1;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest1;
+\det+ import_dest1.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest1 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest1 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest1 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest1 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest1 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest1 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest1 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest1.*
+ Foreign table "import_dest1.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest1.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest1.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest1.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest1.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest1.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest1.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Options
+CREATE SCHEMA import_dest2;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest2
+ OPTIONS (import_default 'true');
+\det+ import_dest2.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest2 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest2 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest2 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest2 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest2 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest2 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest2 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest2.*
+ Foreign table "import_dest2.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest2.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | 42 | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest2.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | now() | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest2.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest2.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest2.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest2.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+CREATE SCHEMA import_dest3;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest3
+ OPTIONS (import_collate 'false', import_generated 'false', import_not_null 'false');
+\det+ import_dest3.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest3 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest3 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest3 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest3 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest3 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest3 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest3 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest3.*
+ Foreign table "import_dest3.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest3.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest3.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest3.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest3.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest3.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest3.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Check LIMIT TO and EXCEPT
+CREATE SCHEMA import_dest4;
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t1, nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+(2 rows)
+
+IMPORT FOREIGN SCHEMA import_source EXCEPT (t1, "x 4", nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest4 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest4 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+ import_dest4 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest4 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+-- Assorted error cases
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest4;
+ERROR: relation "t1" already exists
+CONTEXT: importing foreign table "t1"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO import_dest4;
+ERROR: schema "nonesuch" is not present on foreign server "loopback"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO notthere;
+ERROR: schema "notthere" does not exist
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER nowhere INTO notthere;
+ERROR: server "nowhere" does not exist
+-- Check case of a type present only on the remote server.
+-- We can fake this by dropping the type locally in our transaction.
+CREATE TYPE "Colors" AS ENUM ('red', 'green', 'blue');
+CREATE TABLE import_source.t5 (c1 int, c2 text collate "C", "Col" "Colors");
+CREATE SCHEMA import_dest5;
+BEGIN;
+DROP TYPE "Colors" CASCADE;
+NOTICE: drop cascades to column Col of table import_source.t5
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t5)
+ FROM SERVER loopback INTO import_dest5; -- ERROR
+ERROR: type "public.Colors" does not exist
+LINE 4: "Col" public."Colors" OPTIONS (column_name 'Col')
+ ^
+QUERY: CREATE FOREIGN TABLE t5 (
+ c1 integer OPTIONS (column_name 'c1'),
+ c2 text OPTIONS (column_name 'c2') COLLATE pg_catalog."C",
+ "Col" public."Colors" OPTIONS (column_name 'Col')
+) SERVER loopback
+OPTIONS (schema_name 'import_source', table_name 't5');
+CONTEXT: importing foreign table "t5"
+ROLLBACK;
+BEGIN;
+CREATE SERVER fetch101 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( fetch_size '101' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER fetch101 OPTIONS( SET fetch_size '202' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=202'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30000 ( x int ) SERVER fetch101 OPTIONS ( fetch_size '30000' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '60000');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=60000'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- ===================================================================
+-- test partitionwise joins
+-- ===================================================================
+SET enable_partitionwise_join=on;
+CREATE TABLE fprt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE fprt1_p1 (LIKE fprt1);
+CREATE TABLE fprt1_p2 (LIKE fprt1);
+ALTER TABLE fprt1_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt1_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt1_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 2) i;
+INSERT INTO fprt1_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 2) i;
+CREATE FOREIGN TABLE ftprt1_p1 PARTITION OF fprt1 FOR VALUES FROM (0) TO (250)
+ SERVER loopback OPTIONS (table_name 'fprt1_p1', use_remote_estimate 'true');
+CREATE FOREIGN TABLE ftprt1_p2 PARTITION OF fprt1 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (TABLE_NAME 'fprt1_p2');
+ANALYZE fprt1;
+ANALYZE fprt1_p1;
+ANALYZE fprt1_p2;
+CREATE TABLE fprt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE fprt2_p1 (LIKE fprt2);
+CREATE TABLE fprt2_p2 (LIKE fprt2);
+ALTER TABLE fprt2_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt2_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt2_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 3) i;
+INSERT INTO fprt2_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 3) i;
+CREATE FOREIGN TABLE ftprt2_p1 (b int, c varchar, a int)
+ SERVER loopback OPTIONS (table_name 'fprt2_p1', use_remote_estimate 'true');
+ALTER TABLE fprt2 ATTACH PARTITION ftprt2_p1 FOR VALUES FROM (0) TO (250);
+CREATE FOREIGN TABLE ftprt2_p2 PARTITION OF fprt2 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (table_name 'fprt2_p2', use_remote_estimate 'true');
+ANALYZE fprt2;
+ANALYZE fprt2_p1;
+ANALYZE fprt2_p2;
+-- inner join three tables
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t3.c
+ -> Append
+ -> Foreign Scan
+ Relations: ((ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)) INNER JOIN (ftprt1_p1 t3_1)
+ -> Foreign Scan
+ Relations: ((ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)) INNER JOIN (ftprt1_p2 t3_2)
+(7 rows)
+
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0003
+ 250 | 250 | 0005
+ 400 | 400 | 0008
+(4 rows)
+
+-- left outer join + nullable clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.a, fprt2.b, fprt2.c
+ Relations: (public.ftprt1_p1 t1) LEFT JOIN (public.ftprt2_p1 fprt2)
+ Remote SQL: SELECT r5.a, r6.b, r6.c FROM (public.fprt1_p1 r5 LEFT JOIN public.fprt2_p1 r6 ON (((r5.a = r6.b)) AND ((r5.b = r6.a)) AND ((r6.a < 10)))) WHERE ((r5.a < 10)) ORDER BY r5.a ASC NULLS LAST, r6.b ASC NULLS LAST, r6.c ASC NULLS LAST
+(4 rows)
+
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ a | b | c
+---+---+------
+ 0 | 0 | 0000
+ 2 | |
+ 4 | |
+ 6 | 6 | 0000
+ 8 | |
+(5 rows)
+
+-- with whole-row reference; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ QUERY PLAN
+--------------------------------------------------------
+ Sort
+ Sort Key: ((t1.*)::fprt1), ((t2.*)::fprt2)
+ -> Hash Full Join
+ Hash Cond: (t1.a = t2.b)
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+(11 rows)
+
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ wr | wr
+----------------+----------------
+ (0,0,0000) | (0,0,0000)
+ (50,50,0001) |
+ (100,100,0002) |
+ (150,150,0003) | (150,150,0003)
+ (200,200,0004) |
+ (250,250,0005) | (250,250,0005)
+ (300,300,0006) |
+ (350,350,0007) |
+ (400,400,0008) | (400,400,0008)
+ (450,450,0009) |
+ | (75,75,0001)
+ | (225,225,0004)
+ | (325,325,0006)
+ | (475,475,0009)
+(14 rows)
+
+-- join with lateral reference
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t1.b
+ -> Append
+ -> Foreign Scan
+ Relations: (ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)
+ -> Foreign Scan
+ Relations: (ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)
+(7 rows)
+
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+-- with PHVs, partitionwise join selected but no join pushdown
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: fprt1.a, fprt2.b
+ -> Append
+ -> Hash Full Join
+ Hash Cond: (fprt1_1.a = fprt2_1.b)
+ -> Foreign Scan on ftprt1_p1 fprt1_1
+ -> Hash
+ -> Foreign Scan on ftprt2_p1 fprt2_1
+ -> Hash Full Join
+ Hash Cond: (fprt1_2.a = fprt2_2.b)
+ -> Foreign Scan on ftprt1_p2 fprt1_2
+ -> Hash
+ -> Foreign Scan on ftprt2_p2 fprt2_2
+(13 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | phv | b | phv
+-----+--------+-----+--------
+ 0 | t1_phv | 0 | t2_phv
+ 50 | t1_phv | |
+ 100 | t1_phv | |
+ 150 | t1_phv | 150 | t2_phv
+ 200 | t1_phv | |
+ 250 | t1_phv | 250 | t2_phv
+ 300 | t1_phv | |
+ 350 | t1_phv | |
+ 400 | t1_phv | 400 | t2_phv
+ 450 | t1_phv | |
+ | | 75 | t2_phv
+ | | 225 | t2_phv
+ | | 325 | t2_phv
+ | | 475 | t2_phv
+(14 rows)
+
+-- test FOR UPDATE; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ QUERY PLAN
+--------------------------------------------------------------
+ LockRows
+ -> Sort
+ Sort Key: t1.a
+ -> Hash Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+(12 rows)
+
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+RESET enable_partitionwise_join;
+-- ===================================================================
+-- test partitionwise aggregates
+-- ===================================================================
+CREATE TABLE pagg_tab (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE pagg_tab_p1 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p2 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p3 (LIKE pagg_tab);
+INSERT INTO pagg_tab_p1 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 10;
+INSERT INTO pagg_tab_p2 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 20 and (i % 30) >= 10;
+INSERT INTO pagg_tab_p3 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 30 and (i % 30) >= 20;
+-- Create foreign partitions
+CREATE FOREIGN TABLE fpagg_tab_p1 PARTITION OF pagg_tab FOR VALUES FROM (0) TO (10) SERVER loopback OPTIONS (table_name 'pagg_tab_p1');
+CREATE FOREIGN TABLE fpagg_tab_p2 PARTITION OF pagg_tab FOR VALUES FROM (10) TO (20) SERVER loopback OPTIONS (table_name 'pagg_tab_p2');
+CREATE FOREIGN TABLE fpagg_tab_p3 PARTITION OF pagg_tab FOR VALUES FROM (20) TO (30) SERVER loopback OPTIONS (table_name 'pagg_tab_p3');
+ANALYZE pagg_tab;
+ANALYZE fpagg_tab_p1;
+ANALYZE fpagg_tab_p2;
+ANALYZE fpagg_tab_p3;
+-- When GROUP BY clause matches with PARTITION KEY.
+-- Plan with partitionwise aggregates is disabled
+SET enable_partitionwise_aggregate TO false;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> HashAggregate
+ Group Key: pagg_tab.a
+ Filter: (avg(pagg_tab.b) < '22'::numeric)
+ -> Append
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab_1
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_2
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_3
+(9 rows)
+
+-- Plan with partitionwise aggregates is enabled
+SET enable_partitionwise_aggregate TO true;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> Append
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p1 pagg_tab)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p2 pagg_tab_1)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p3 pagg_tab_2)
+(9 rows)
+
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | sum | min | count
+----+------+-----+-------
+ 0 | 2000 | 0 | 100
+ 1 | 2100 | 1 | 100
+ 10 | 2000 | 0 | 100
+ 11 | 2100 | 1 | 100
+ 20 | 2000 | 0 | 100
+ 21 | 2100 | 1 | 100
+(6 rows)
+
+-- Check with whole-row reference
+-- Should have all the columns in the target list for the given relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, (count(((t1.*)::pagg_tab)))
+ Sort Key: t1.a
+ -> Append
+ -> HashAggregate
+ Output: t1.a, count(((t1.*)::pagg_tab))
+ Group Key: t1.a
+ Filter: (avg(t1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p1 t1
+ Output: t1.a, t1.*, t1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p1
+ -> HashAggregate
+ Output: t1_1.a, count(((t1_1.*)::pagg_tab))
+ Group Key: t1_1.a
+ Filter: (avg(t1_1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p2 t1_1
+ Output: t1_1.a, t1_1.*, t1_1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p2
+ -> HashAggregate
+ Output: t1_2.a, count(((t1_2.*)::pagg_tab))
+ Group Key: t1_2.a
+ Filter: (avg(t1_2.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p3 t1_2
+ Output: t1_2.a, t1_2.*, t1_2.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p3
+(25 rows)
+
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | count
+----+-------
+ 0 | 100
+ 1 | 100
+ 10 | 100
+ 11 | 100
+ 20 | 100
+ 21 | 100
+(6 rows)
+
+-- When GROUP BY clause does not match with PARTITION KEY.
+EXPLAIN (COSTS OFF)
+SELECT b, avg(a), max(a), count(*) FROM pagg_tab GROUP BY b HAVING sum(a) < 700 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.b
+ -> Finalize HashAggregate
+ Group Key: pagg_tab.b
+ Filter: (sum(pagg_tab.a) < 700)
+ -> Append
+ -> Partial HashAggregate
+ Group Key: pagg_tab.b
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab
+ -> Partial HashAggregate
+ Group Key: pagg_tab_1.b
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_1
+ -> Partial HashAggregate
+ Group Key: pagg_tab_2.b
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_2
+(15 rows)
+
+-- ===================================================================
+-- access rights and superuser
+-- ===================================================================
+-- Non-superuser cannot create a FDW without a password in the connstr
+CREATE ROLE regress_nosuper NOSUPERUSER;
+GRANT USAGE ON FOREIGN DATA WRAPPER postgres_fdw TO regress_nosuper;
+SET ROLE regress_nosuper;
+SHOW is_superuser;
+ is_superuser
+--------------
+ off
+(1 row)
+
+-- This will be OK, we can create the FDW
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback_nopw FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+-- But creation of user mappings for non-superusers should fail
+CREATE USER MAPPING FOR public SERVER loopback_nopw;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+CREATE FOREIGN TABLE pg_temp.ft1_nopw (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback_nopw OPTIONS (schema_name 'public', table_name 'ft1');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+-- If we add a password to the connstr it'll fail, because we don't allow passwords
+-- in connstrs only in user mappings.
+ALTER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+ERROR: invalid option "password"
+HINT: Perhaps you meant the option "passfile".
+-- If we add a password for our user mapping instead, we should get a different
+-- error because the password wasn't actually *used* when we run with trust auth.
+--
+-- This won't work with installcheck, but neither will most of the FDW checks.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+-- Unpriv user cannot make the mapping passwordless
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+ERROR: password_required=false is superuser-only
+HINT: User mappings with the password_required option set to false may only be created or modified by the superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+RESET ROLE;
+-- But the superuser can
+ALTER USER MAPPING FOR regress_nosuper SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+SET ROLE regress_nosuper;
+-- Should finally work now
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- unpriv user also cannot set sslcert / sslkey on the user mapping
+-- first set password_required so we see the right error messages
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (SET password_required 'true');
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslcert 'foo.crt');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslkey 'foo.key');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+-- We're done with the role named after a specific user and need to check the
+-- changes to the public mapping.
+DROP USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+-- This will fail again as it'll resolve the user mapping for public, which
+-- lacks password_required=false
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+RESET ROLE;
+-- The user mapping for public is passwordless and lacks the password_required=false
+-- mapping option, but will work because the current user is a superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- cleanup
+DROP USER MAPPING FOR public SERVER loopback_nopw;
+DROP OWNED BY regress_nosuper;
+DROP ROLE regress_nosuper;
+-- Clean-up
+RESET enable_partitionwise_aggregate;
+-- Two-phase transactions are not supported.
+BEGIN;
+SELECT count(*) FROM ft1;
+ count
+-------
+ 822
+(1 row)
+
+-- error here
+PREPARE TRANSACTION 'fdw_tpc';
+ERROR: cannot PREPARE a transaction that has operated on postgres_fdw foreign tables
+ROLLBACK;
+WARNING: there is no transaction in progress
+-- ===================================================================
+-- reestablish new connection
+-- ===================================================================
+-- Change application_name of remote connection to special one
+-- so that we can easily terminate the connection later.
+ALTER SERVER loopback OPTIONS (application_name 'fdw_retry_check');
+-- If debug_discard_caches is active, it results in
+-- dropping remote connections after every transaction, making it
+-- impossible to test termination meaningfully. So turn that off
+-- for this test.
+SET debug_discard_caches = 0;
+-- Make sure we have a remote connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- This query should detect the broken connection when starting new remote
+-- transaction, reestablish new connection, and then succeed.
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- If we detect the broken connection when starting a new remote
+-- subtransaction, we should fail instead of establishing a new connection.
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+SAVEPOINT s;
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT 1 FROM ft1 LIMIT 1; -- should fail
+ERROR: 08006
+\set VERBOSITY default
+COMMIT;
+RESET debug_discard_caches;
+-- =============================================================================
+-- test connection invalidation cases and postgres_fdw_get_connections function
+-- =============================================================================
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- This test case is for closing the connection in pgfdw_xact_callback
+BEGIN;
+-- Connection xact depth becomes 1 i.e. the connection is in midst of the xact.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT 1 FROM ft7 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback3 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback3
+(2 rows)
+
+-- Connections are not closed at the end of the alter and drop statements.
+-- That's because the connections are in midst of this xact,
+-- they are just marked as invalid in pgfdw_inval_callback.
+ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
+DROP SERVER loopback3 CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to user mapping for public on server loopback3
+drop cascades to foreign table ft7
+-- List all the existing cached connections. loopback and loopback3
+-- should be output as invalid connections. Also the server name for
+-- loopback3 should be NULL because the server was dropped.
+SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | valid
+-------------+-------
+ loopback | f
+ | f
+(2 rows)
+
+-- The invalid connections get closed in pgfdw_xact_callback during commit.
+COMMIT;
+-- All cached connections were closed while committing above xact, so no
+-- records should be output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+(0 rows)
+
+-- =======================================================================
+-- test postgres_fdw_disconnect and postgres_fdw_disconnect_all functions
+-- =======================================================================
+BEGIN;
+-- Ensure to cache loopback connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Ensure to cache loopback2 connection.
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Issue a warning and return false as loopback connection is still in use and
+-- can not be closed.
+SELECT postgres_fdw_disconnect('loopback');
+WARNING: cannot close connection for server "loopback" because it is still in use
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Return false as connections are still in use, warnings are issued.
+-- But disable warnings temporarily because the order of them is not stable.
+SET client_min_messages = 'ERROR';
+SELECT postgres_fdw_disconnect_all();
+ postgres_fdw_disconnect_all
+-----------------------------
+ f
+(1 row)
+
+RESET client_min_messages;
+COMMIT;
+-- Ensure that loopback2 connection is closed.
+SELECT 1 FROM postgres_fdw_disconnect('loopback2');
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT server_name FROM postgres_fdw_get_connections() WHERE server_name = 'loopback2';
+ server_name
+-------------
+(0 rows)
+
+-- Return false as loopback2 connection is closed already.
+SELECT postgres_fdw_disconnect('loopback2');
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- Return an error as there is no foreign server with given name.
+SELECT postgres_fdw_disconnect('unknownserver');
+ERROR: server "unknownserver" does not exist
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- =============================================================================
+-- test case for having multiple cached connections for a foreign server
+-- =============================================================================
+CREATE ROLE regress_multi_conn_user1 SUPERUSER;
+CREATE ROLE regress_multi_conn_user2 SUPERUSER;
+CREATE USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+CREATE USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+BEGIN;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user1
+SET ROLE regress_multi_conn_user1;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user2
+SET ROLE regress_multi_conn_user2;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Should output two connections for loopback server
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback
+(2 rows)
+
+COMMIT;
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- Clean up
+DROP USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+DROP USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+DROP ROLE regress_multi_conn_user1;
+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
+-- ===================================================================
+BEGIN;
+CREATE SERVER batch10 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( batch_size '10' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER batch10 OPTIONS( SET batch_size '20' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=20'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30 ( x int ) SERVER batch10 OPTIONS ( batch_size '30' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30 OPTIONS ( SET batch_size '40');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=40'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+CREATE TABLE batch_table ( x int );
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '10' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 10
+ -> Function Scan on pg_catalog.generate_series i
+ Output: i.i
+ Function Call: generate_series(1, 10)
+(6 rows)
+
+INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+INSERT INTO ftable SELECT * FROM generate_series(11, 31) i;
+INSERT INTO ftable VALUES (32);
+INSERT INTO ftable VALUES (33), (34);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 34
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- try if large batches exceed max number of bind parameters
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '100000' );
+INSERT INTO ftable SELECT * FROM generate_series(1, 70000) i;
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 70000
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- Disable batch insert
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '1' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (1), (2);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 2
+(1 row)
+
+-- Disable batch inserting into foreign tables with BEFORE ROW INSERT triggers
+-- even if the batch_size option is enabled.
+ALTER FOREIGN TABLE ftable OPTIONS ( SET batch_size '10' );
+CREATE TRIGGER trig_row_before BEFORE INSERT ON ftable
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (3), (4);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (3), (4);
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (3)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (4)
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 4
+(1 row)
+
+-- Clean up
+DROP TRIGGER trig_row_before ON ftable;
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+-- Use partitioning
+CREATE TABLE batch_table ( x int ) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0', batch_size '10');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1', batch_size '1');
+CREATE TABLE batch_table_p2
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 2);
+INSERT INTO batch_table SELECT * FROM generate_series(1, 66) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 66
+(1 row)
+
+-- Check that enabling batched inserts doesn't interfere with cross-partition
+-- updates
+CREATE TABLE batch_cp_upd_test (a int) PARTITION BY LIST (a);
+CREATE TABLE batch_cp_upd_test1 (LIKE batch_cp_upd_test);
+CREATE FOREIGN TABLE batch_cp_upd_test1_f
+ PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_cp_upd_test1', batch_size '10');
+CREATE TABLE batch_cp_up_test1 PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (2);
+INSERT INTO batch_cp_upd_test VALUES (1), (2);
+-- The following moves a row from the local partition to the foreign one
+UPDATE batch_cp_upd_test t SET a = 1 FROM (VALUES (1), (2)) s(a) WHERE t.a = s.a;
+ERROR: cannot route tuples into foreign table to be updated "batch_cp_upd_test1_f"
+SELECT tableoid::regclass, * FROM batch_cp_upd_test;
+ tableoid | a
+----------------------+---
+ batch_cp_upd_test1_f | 1
+ batch_cp_up_test1 | 2
+(2 rows)
+
+-- Clean up
+DROP TABLE batch_table, batch_cp_upd_test, batch_table_p0, batch_table_p1 CASCADE;
+-- Use partitioning
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+CREATE TABLE batch_table ( x int, field1 text, field2 text) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+ALTER TABLE batch_table_p0 ADD CONSTRAINT p0_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+ALTER TABLE batch_table_p1 ADD CONSTRAINT p1_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1');
+INSERT INTO batch_table SELECT i, 'test'||i, 'test'|| i FROM generate_series(1, 50) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 50
+(1 row)
+
+SELECT * FROM batch_table ORDER BY x;
+ x | field1 | field2
+----+--------+--------
+ 1 | test1 | test1
+ 2 | test2 | test2
+ 3 | test3 | test3
+ 4 | test4 | test4
+ 5 | test5 | test5
+ 6 | test6 | test6
+ 7 | test7 | test7
+ 8 | test8 | test8
+ 9 | test9 | test9
+ 10 | test10 | test10
+ 11 | test11 | test11
+ 12 | test12 | test12
+ 13 | test13 | test13
+ 14 | test14 | test14
+ 15 | test15 | test15
+ 16 | test16 | test16
+ 17 | test17 | test17
+ 18 | test18 | test18
+ 19 | test19 | test19
+ 20 | test20 | test20
+ 21 | test21 | test21
+ 22 | test22 | test22
+ 23 | test23 | test23
+ 24 | test24 | test24
+ 25 | test25 | test25
+ 26 | test26 | test26
+ 27 | test27 | test27
+ 28 | test28 | test28
+ 29 | test29 | test29
+ 30 | test30 | test30
+ 31 | test31 | test31
+ 32 | test32 | test32
+ 33 | test33 | test33
+ 34 | test34 | test34
+ 35 | test35 | test35
+ 36 | test36 | test36
+ 37 | test37 | test37
+ 38 | test38 | test38
+ 39 | test39 | test39
+ 40 | test40 | test40
+ 41 | test41 | test41
+ 42 | test42 | test42
+ 43 | test43 | test43
+ 44 | test44 | test44
+ 45 | test45 | test45
+ 46 | test46 | test46
+ 47 | test47 | test47
+ 48 | test48 | test48
+ 49 | test49 | test49
+ 50 | test50 | test50
+(50 rows)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+-- ===================================================================
+-- test asynchronous execution
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD async_capable 'true');
+ALTER SERVER loopback2 OPTIONS (ADD async_capable 'true');
+CREATE TABLE async_pt (a int, b int, c text) PARTITION BY RANGE (a);
+CREATE TABLE base_tbl1 (a int, b int, c text);
+CREATE TABLE base_tbl2 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p1 PARTITION OF async_pt FOR VALUES FROM (1000) TO (2000)
+ SERVER loopback OPTIONS (table_name 'base_tbl1');
+CREATE FOREIGN TABLE async_p2 PARTITION OF async_pt FOR VALUES FROM (2000) TO (3000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl2');
+INSERT INTO async_p1 SELECT 1000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+INSERT INTO async_p2 SELECT 2000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+-- simple queries
+CREATE TABLE result_tbl (a int, b int, c text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE (((b % 100) = 0))
+(8 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1000 | 0 | 0000
+ 1100 | 100 | 0100
+ 1200 | 200 | 0200
+ 1300 | 300 | 0300
+ 1400 | 400 | 0400
+ 1500 | 500 | 0500
+ 1600 | 600 | 0600
+ 1700 | 700 | 0700
+ 1800 | 800 | 0800
+ 1900 | 900 | 0900
+ 2000 | 0 | 0000
+ 2100 | 100 | 0100
+ 2200 | 200 | 0200
+ 2300 | 300 | 0300
+ 2400 | 400 | 0400
+ 2500 | 500 | 0500
+ 2600 | 600 | 0600
+ 2700 | 700 | 0700
+ 2800 | 800 | 0800
+ 2900 | 900 | 0900
+(20 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, ('AAA'::text || async_pt_1.c)
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, ('AAA'::text || async_pt_2.c)
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+---------
+ 1505 | 505 | AAA0505
+ 2505 | 505 | AAA0505
+(2 rows)
+
+DELETE FROM result_tbl;
+-- Check case where multiple partitions use the same connection
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl3');
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Async Foreign Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(14 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+DROP FOREIGN TABLE async_p3;
+DROP TABLE base_tbl3;
+-- Check case where the partitioned table has local/remote partitions
+CREATE TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000);
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+(13 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+-- partitionwise joins
+SET enable_partitionwise_join TO true;
+CREATE TABLE join_tbl (a1 int, b1 int, c1 text, a2 int, b2 int, c2 text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t2_1.b, t2_1.c
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t2_2.b, t2_2.c
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, t1_3.c, t2_3.a, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+ 2000 | 0 | 0000 | 2000 | 0 | 0000
+ 2100 | 100 | 0100 | 2100 | 100 | 0100
+ 2200 | 200 | 0200 | 2200 | 200 | 0200
+ 2300 | 300 | 0300 | 2300 | 300 | 0300
+ 2400 | 400 | 0400 | 2400 | 400 | 0400
+ 2500 | 500 | 0500 | 2500 | 500 | 0500
+ 2600 | 600 | 0600 | 2600 | 600 | 0600
+ 2700 | 700 | 0700 | 2700 | 700 | 0700
+ 2800 | 800 | 0800 | 2800 | 800 | 0800
+ 2900 | 900 | 0900 | 2900 | 900 | 0900
+ 3000 | 0 | 0000 | 3000 | 0 | 0000
+ 3100 | 100 | 0100 | 3100 | 100 | 0100
+ 3200 | 200 | 0200 | 3200 | 200 | 0200
+ 3300 | 300 | 0300 | 3300 | 300 | 0300
+ 3400 | 400 | 0400 | 3400 | 400 | 0400
+ 3500 | 500 | 0500 | 3500 | 500 | 0500
+ 3600 | 600 | 0600 | 3600 | 600 | 0600
+ 3700 | 700 | 0700 | 3700 | 700 | 0700
+ 3800 | 800 | 0800 | 3800 | 800 | 0800
+ 3900 | 900 | 0900 | 3900 | 900 | 0900
+(30 rows)
+
+DELETE FROM join_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, ('AAA'::text || t1_1.c), t2_1.a, t2_1.b, ('AAA'::text || t2_1.c)
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, ('AAA'::text || t1_2.c), t2_2.a, t2_2.b, ('AAA'::text || t2_2.c)
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, ('AAA'::text || t1_3.c), t2_3.a, t2_3.b, ('AAA'::text || t2_3.c)
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+---------+------+-----+---------
+ 1000 | 0 | AAA0000 | 1000 | 0 | AAA0000
+ 1100 | 100 | AAA0100 | 1100 | 100 | AAA0100
+ 1200 | 200 | AAA0200 | 1200 | 200 | AAA0200
+ 1300 | 300 | AAA0300 | 1300 | 300 | AAA0300
+ 1400 | 400 | AAA0400 | 1400 | 400 | AAA0400
+ 1500 | 500 | AAA0500 | 1500 | 500 | AAA0500
+ 1600 | 600 | AAA0600 | 1600 | 600 | AAA0600
+ 1700 | 700 | AAA0700 | 1700 | 700 | AAA0700
+ 1800 | 800 | AAA0800 | 1800 | 800 | AAA0800
+ 1900 | 900 | AAA0900 | 1900 | 900 | AAA0900
+ 2000 | 0 | AAA0000 | 2000 | 0 | AAA0000
+ 2100 | 100 | AAA0100 | 2100 | 100 | AAA0100
+ 2200 | 200 | AAA0200 | 2200 | 200 | AAA0200
+ 2300 | 300 | AAA0300 | 2300 | 300 | AAA0300
+ 2400 | 400 | AAA0400 | 2400 | 400 | AAA0400
+ 2500 | 500 | AAA0500 | 2500 | 500 | AAA0500
+ 2600 | 600 | AAA0600 | 2600 | 600 | AAA0600
+ 2700 | 700 | AAA0700 | 2700 | 700 | AAA0700
+ 2800 | 800 | AAA0800 | 2800 | 800 | AAA0800
+ 2900 | 900 | AAA0900 | 2900 | 900 | AAA0900
+ 3000 | 0 | AAA0000 | 3000 | 0 | AAA0000
+ 3100 | 100 | AAA0100 | 3100 | 100 | AAA0100
+ 3200 | 200 | AAA0200 | 3200 | 200 | AAA0200
+ 3300 | 300 | AAA0300 | 3300 | 300 | AAA0300
+ 3400 | 400 | AAA0400 | 3400 | 400 | AAA0400
+ 3500 | 500 | AAA0500 | 3500 | 500 | AAA0500
+ 3600 | 600 | AAA0600 | 3600 | 600 | AAA0600
+ 3700 | 700 | AAA0700 | 3700 | 700 | AAA0700
+ 3800 | 800 | AAA0800 | 3800 | 800 | AAA0800
+ 3900 | 900 | AAA0900 | 3900 | 900 | AAA0900
+(30 rows)
+
+DELETE FROM join_tbl;
+RESET enable_partitionwise_join;
+-- Test rescan of an async Append node with do_exec_prune=false
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: ((t1.a = t2.a) AND (t1.b = t2.b))
+ -> Foreign Scan on public.async_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t2_1
+ Output: t2_1.a, t2_1.b, t2_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t2_2
+ Output: t2_2.a, t2_2.b, t2_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+(16 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+(10 rows)
+
+DELETE FROM join_tbl;
+RESET enable_hashjoin;
+-- Test interaction of async execution with plan-time partition pruning
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 3000;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(7 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 2000;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Foreign Scan on public.async_p1 async_pt
+ Output: async_pt.a, async_pt.b, async_pt.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 2000))
+(3 rows)
+
+-- Test interaction of async execution with run-time partition pruning
+SET plan_cache_mode TO force_generic_plan;
+PREPARE async_pt_query (int, int) AS
+ INSERT INTO result_tbl SELECT * FROM async_pt WHERE a < $1 AND b === $2;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (3000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 1
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < $1::integer))
+(11 rows)
+
+EXECUTE async_pt_query (3000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (2000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 2
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+(7 rows)
+
+EXECUTE async_pt_query (2000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+(1 row)
+
+DELETE FROM result_tbl;
+RESET plan_cache_mode;
+CREATE TABLE local_tbl(a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo'), (2505, 505, 'bar');
+ANALYZE local_tbl;
+CREATE INDEX base_tbl1_idx ON base_tbl1 (a);
+CREATE INDEX base_tbl2_idx ON base_tbl2 (a);
+CREATE INDEX async_p3_idx ON async_p3 (a);
+ANALYZE base_tbl1;
+ANALYZE base_tbl2;
+ANALYZE async_p3;
+ALTER FOREIGN TABLE async_p1 OPTIONS (use_remote_estimate 'true');
+ALTER FOREIGN TABLE async_p2 OPTIONS (use_remote_estimate 'true');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: local_tbl.a, local_tbl.b, local_tbl.c, async_pt.a, async_pt.b, async_pt.c
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ Filter: (local_tbl.c = 'bar'::text)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (($1::integer = a))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE (($1::integer = a))
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (local_tbl.a = async_pt_3.a)
+(15 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Nested Loop (actual rows=1 loops=1)
+ -> Seq Scan on local_tbl (actual rows=1 loops=1)
+ Filter: (c = 'bar'::text)
+ Rows Removed by Filter: 1
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (never executed)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=1 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (never executed)
+ Filter: (local_tbl.a = a)
+(9 rows)
+
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ a | b | c | a | b | c
+------+-----+-----+------+-----+------
+ 2505 | 505 | bar | 2505 | 505 | 0505
+(1 row)
+
+ALTER FOREIGN TABLE async_p1 OPTIONS (DROP use_remote_estimate);
+ALTER FOREIGN TABLE async_p2 OPTIONS (DROP use_remote_estimate);
+DROP TABLE local_tbl;
+DROP INDEX base_tbl1_idx;
+DROP INDEX base_tbl2_idx;
+DROP INDEX async_p3_idx;
+-- UNION queries
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> HashAggregate
+ Output: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ Group Key: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(11 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(8 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+-- Disable async execution if we use gating Result nodes for pseudoconstant
+-- quals
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Result
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+(18 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+(SELECT * FROM async_p1 WHERE CURRENT_USER = SESSION_USER)
+UNION ALL
+(SELECT * FROM async_p2 WHERE CURRENT_USER = SESSION_USER);
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(13 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ((SELECT * FROM async_p1 WHERE b < 10) UNION ALL (SELECT * FROM async_p2 WHERE b < 10)) s WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((b < 10))
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(13 rows)
+
+-- Test that pending requests are processed properly
+SET enable_mergejoin TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: (t1.a = t2.a)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+ -> Materialize
+ Output: t2.a, t2.b, t2.c
+ -> Foreign Scan on public.async_p2 t2
+ Output: t2.a, t2.b, t2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(20 rows)
+
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ a | b | c | a | b | c
+------+-----+------+------+-----+------
+ 2505 | 505 | 0505 | 2505 | 505 | 0505
+(1 row)
+
+CREATE TABLE local_tbl (a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo');
+ANALYZE local_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, async_pt.a, async_pt.b, async_pt.c, ($0)
+ Join Filter: (t1.a = async_pt.a)
+ InitPlan 1 (returns $0)
+ -> Aggregate
+ Output: count(*)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_4
+ Remote SQL: SELECT NULL FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_5
+ Remote SQL: SELECT NULL FROM public.base_tbl2 WHERE ((a < 3000))
+ -> Seq Scan on public.local_tbl t1
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(20 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Nested Loop Left Join (actual rows=1 loops=1)
+ Join Filter: (t1.a = async_pt.a)
+ Rows Removed by Join Filter: 399
+ InitPlan 1 (returns $0)
+ -> Aggregate (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_4 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_5 (actual rows=200 loops=1)
+ -> Seq Scan on local_tbl t1 (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=200 loops=1)
+(12 rows)
+
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ a | b | c | a | b | c | count
+------+-----+-----+------+-----+------+-------
+ 1505 | 505 | foo | 1505 | 505 | 0505 | 400
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+----------------------------------------------------------------
+ Limit
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+(14 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit (actual rows=1 loops=1)
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 t1_1 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Async Foreign Scan on async_p2 t1_2 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Seq Scan on async_p3 t1_3 (actual rows=1 loops=1)
+ Filter: (b === 505)
+ Rows Removed by Filter: 101
+(9 rows)
+
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ a | b | c
+------+-----+------
+ 3505 | 505 | 0505
+(1 row)
+
+-- Check with foreign modify
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE remote_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl3');
+INSERT INTO remote_tbl VALUES (2505, 505, 'bar');
+CREATE TABLE base_tbl4 (a int, b int, c text);
+CREATE FOREIGN TABLE insert_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl4');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Insert on public.insert_tbl
+ Remote SQL: INSERT INTO public.base_tbl4(a, b, c) VALUES ($1, $2, $3)
+ Batch Size: 1
+ -> Append
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ -> Async Foreign Scan on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(9 rows)
+
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+SELECT * FROM insert_tbl ORDER BY a;
+ a | b | c
+------+-----+-----
+ 1505 | 505 | foo
+ 2505 | 505 | bar
+(2 rows)
+
+-- Check with direct modify
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ CTE t
+ -> Update on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ -> Foreign Update on public.remote_tbl
+ Remote SQL: UPDATE public.base_tbl3 SET c = (c || c) RETURNING a, b, c
+ -> Nested Loop Left Join
+ Output: async_pt.a, async_pt.b, async_pt.c, t.a, t.b, t.c
+ Join Filter: ((async_pt.a = t.a) AND (async_pt.b = t.b))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ -> CTE Scan on t
+ Output: t.a, t.b, t.c
+(23 rows)
+
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+--------
+ 1505 | 505 | 0505 | | |
+ 2505 | 505 | 0505 | 2505 | 505 | barbar
+ 3505 | 505 | 0505 | | |
+(3 rows)
+
+DELETE FROM join_tbl;
+DROP TABLE local_tbl;
+DROP FOREIGN TABLE remote_tbl;
+DROP FOREIGN TABLE insert_tbl;
+DROP TABLE base_tbl3;
+DROP TABLE base_tbl4;
+RESET enable_mergejoin;
+RESET enable_hashjoin;
+-- Test that UPDATE/DELETE with inherited target works with async_capable enabled
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Update on public.async_p1 async_pt_1
+ Foreign Update on public.async_p2 async_pt_2
+ Update on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Update on public.async_p1 async_pt_1
+ Remote SQL: UPDATE public.base_tbl1 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Update on public.async_p2 async_pt_2
+ Remote SQL: UPDATE public.base_tbl2 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: (async_pt_3.c || async_pt_3.c), async_pt_3.tableoid, async_pt_3.ctid, NULL::record
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Delete on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Delete on public.async_p1 async_pt_1
+ Foreign Delete on public.async_p2 async_pt_2
+ Delete on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Delete on public.async_p1 async_pt_1
+ Remote SQL: DELETE FROM public.base_tbl1 WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Delete on public.async_p2 async_pt_2
+ Remote SQL: DELETE FROM public.base_tbl2 WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.tableoid, async_pt_3.ctid
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+-- Check EXPLAIN ANALYZE for a query that scans empty partitions asynchronously
+DELETE FROM async_p1;
+DELETE FROM async_p2;
+DELETE FROM async_p3;
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Append (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=0 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (actual rows=0 loops=1)
+(4 rows)
+
+-- Clean up
+DROP TABLE async_pt;
+DROP TABLE base_tbl1;
+DROP TABLE base_tbl2;
+DROP TABLE result_tbl;
+DROP TABLE join_tbl;
+-- Test that an asynchronous fetch is processed before restarting the scan in
+-- ReScanForeignScan
+CREATE TABLE base_tbl (a int, b int);
+INSERT INTO base_tbl VALUES (1, 11), (2, 22), (3, 33);
+CREATE FOREIGN TABLE foreign_tbl (b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE FOREIGN TABLE foreign_tbl2 () INHERITS (foreign_tbl)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Seq Scan on public.base_tbl
+ Output: base_tbl.a
+ Filter: (SubPlan 1)
+ SubPlan 1
+ -> Result
+ Output: base_tbl.a
+ -> Append
+ -> Async Foreign Scan on public.foreign_tbl foreign_tbl_1
+ Remote SQL: SELECT NULL FROM public.base_tbl
+ -> Async Foreign Scan on public.foreign_tbl2 foreign_tbl_2
+ Remote SQL: SELECT NULL FROM public.base_tbl
+(11 rows)
+
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ a
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+-- Clean up
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to foreign table foreign_tbl2
+DROP TABLE base_tbl;
+ALTER SERVER loopback OPTIONS (DROP async_capable);
+ALTER SERVER loopback2 OPTIONS (DROP async_capable);
+-- ===================================================================
+-- test invalid server, foreign table and foreign data wrapper options
+-- ===================================================================
+-- Invalid fdw_startup_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_startup_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_startup_cost": 100$%$#$#
+-- Invalid fdw_tuple_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_tuple_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_tuple_cost": 100$%$#$#
+-- Invalid fetch_size option
+CREATE FOREIGN TABLE inv_fsz (c1 int )
+ SERVER loopback OPTIONS (fetch_size '100$%$#$#');
+ERROR: invalid value for integer option "fetch_size": 100$%$#$#
+-- Invalid batch_size option
+CREATE FOREIGN TABLE inv_bsz (c1 int )
+ SERVER loopback OPTIONS (batch_size '100$%$#$#');
+ERROR: invalid value for integer option "batch_size": 100$%$#$#
+-- No option is allowed to be specified at foreign data wrapper level
+ALTER FOREIGN DATA WRAPPER postgres_fdw OPTIONS (nonexistent 'fdw');
+ERROR: invalid option "nonexistent"
+HINT: There are no valid options in this context.
+-- ===================================================================
+-- test postgres_fdw.application_name GUC
+-- ===================================================================
+--- Turn debug_discard_caches off for this test to make sure that
+--- the remote connection is alive when checking its application_name.
+SET debug_discard_caches = 0;
+-- Specify escape sequences in application_name option of a server
+-- object so as to test that they are replaced with status information
+-- expectedly.
+--
+-- Since pg_stat_activity.application_name may be truncated to less than
+-- NAMEDATALEN characters, note that substring() needs to be used
+-- at the condition of test query to make sure that the string consisting
+-- of database name and process ID is also less than that.
+ALTER SERVER loopback2 OPTIONS (application_name 'fdw_%d%p');
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_database() || pg_backend_pid() for
+ current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- postgres_fdw.application_name overrides application_name option
+-- of a server object if both settings are present.
+SET postgres_fdw.application_name TO 'fdw_%a%u%%';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('application_name') ||
+ CURRENT_USER || '%' for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- Test %c (session ID) and %C (cluster name) escape sequences.
+SET postgres_fdw.application_name TO 'fdw_%C%c';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('cluster_name') ||
+ to_hex(trunc(EXTRACT(EPOCH FROM (SELECT backend_start FROM
+ pg_stat_get_activity(pg_backend_pid()))))::integer) || '.' ||
+ to_hex(pg_backend_pid())
+ for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+--Clean up
+RESET postgres_fdw.application_name;
+RESET debug_discard_caches;
+-- ===================================================================
+-- test parallel commit
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (ADD parallel_commit 'true');
+ALTER SERVER loopback2 OPTIONS (ADD parallel_commit 'true');
+CREATE TABLE ploc1 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem1 (f1 int, f2 text)
+ SERVER loopback OPTIONS (table_name 'ploc1');
+CREATE TABLE ploc2 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem2 (f1 int, f2 text)
+ SERVER loopback2 OPTIONS (table_name 'ploc2');
+BEGIN;
+INSERT INTO prem1 VALUES (101, 'foo');
+INSERT INTO prem2 VALUES (201, 'bar');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+-----
+ 101 | foo
+(1 row)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+-----
+ 201 | bar
+(1 row)
+
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (102, 'foofoo');
+INSERT INTO prem2 VALUES (202, 'barbar');
+RELEASE SAVEPOINT s;
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+(2 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+(2 rows)
+
+-- This tests executing DEALLOCATE ALL against foreign servers in parallel
+-- during pre-commit
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (103, 'baz');
+INSERT INTO prem2 VALUES (203, 'qux');
+ROLLBACK TO SAVEPOINT s;
+RELEASE SAVEPOINT s;
+INSERT INTO prem1 VALUES (104, 'bazbaz');
+INSERT INTO prem2 VALUES (204, 'quxqux');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+ 104 | bazbaz
+(3 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+ 204 | quxqux
+(3 rows)
+
+ALTER SERVER loopback OPTIONS (DROP parallel_commit);
+ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for health-check feature
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Set GUC for checking the health of remote servers
+SET postgres_fdw.health_check_interval TO '1s';
+ERROR: invalid value for parameter "postgres_fdw.health_check_interval": 1000
+DETAIL: postgres_fdw.health_check_interval must be set to 0 on this platform
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+-- FIXME: this should be skipped in some platforms
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- While sleeping the process down will be detected.
+SELECT pg_sleep(3);
+ pg_sleep
+----------
+
+(1 row)
+
+COMMIT;
+ERROR: server closed the connection unexpectedly
+ This probably means the server terminated abnormally
+ before or while processing the request.
+CONTEXT: remote SQL command: COMMIT TRANSACTION
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index e48ccd286b..375cde1b84 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3682,3 +3682,30 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+
+-- ===================================================================
+-- test for health-check feature
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Set GUC for checking the health of remote servers
+SET postgres_fdw.health_check_interval TO '1s';
+
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+-- Terminate the remote backend process
+-- FIXME: this should be skipped in some platforms
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+-- While sleeping the process down will be detected.
+SELECT pg_sleep(3);
+COMMIT;
+
+-- Clean up
+RESET debug_discard_caches;
--
2.27.0
v16-0001-Add-an-infrastracture-for-checking-remote-server.patchapplication/octet-stream; name=v16-0001-Add-an-infrastracture-for-checking-remote-server.patchDownload
From df7068c18cda5dd5662e2a8c0eedaa025543a43c Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:02:45 +0000
Subject: [PATCH v16 1/4] Add an infrastracture for checking remote servers
This patch adds a mechanism for registering callback functions.
They should be used for checking health of remote servers.
These functions will be called when flags CheckingRemoteServersTimeoutPending and InterruptPending are set to true.
CheckingRemoteServersTimeoutPending is expected that it is set from signal handlers, which is registered by FDWs.
Inside the function a signal SIGINT should be raised and a message should be set to QueryCancelMessage
if one of remote servers is disconnected. To fill the message new API TrySetQueryCancelMessage can be used.
When a query is canceled and a string is set to QueryCancelMessage,
the server will output the given message to the log instead of the normal message.
Note that TrySetQueryCancelMessage does not allow to override the QueryCancelMessage.
If the function is called but the message is already filled, returns immediately
---
src/backend/foreign/foreign.c | 57 ++++++++++++++++++++++++++++++++
src/backend/tcop/postgres.c | 50 ++++++++++++++++++++++++++++
src/backend/utils/init/globals.c | 1 +
src/include/foreign/foreign.h | 19 +++++++++++
src/include/miscadmin.h | 2 ++
src/include/tcop/tcopprot.h | 3 ++
6 files changed, 132 insertions(+)
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index 353e20a0cf..fbc943bea9 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -28,7 +28,9 @@
#include "utils/rel.h"
#include "utils/syscache.h"
#include "utils/varlena.h"
+#include "utils/timeout.h"
+static CheckingRemoteServersCallbackItem *remote_check_callbacks = NULL;
/*
* GetForeignDataWrapper - look up the foreign-data wrapper by OID.
@@ -810,3 +812,58 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
}
return NULL;
}
+
+
+/*
+ * Register callbacks for checking remote servers.
+ *
+ * This function is intended for use by FDW extensions.
+ */
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+
+ item = (CheckingRemoteServersCallbackItem *)
+ MemoryContextAlloc(TopMemoryContext,
+ sizeof(CheckingRemoteServersCallbackItem));
+ item->callback = callback;
+ item->arg = arg;
+ item->next = remote_check_callbacks;
+ remote_check_callbacks = item;
+}
+
+void
+UnRegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+ CheckingRemoteServersCallbackItem *prev;
+
+ prev = NULL;
+ for (item = remote_check_callbacks; item; prev = item, item = item->next)
+ {
+ if (item->callback == callback && item->arg == arg)
+ {
+ if (prev)
+ prev->next = item->next;
+ else
+ remote_check_callbacks = item->next;
+ pfree(item);
+ break;
+ }
+ }
+}
+
+/*
+ * Call callbacks for checking remote servers.
+ */
+void
+CallCheckingRemoteServersCallbacks(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+
+ for (item = remote_check_callbacks; item; item = item->next)
+ item->callback(item->arg);
+}
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index 5352d5f4c6..5a24e4f0a4 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -35,6 +35,7 @@
#include "commands/async.h"
#include "commands/prepare.h"
#include "common/pg_prng.h"
+#include "foreign/foreign.h"
#include "jit/jit.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@@ -166,6 +167,9 @@ static ProcSignalReason RecoveryConflictReason;
static MemoryContext row_description_context = NULL;
static StringInfoData row_description_buf;
+/* Message string for canceling qurery caused by extensions */
+static char *QueryCancelMessage = NULL;
+
/* ----------------------------------------------------------------
* decls for routines only used in this file
* ----------------------------------------------------------------
@@ -3226,6 +3230,13 @@ ProcessInterrupts(void)
errmsg("connection to client lost")));
}
+ if (CheckingRemoteServersTimeoutPending)
+ {
+ CheckingRemoteServersTimeoutPending = false;
+
+ CallCheckingRemoteServersCallbacks();
+ }
+
/*
* If a recovery conflict happens while we are waiting for input from the
* client, the client is presumably just sitting idle in a transaction,
@@ -3330,8 +3341,21 @@ ProcessInterrupts(void)
LockErrorCleanup();
ereport(ERROR,
(errcode(ERRCODE_QUERY_CANCELED),
+ QueryCancelMessage ?
+ errmsg("%s", QueryCancelMessage) :
errmsg("canceling statement due to user request")));
}
+
+ /*
+ * If a cancel request from FDW is ignored, we expect that it raise SIGINT and
+ * fill QueryCancelMessage again. But some FDWs may skip its health check if
+ * we already have a cancel message. To avoid that we clean up it.
+ */
+ if (QueryCancelMessage != NULL)
+ {
+ pfree(QueryCancelMessage);
+ QueryCancelMessage = NULL;
+ }
}
if (IdleInTransactionSessionTimeoutPending)
@@ -4266,6 +4290,9 @@ PostgresMain(const char *dbname, const char *username)
/* Report the error to the client and/or server log */
EmitErrorReport();
+ /* Make sure QueryCancelMessage is reset. */
+ QueryCancelMessage = NULL;
+
/*
* Make sure debug_query_string gets reset before we possibly clobber
* the storage it points at.
@@ -5024,3 +5051,26 @@ disable_statement_timeout(void)
if (get_timeout_active(STATEMENT_TIMEOUT))
disable_timeout(STATEMENT_TIMEOUT, false);
}
+
+bool
+TrySetQueryCancelMessage(char *message)
+{
+ if (!HasQueryCancelMessage())
+ {
+ MemoryContext old;
+
+ old = MemoryContextSwitchTo(CurTransactionContext);
+ QueryCancelMessage = pstrdup(message);
+ MemoryContextSwitchTo(old);
+
+ return true;
+ }
+
+ return false;
+}
+
+bool
+HasQueryCancelMessage(void)
+{
+ return QueryCancelMessage != NULL;
+}
diff --git a/src/backend/utils/init/globals.c b/src/backend/utils/init/globals.c
index 1a5d29ac9b..bb94adfea8 100644
--- a/src/backend/utils/init/globals.c
+++ b/src/backend/utils/init/globals.c
@@ -37,6 +37,7 @@ volatile sig_atomic_t IdleSessionTimeoutPending = false;
volatile sig_atomic_t ProcSignalBarrierPending = false;
volatile sig_atomic_t LogMemoryContextPending = false;
volatile sig_atomic_t IdleStatsUpdateTimeoutPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
volatile uint32 InterruptHoldoffCount = 0;
volatile uint32 QueryCancelHoldoffCount = 0;
volatile uint32 CritSectionCount = 0;
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index ac82125530..9859513ac6 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -82,4 +82,23 @@ extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum);
extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok);
extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);
+
+/* Functions and variables for fdw checking */
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+
+typedef struct CheckingRemoteServersCallbackItem CheckingRemoteServersCallbackItem;
+
+struct CheckingRemoteServersCallbackItem
+{
+ CheckingRemoteServersCallbackItem *next;
+ CheckingRemoteServersCallback callback;
+ void *arg;
+};
+
+extern void RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg);
+extern void UnRegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg);
+extern void CallCheckingRemoteServersCallbacks(void);
+
#endif /* FOREIGN_H */
diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h
index e7ebea4ff4..75697e2be0 100644
--- a/src/include/miscadmin.h
+++ b/src/include/miscadmin.h
@@ -99,6 +99,8 @@ extern PGDLLIMPORT volatile sig_atomic_t IdleStatsUpdateTimeoutPending;
extern PGDLLIMPORT volatile sig_atomic_t CheckClientConnectionPending;
extern PGDLLIMPORT volatile sig_atomic_t ClientConnectionLost;
+extern PGDLLIMPORT volatile sig_atomic_t CheckingRemoteServersTimeoutPending;
+
/* these are marked volatile because they are examined by signal handlers: */
extern PGDLLIMPORT volatile uint32 InterruptHoldoffCount;
extern PGDLLIMPORT volatile uint32 QueryCancelHoldoffCount;
diff --git a/src/include/tcop/tcopprot.h b/src/include/tcop/tcopprot.h
index 5d34978f32..5d1216f170 100644
--- a/src/include/tcop/tcopprot.h
+++ b/src/include/tcop/tcopprot.h
@@ -91,4 +91,7 @@ extern bool set_plan_disabling_options(const char *arg,
GucContext context, GucSource source);
extern const char *get_stats_option_name(const char *arg);
+extern bool TrySetQueryCancelMessage(char *message);
+extern bool HasQueryCancelMessage(void);
+
#endif /* TCOPPROT_H */
--
2.27.0
Hi,
Sounds reasonable. Do you mean that we can add additional GUC like
"postgres_fdw.initial_check",
wait WL_SOCKET_CLOSED if the conneciton is found in the hash table, and do
reconnection if it might be closed, right?
Alright, it took me sometime to realize that postgres_fdw already has a
retry mechanism if the first command fails: postgres_fdw: reestablish new
connection if cached one is detected as… · postgres/postgres@32a9c0b
(github.com)
<https://github.com/postgres/postgres/commit/32a9c0bdf493cf5fc029ab44a22384d547290eff>
Still, the reestablish mechanism can be further simplified with
WL_SOCKET_CLOSED event such as the following (where we should probably
rename pgfdw_connection_check_internal):
/*
* If the connection needs to be remade due to invalidation, disconnect as
* soon as we're out of all transactions.
*/
* | +bool remoteSocketIsClosed = entry->conn != NULL : *
pgfdw_connection_check_internal*(entry->conn) : false;*
if (entry->conn != NULL && (entry->invalidated || remoteSocketIsClosed) &&
entry->xact_depth == 0)
{
elog(DEBUG3, "closing connection %p for option changes to take effect",
entry->conn);
disconnect_pg_server(entry);
}
* | +else if (remoteSocketIsClosed && && entry->xact_depth > 0)*
* | + error ("Remote Server is down ...")*
In other words, a variation of pgfdw_connection_check_internal()
could potentially go into interfaces/libpq/libpq-fe.h
(backend/libpq/pqcomm.c or src/interfaces/libpq/fe-connect.c).
Then, GetConnection() in postgres_fdw, it can force to reconnect as it is
already done for some cases or error properly:
Based on off and on discussions, I modified my patch.
I still think that it is probably too much work/code to detect the
mentioned use-case you described on [1]/messages/by-id/TYAPR01MB58662809E678253B90E82CE5F5889@TYAPR01MB5866.jpnprd01.prod.outlook.com. Each backend constantly
calling CallCheckingRemoteServersCallbacks() for this purpose doesn't sound
the optimal way to approach the "check whether server down" problem. You
typically try to decide whether a server is down by establishing a
connection (or ping etc), not going over all the existing connections.
As far as I can think of, it should probably be a single background task
checking whether the server is down. If so, sending an invalidation message
to all the backends such that related backends could act on the
invalidation and throw an error. This is to cover the use-case you
described on [1]/messages/by-id/TYAPR01MB58662809E678253B90E82CE5F5889@TYAPR01MB5866.jpnprd01.prod.outlook.com.
Also, maybe we could have a new catalog table like pg_foreign_server_health
or such, where we can keep the last time the check succeeded (and/or
failed), and how many times the check succeeded (and/or failed).
This is of course how I would approach this problem. I think some other
perspectives on this would be very useful to hear.
Thanks,
Onder KALACI
[1]: /messages/by-id/TYAPR01MB58662809E678253B90E82CE5F5889@TYAPR01MB5866.jpnprd01.prod.outlook.com
/messages/by-id/TYAPR01MB58662809E678253B90E82CE5F5889@TYAPR01MB5866.jpnprd01.prod.outlook.com
Hi,
On Wednesday, October 5, 2022 6:27 PM kuroda.hayato@fujitsu.com <kuroda.hayato@fujitsu.com> wrote:
Thanks for giving many comments! Based on off and on discussions, I modified
my patch.
Thank you for your patch set !
While reviewing and testing the new v16, I've met a possible issue
by slightly adjusting the scenario written in [1]/messages/by-id/TYAPR01MB58662CD4FD98AA475B3D10F9F59B9@TYAPR01MB5866.jpnprd01.prod.outlook.com.
I mainly followed the steps there and
replaced the command "SELECT" for the remote table at 6-9 with "INSERT" command.
Then, after waiting for few seconds, the "COMMIT" succeeded like below output,
even after the server stop of the worker side.
After the transaction itself, any reference to the remote table fails.
Note that the local table has some data initially in my test.
postgres=# begin;
BEGIN
postgres=*# insert into remote values (-1000);
INSERT 0 1
postgres=*# select * from local;
number
--------
101
102
103
104
105
(5 rows)
postgres=*# commit;
COMMIT
postgres=# select * from remote;
ERROR: could not connect to server "my_external_server"
DETAIL: connection to server on socket "/tmp/.s.PGSQL.9999" failed: No such file or directory
Is the server running locally and accepting connections on that socket?
Additionally, the last reference "SELECT" which failed above can succeed,
if I restart the worker server before the "SELECT" command to the remote table.
This means the transaction looks successful but the data isn't there ?
Could you please have a look at this issue ?
[1]: /messages/by-id/TYAPR01MB58662CD4FD98AA475B3D10F9F59B9@TYAPR01MB5866.jpnprd01.prod.outlook.com
Best Regards,
Takamichi Osumi
On Wednesday, October 5, 2022 6:27 PM kuroda.hayato@fujitsu.com <kuroda.hayato@fujitsu.com> wrote:
Thanks for giving many comments! Based on off and on discussions, I modified
my patch.
Here are my other quick review comments on v16.
(1) v16-0001 : definition of a new structure
CheckingRemoteServersCallbackItem can be added to typedefs.list.
(2) v16-0001 : UnRegisterCheckingRemoteServersCallback's header comment
+void
+UnRegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+{
Looks require a header comment for this function,
because in this file, all other functions have each one.
(3) v16-0002 : better place to declare new variables
New variables 'old' and 'server' in GetConnection() can be moved to
a scope of 'if' statement where those are used.
@@ -138,6 +149,8 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
ConnCacheEntry *entry;
ConnCacheKey key;
MemoryContext ccxt = CurrentMemoryContext;
+ MemoryContext old;
+ ForeignServer *server = GetForeignServer(user->serverid);
(4) v16-0002 : typo in pgfdw_connection_check_internal()
+ /* return false is if the socket seems to be closed. */
It should be "return false if the socket seems to be closed" ?
(5) v16-0002 : pgfdw_connection_check's message
When I tested the new feature, I got a below message.
"ERROR: Foreign Server my_external_server might be down."
I think we can wrap the server name with double quotes
so that the message is more aligned with existing error message
like connect_pg_server.
(6) v16-003 : typo
+ Authors needs to register the callback function via following API.
Should be "Authors need to register the ...".
(7) v16-0004 : unnecessary file
I think we can remove a new file which looks like a log file.
.../postgres_fdw/expected/postgres_fdw_1.out
Best Regards,
Takamichi Osumi
Dear Önder,
Thanks for giving suggestions!
Still, the reestablish mechanism can be further simplified with
WL_SOCKET_CLOSED event such as the following (where we should probably
rename pgfdw_connection_check_internal):
Sounds reasonable.
I think it may be included in this patch. I will try to next (or later) version.
In other words, a variation of pgfdw_connection_check_internal()
could potentially go into interfaces/libpq/libpq-fe.h
(backend/libpq/pqcomm.c or src/interfaces/libpq/fe-connect.c).
Hmm, IIUC libpq related function and data structures cannot be accessed from core source,
so we cannot move to pqcomm.c.
(This is a motivation for introducing libpqwalreceiver library. It is used to avoid to link libpq directly)
And functions in libpq/fe-connect.c will be included libpq.so,
but latch related functions like WaitEventSetWait() should not be called from client application.
So it is also not appropriate.
In short, there are no good position to place the function because this requires both of libpq and core functions.
I still think that it is probably too much work/code to detect the
mentioned use-case you described on [1]. Each backend constantly
calling CallCheckingRemoteServersCallbacks() for this purpose doesn't sound
the optimal way to approach the "check whether server down" problem. You
typically try to decide whether a server is down by establishing a
connection (or ping etc), not going over all the existing connections.
Yes, the approach that establishes a new connection is very simple, but I think it has some holes.
For example, if the DNS server or some routing software may is stopped,
we will fail to connect to foreign servers.
In your approach, we regard the case as "failed" and try to invalidate the server
even if the existing connection can be used.
Another case is that if a server goes down and failover has occurred, we will succeed to connect to foreign servers.
We may regard the case as a "success", but we cannot COMMIT the transaction.
As far as I can think of, it should probably be a single background task
checking whether the server is down. If so, sending an invalidation message
to all the backends such that related backends could act on the
invalidation and throw an error. This is to cover the use-case you
described on [1].
Indeed your approach covers the use case I said, but I'm not sure whether it is really good.
In your approach, once the background worker process will manage all foreign servers.
It may be OK if there are a few servers, but if there are hundreds of servers,
the time interval during checks will be longer.
Currently, each FDW can decide whether we do health checks or not per the backend.
For example, we can skip health checks if the foreign server is not used now.
The background worker cannot control such a way.
Moreover, methods to connect to foreign servers and check health are different per FDW.
In terms of mysql_fdw [1]https://github.com/EnterpriseDB/mysql_fdw, we must do mysql_init() and mysql_real_connect().
About file_fdw, we do not have to connect, but developers may want to calculate checksum and compare.
Therefore, we must provide callback functions anyway.
Based on the above, I do not agree that we introduce a new background worker and make it to do a health check.
This is of course how I would approach this problem. I think some other
perspectives on this would be very useful to hear.
Yes, we can hear other opinions :-).
[1]: https://github.com/EnterpriseDB/mysql_fdw
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
At Mon, 17 Oct 2022 07:27:21 +0000, "kuroda.hayato@fujitsu.com" <kuroda.hayato@fujitsu.com> wrote in
In other words, a variation of pgfdw_connection_check_internal()
could potentially go into interfaces/libpq/libpq-fe.h
(backend/libpq/pqcomm.c or src/interfaces/libpq/fe-connect.c).Hmm, IIUC libpq related function and data structures cannot be accessed from core source,
so we cannot move to pqcomm.c.
(This is a motivation for introducing libpqwalreceiver library. It is used to avoid to link libpq directly)
And functions in libpq/fe-connect.c will be included libpq.so,
but latch related functions like WaitEventSetWait() should not be called from client application.
So it is also not appropriate.
In short, there are no good position to place the function because this requires both of libpq and core functions.
Might be on slight different direction, but it looks to me a bit too
much to use WaitEventSet to check only if a socket is live or not.
A quick search in the tree told me that we could use pqSocketCheck()
instead, and I think it would be the something that "could potentially
go into libpq-fe.h" as Önder mentioned, if I understand what he said
correctly.
regards.
--
Kyotaro Horiguchi
NTT Open Source Software Center
Dear Horiguchi-san,
Might be on slight different direction, but it looks to me a bit too
much to use WaitEventSet to check only if a socket is live or not.A quick search in the tree told me that we could use pqSocketCheck()
instead, and I think it would be the something that "could potentially
go into libpq-fe.h" as Önder mentioned, if I understand what he said
correctly.
Based on your suggestion, I tried to add like following function to fe-misc.c:
```
int
PQconncheck(PGconn *conn)
{
/* Raise an ERROR if invalid socket has come */
if (conn == NULL ||
PQsocket(conn) == PGINVALID_SOCKET)
return -1;
return pqSocketCheck(conn, 1, 1, -1);
}
```
... and replace pgfdw_connection_check_internal() to PQconncheck(),
but it did not work well.
To be exact, pqSocketCheck() said the socket was "readable" and "writable"
even if the connection has been killed.
IIUC, pqSocketCheck () calls pqSocketPoll(),
and in the pqSocketPoll() we poll()'d the POLLIN or POLLOUT event.
But according to [1]https://man7.org/linux/man-pages/man2/poll.2.html, we must wait POLLRDHUP event,
so we cannot reuse it straightforward.
If we really want to move the checking function anyway,
we must follow AddWaitEventToSet() and some WaitEventAdjust functions.
I'm not sure whether it is really good.
[1]: https://man7.org/linux/man-pages/man2/poll.2.html
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Dear Osumi-san,
I mainly followed the steps there and
replaced the command "SELECT" for the remote table at 6-9 with "INSERT"
command.
Then, after waiting for few seconds, the "COMMIT" succeeded like below output,
even after the server stop of the worker side.
Additionally, the last reference "SELECT" which failed above can succeed,
if I restart the worker server before the "SELECT" command to the remote table.
This means the transaction looks successful but the data isn't there ?
Could you please have a look at this issue ?
Good catch. This was occurred because we disconnected the crashed server.
Previously the failed server had been disconnected in the pgfdw_connection_check().
It was OK if the transaction(or statement) was surely cacneled.
But currently the statement might be not canceled because QueryCancelPending might be cleaned up[1]/messages/by-id/TYAPR01MB5866CE34430424A588F60FC2F55D9@TYAPR01MB5866.jpnprd01.prod.outlook.com.
If we failed to cancel statements and reached pgfdw_xact_callback(),
the connection would not be used because entry->conn is NULL.
That's why you sucseeded to do "COMMIT".
However, the backend did not send "COMMIT" command to the srever,
so inserted data was vanished on remote server.
I understood that we should not call disconnect_pg_server(entry->conn) even if we detect the disconnection.
If should be controlled in Xact callback. This will be modified in next version.
Moreover, I noticed that we should enable timer even if the QueryCancelMessage was not NULL.
If we do not turn on here, the checking will be never enabled again.
[1]: /messages/by-id/TYAPR01MB5866CE34430424A588F60FC2F55D9@TYAPR01MB5866.jpnprd01.prod.outlook.com
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Dear Osumi-san,
Thanks for reviewing! PSA v17 patchset.
(1) v16-0001 : definition of a new structure
CheckingRemoteServersCallbackItem can be added to typedefs.list.
Added.
(2) v16-0001 : UnRegisterCheckingRemoteServersCallback's header comment
+void +UnRegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback, + void *arg) +{Looks require a header comment for this function,
because in this file, all other functions have each one.
Added. Additionally, I renamed this function to Unregister...,
this follows other unregister functions.
(3) v16-0002 : better place to declare new variables
New variables 'old' and 'server' in GetConnection() can be moved to
a scope of 'if' statement where those are used.@@ -138,6 +149,8 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state) ConnCacheEntry *entry; ConnCacheKey key; MemoryContext ccxt = CurrentMemoryContext; + MemoryContext old; + ForeignServer *server = GetForeignServer(user->serverid);
Fixed.
(4) v16-0002 : typo in pgfdw_connection_check_internal()
+ /* return false is if the socket seems to be closed. */
It should be "return false if the socket seems to be closed" ?
Fixed.
(5) v16-0002 : pgfdw_connection_check's message
When I tested the new feature, I got a below message.
"ERROR: Foreign Server my_external_server might be down."
I think we can wrap the server name with double quotes
so that the message is more aligned with existing error message
like connect_pg_server.
Fixed.
...I'm not sure whether this message is still need, because
the disconnection was delegated to XactCallback, and the function did following output:
```
WARNING: FATAL: terminating connection due to administrator command
server closed the connection unexpectedly
This probably means the server terminated abnormally
before or while processing the request.
```
(6) v16-003 : typo
+ Authors needs to register the callback function via following API.
Should be "Authors need to register the ...".
Fixed.
(7) v16-0004 : unnecessary file
I think we can remove a new file which looks like a log file.
.../postgres_fdw/expected/postgres_fdw_1.out
This is needed to pass the test on the windows platform. See:
https://www.postgresql.org/docs/devel/regress-variant.html
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v17-0001-Add-an-infrastracture-for-checking-remote-server.patchapplication/octet-stream; name=v17-0001-Add-an-infrastracture-for-checking-remote-server.patchDownload
From a8f7be269dcfe6cd8c4771840faa290e2c20efdb Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:02:45 +0000
Subject: [PATCH v17 1/4] Add an infrastracture for checking remote servers
This patch adds a mechanism for registering callback functions.
They should be used for checking health of remote servers.
These functions will be called when flags CheckingRemoteServersTimeoutPending and InterruptPending are set to true.
CheckingRemoteServersTimeoutPending is expected that it is set from signal handlers, which is registered by FDWs.
Inside the function a signal SIGINT should be raised and a message should be set to QueryCancelMessage
if one of remote servers is disconnected. To fill the message new API TrySetQueryCancelMessage can be used.
When a query is canceled and a string is set to QueryCancelMessage,
the server will output the given message to the log instead of the normal message.
Note that TrySetQueryCancelMessage does not allow to override the QueryCancelMessage.
If the function is called but the message is already filled, returns immediately
---
src/backend/foreign/foreign.c | 60 ++++++++++++++++++++++++++++++++
src/backend/tcop/postgres.c | 50 ++++++++++++++++++++++++++
src/backend/utils/init/globals.c | 1 +
src/include/foreign/foreign.h | 19 ++++++++++
src/include/miscadmin.h | 2 ++
src/include/tcop/tcopprot.h | 3 ++
src/tools/pgindent/typedefs.list | 1 +
7 files changed, 136 insertions(+)
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index 353e20a0cf..58353abc40 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -28,7 +28,9 @@
#include "utils/rel.h"
#include "utils/syscache.h"
#include "utils/varlena.h"
+#include "utils/timeout.h"
+static CheckingRemoteServersCallbackItem *remote_check_callbacks = NULL;
/*
* GetForeignDataWrapper - look up the foreign-data wrapper by OID.
@@ -810,3 +812,61 @@ GetExistingLocalJoinPath(RelOptInfo *joinrel)
}
return NULL;
}
+
+
+/*
+ * Register callbacks for checking remote servers.
+ *
+ * This function is intended for use by FDW extensions.
+ */
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+
+ item = (CheckingRemoteServersCallbackItem *)
+ MemoryContextAlloc(TopMemoryContext,
+ sizeof(CheckingRemoteServersCallbackItem));
+ item->callback = callback;
+ item->arg = arg;
+ item->next = remote_check_callbacks;
+ remote_check_callbacks = item;
+}
+
+/*
+ * Deregister callbacks for checking remote servers.
+ */
+void
+UnregisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+{
+ CheckingRemoteServersCallbackItem *item;
+ CheckingRemoteServersCallbackItem *prev;
+
+ prev = NULL;
+ for (item = remote_check_callbacks; item; prev = item, item = item->next)
+ {
+ if (item->callback == callback && item->arg == arg)
+ {
+ if (prev)
+ prev->next = item->next;
+ else
+ remote_check_callbacks = item->next;
+ pfree(item);
+ break;
+ }
+ }
+}
+
+/*
+ * Call callbacks for checking remote servers.
+ */
+void
+CallCheckingRemoteServersCallbacks(void)
+{
+ CheckingRemoteServersCallbackItem *item;
+
+ for (item = remote_check_callbacks; item; item = item->next)
+ item->callback(item->arg);
+}
diff --git a/src/backend/tcop/postgres.c b/src/backend/tcop/postgres.c
index a9a1851c94..f0f00d316e 100644
--- a/src/backend/tcop/postgres.c
+++ b/src/backend/tcop/postgres.c
@@ -35,6 +35,7 @@
#include "commands/async.h"
#include "commands/prepare.h"
#include "common/pg_prng.h"
+#include "foreign/foreign.h"
#include "jit/jit.h"
#include "libpq/libpq.h"
#include "libpq/pqformat.h"
@@ -166,6 +167,9 @@ static ProcSignalReason RecoveryConflictReason;
static MemoryContext row_description_context = NULL;
static StringInfoData row_description_buf;
+/* Message string for canceling qurery caused by extensions */
+static char *QueryCancelMessage = NULL;
+
/* ----------------------------------------------------------------
* decls for routines only used in this file
* ----------------------------------------------------------------
@@ -3226,6 +3230,13 @@ ProcessInterrupts(void)
errmsg("connection to client lost")));
}
+ if (CheckingRemoteServersTimeoutPending)
+ {
+ CheckingRemoteServersTimeoutPending = false;
+
+ CallCheckingRemoteServersCallbacks();
+ }
+
/*
* If a recovery conflict happens while we are waiting for input from the
* client, the client is presumably just sitting idle in a transaction,
@@ -3330,8 +3341,21 @@ ProcessInterrupts(void)
LockErrorCleanup();
ereport(ERROR,
(errcode(ERRCODE_QUERY_CANCELED),
+ QueryCancelMessage ?
+ errmsg("%s", QueryCancelMessage) :
errmsg("canceling statement due to user request")));
}
+
+ /*
+ * If a cancel request from FDW is ignored, we expect that it raise SIGINT and
+ * fill QueryCancelMessage again. But some FDWs may skip its health check if
+ * we already have a cancel message. To avoid that we clean up it.
+ */
+ if (QueryCancelMessage != NULL)
+ {
+ pfree(QueryCancelMessage);
+ QueryCancelMessage = NULL;
+ }
}
if (IdleInTransactionSessionTimeoutPending)
@@ -4266,6 +4290,9 @@ PostgresMain(const char *dbname, const char *username)
/* Report the error to the client and/or server log */
EmitErrorReport();
+ /* Make sure QueryCancelMessage is reset. */
+ QueryCancelMessage = NULL;
+
/*
* Make sure debug_query_string gets reset before we possibly clobber
* the storage it points at.
@@ -5024,3 +5051,26 @@ disable_statement_timeout(void)
if (get_timeout_active(STATEMENT_TIMEOUT))
disable_timeout(STATEMENT_TIMEOUT, false);
}
+
+bool
+TrySetQueryCancelMessage(char *message)
+{
+ if (!HasQueryCancelMessage())
+ {
+ MemoryContext old;
+
+ old = MemoryContextSwitchTo(CurTransactionContext);
+ QueryCancelMessage = pstrdup(message);
+ MemoryContextSwitchTo(old);
+
+ return true;
+ }
+
+ return false;
+}
+
+bool
+HasQueryCancelMessage(void)
+{
+ return QueryCancelMessage != NULL;
+}
diff --git a/src/backend/utils/init/globals.c b/src/backend/utils/init/globals.c
index 1a5d29ac9b..bb94adfea8 100644
--- a/src/backend/utils/init/globals.c
+++ b/src/backend/utils/init/globals.c
@@ -37,6 +37,7 @@ volatile sig_atomic_t IdleSessionTimeoutPending = false;
volatile sig_atomic_t ProcSignalBarrierPending = false;
volatile sig_atomic_t LogMemoryContextPending = false;
volatile sig_atomic_t IdleStatsUpdateTimeoutPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
volatile uint32 InterruptHoldoffCount = 0;
volatile uint32 QueryCancelHoldoffCount = 0;
volatile uint32 CritSectionCount = 0;
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index ac82125530..22f8143bdd 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -82,4 +82,23 @@ extern List *GetForeignColumnOptions(Oid relid, AttrNumber attnum);
extern Oid get_foreign_data_wrapper_oid(const char *fdwname, bool missing_ok);
extern Oid get_foreign_server_oid(const char *servername, bool missing_ok);
+
+/* Functions and variables for fdw checking */
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+
+typedef struct CheckingRemoteServersCallbackItem CheckingRemoteServersCallbackItem;
+
+struct CheckingRemoteServersCallbackItem
+{
+ CheckingRemoteServersCallbackItem *next;
+ CheckingRemoteServersCallback callback;
+ void *arg;
+};
+
+extern void RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg);
+extern void UnregisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg);
+extern void CallCheckingRemoteServersCallbacks(void);
+
#endif /* FOREIGN_H */
diff --git a/src/include/miscadmin.h b/src/include/miscadmin.h
index e7ebea4ff4..75697e2be0 100644
--- a/src/include/miscadmin.h
+++ b/src/include/miscadmin.h
@@ -99,6 +99,8 @@ extern PGDLLIMPORT volatile sig_atomic_t IdleStatsUpdateTimeoutPending;
extern PGDLLIMPORT volatile sig_atomic_t CheckClientConnectionPending;
extern PGDLLIMPORT volatile sig_atomic_t ClientConnectionLost;
+extern PGDLLIMPORT volatile sig_atomic_t CheckingRemoteServersTimeoutPending;
+
/* these are marked volatile because they are examined by signal handlers: */
extern PGDLLIMPORT volatile uint32 InterruptHoldoffCount;
extern PGDLLIMPORT volatile uint32 QueryCancelHoldoffCount;
diff --git a/src/include/tcop/tcopprot.h b/src/include/tcop/tcopprot.h
index 5d34978f32..5d1216f170 100644
--- a/src/include/tcop/tcopprot.h
+++ b/src/include/tcop/tcopprot.h
@@ -91,4 +91,7 @@ extern bool set_plan_disabling_options(const char *arg,
GucContext context, GucSource source);
extern const char *get_stats_option_name(const char *arg);
+extern bool TrySetQueryCancelMessage(char *message);
+extern bool HasQueryCancelMessage(void);
+
#endif /* TCOPPROT_H */
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index d9b839c979..3a1f9ac271 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -363,6 +363,7 @@ CatalogId
CatalogIdMapEntry
CatalogIndexState
ChangeVarNodes_context
+CheckingRemoteServersCallbackItem
CheckPoint
CheckPointStmt
CheckpointStatsData
--
2.27.0
v17-0002-postgres_fdw-Implement-health-check-feature.patchapplication/octet-stream; name=v17-0002-postgres_fdw-Implement-health-check-feature.patchDownload
From b194426726f39404a0e630ef480c69ee6f0fe7f0 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:30:56 +0000
Subject: [PATCH v17 2/4] postgres_fdw: Implement health check feature
This patch adds a new GUC parameter postgres_fdw.health_check_interval.
This defines a time interval between checking remote servers.
In the checking function we use a socket event WL_SOCKET_CLOSED.
---
contrib/postgres_fdw/connection.c | 177 +++++++++++++++++++++++++++-
contrib/postgres_fdw/option.c | 63 ++++++++++
contrib/postgres_fdw/postgres_fdw.h | 3 +
3 files changed, 240 insertions(+), 3 deletions(-)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 939d114f02..99ee663614 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -23,12 +23,14 @@
#include "postgres_fdw.h"
#include "storage/fd.h"
#include "storage/latch.h"
+#include "tcop/tcopprot.h"
#include "utils/builtins.h"
#include "utils/datetime.h"
#include "utils/hsearch.h"
#include "utils/inval.h"
#include "utils/memutils.h"
#include "utils/syscache.h"
+#include "utils/timeout.h"
/*
* Connection cache hash table entry
@@ -63,6 +65,7 @@ typedef struct ConnCacheEntry
bool keep_connections; /* setting value of keep_connections
* server option */
Oid serverid; /* foreign server OID used to get server name */
+ char *servername; /* foreign server name used to report ERROR */
uint32 server_hashvalue; /* hash value of foreign server OID */
uint32 mapping_hashvalue; /* hash value of user mapping OID */
PgFdwConnState state; /* extra per-connection state */
@@ -80,6 +83,9 @@ static unsigned int prep_stmt_number = 0;
/* tracks whether any work is needed in callback functions */
static bool xact_got_connection = false;
+/* Timeout identifier for health check */
+TimeoutId pgfdw_health_check_timeout = MAX_TIMEOUTS;
+
/*
* SQL functions
*/
@@ -117,6 +123,11 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+/* Functions for checking remote servers */
+static void pgfdw_connection_check(void *arg);
+static bool pgfdw_connection_check_internal(PGconn *conn);
+static void pgfdw_checking_remote_servers_timeout_handler(void);
+
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
* server with the user's authorization. A new connection is established
@@ -160,6 +171,13 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
pgfdw_inval_callback, (Datum) 0);
CacheRegisterSyscacheCallback(USERMAPPINGOID,
pgfdw_inval_callback, (Datum) 0);
+ CacheRegisterSyscacheCallback(FOREIGNSERVERNAME,
+ pgfdw_inval_callback, (Datum) 0);
+
+ /* Register a timeout and a callback for checking remote servers */
+ pgfdw_health_check_timeout = RegisterTimeout(USER_TIMEOUT,
+ pgfdw_checking_remote_servers_timeout_handler);
+ RegisterCheckingRemoteServersCallback(pgfdw_connection_check, NULL);
}
/* Set flag that we did GetConnection during the current transaction */
@@ -175,10 +193,11 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
if (!found)
{
/*
- * We need only clear "conn" here; remaining fields will be filled
- * later when "conn" is set.
+ * We need clear "conn" and "servername" here; remaining fields will be filled
+ * later when they are set.
*/
entry->conn = NULL;
+ entry->servername = NULL;
}
/* Reject further use of connections which failed abort cleanup. */
@@ -203,6 +222,19 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
if (entry->conn == NULL)
make_new_connection(entry, user);
+ /*
+ * If cache entry doesn't have a name, duplicate it to the TopMemoryContext
+ */
+ if (entry->servername == NULL)
+ {
+ MemoryContext old;
+ ForeignServer *server = GetForeignServer(user->serverid);
+
+ old = MemoryContextSwitchTo(TopMemoryContext);
+ entry->servername = pstrdup(server->servername);
+ MemoryContextSwitchTo(old);
+ }
+
/*
* We check the health of the cached connection here when using it. In
* cases where we're out of all transactions, if a broken connection is
@@ -283,6 +315,12 @@ GetConnection(UserMapping *user, bool will_prep_stmt, PgFdwConnState **state)
if (state)
*state = &entry->state;
+ /* Start health-check timer if needed */
+ if (pgfdw_health_check_interval > 0 &&
+ !get_timeout_active(pgfdw_health_check_timeout))
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
return entry->conn;
}
@@ -532,6 +570,12 @@ disconnect_pg_server(ConnCacheEntry *entry)
entry->conn = NULL;
ReleaseExternalFD();
}
+
+ if (entry->servername != NULL)
+ {
+ pfree(entry->servername);
+ entry->servername = NULL;
+ }
}
/*
@@ -1040,6 +1084,9 @@ pgfdw_xact_callback(XactEvent event, void *arg)
*/
xact_got_connection = false;
+ /* Stop timer because checking is no more needed. */
+ disable_timeout(pgfdw_health_check_timeout, false);
+
/* Also reset cursor numbering for next transaction */
cursor_number = 0;
}
@@ -1148,7 +1195,7 @@ pgfdw_inval_callback(Datum arg, int cacheid, uint32 hashvalue)
HASH_SEQ_STATUS scan;
ConnCacheEntry *entry;
- Assert(cacheid == FOREIGNSERVEROID || cacheid == USERMAPPINGOID);
+ Assert(cacheid == FOREIGNSERVEROID || cacheid == USERMAPPINGOID || cacheid == FOREIGNSERVERNAME);
/* ConnectionHash must exist already, if we're registered */
hash_seq_init(&scan, ConnectionHash);
@@ -1179,6 +1226,21 @@ pgfdw_inval_callback(Datum arg, int cacheid, uint32 hashvalue)
else
entry->invalidated = true;
}
+
+ /* If ALTER SERVER RENAME is executed, the entry must be also modified. */
+ if (cacheid == FOREIGNSERVERNAME &&
+ entry->server_hashvalue == hashvalue)
+ {
+ ForeignServer *server = GetForeignServer(entry->serverid);
+ MemoryContext old;
+
+ if (entry->servername != NULL)
+ pfree(entry->servername);
+
+ old = MemoryContextSwitchTo(TopMemoryContext);
+ entry->servername = pstrdup(server->servername);
+ MemoryContextSwitchTo(old);
+ }
}
}
@@ -1862,3 +1924,112 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Signal handler for triggering health check
+ */
+static void
+pgfdw_checking_remote_servers_timeout_handler(void)
+{
+ CheckingRemoteServersTimeoutPending = true;
+ InterruptPending = true;
+ SetLatch(MyLatch);
+}
+
+/*
+ * Function for checking remote servers.
+ *
+ * This function searches the hash table from the beginning
+ * and performs a health-check on each entry.
+ *
+ * Raise SIGINT if someone might be down, otherwise do nothing.
+ */
+static void
+pgfdw_connection_check(void *arg)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool killed = false;
+
+ Assert(ConnectionHash);
+
+ /*
+ * checking will be done by waiting WL_SOCKET_CLOSED event,
+ * so exit immediately if it cannot be used in this system.
+ */
+ if (!WaitEventSetCanReportClosed())
+ return;
+
+ /* raise SIGINT if QueryCancelMessage has been already set. */
+ if (HasQueryCancelMessage())
+ {
+ kill(MyProcPid, SIGINT);
+ return;
+ }
+
+ if (!killed)
+ {
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ if (entry->conn == NULL || entry->xact_depth == 0)
+ continue;
+ if (!pgfdw_connection_check_internal(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so raise SIGINT.
+ * Note that error message is passed to QueryCancelMessage
+ * for reporting error in ProcessInterrupts().
+ */
+ char msg[31 + MAXDATELEN];
+ snprintf(msg, sizeof(msg), "Foreign Server \"%s\" might be down.", entry->servername);
+ TrySetQueryCancelMessage(msg);
+
+ hash_seq_term(&scan);
+
+ kill(MyProcPid, SIGINT);
+ break;
+ }
+ }
+ }
+
+ /* re-schedule timer if needed. */
+ if (pgfdw_health_check_interval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout,
+ pgfdw_health_check_interval);
+
+ return;
+}
+
+/*
+ * Helper function for pgfdw_connection_check
+ */
+static bool
+pgfdw_connection_check_internal(PGconn *conn)
+{
+ WaitEventSet *eventset;
+ WaitEvent events;
+
+ Assert(WaitEventSetCanReportClosed());
+
+ /* Raise an ERROR if invalid socket has come */
+ if (conn == NULL ||
+ PQsocket(conn) == PGINVALID_SOCKET)
+ elog(ERROR, "Invalid connection has been arrived");
+
+ eventset = CreateWaitEventSet(TopMemoryContext, 1);
+
+ (void) AddWaitEventToSet(eventset, WL_SOCKET_CLOSED, PQsocket(conn), NULL, NULL);
+
+ WaitEventSetWait(eventset, 0, &events, 1, 0);
+
+ /* return false if the socket seems to be closed */
+ if (events.events & WL_SOCKET_CLOSED)
+ {
+ FreeWaitEventSet(eventset);
+ return false;
+ }
+
+ FreeWaitEventSet(eventset);
+ return true;
+}
diff --git a/contrib/postgres_fdw/option.c b/contrib/postgres_fdw/option.c
index fa80ee2a55..9cd5a32e77 100644
--- a/contrib/postgres_fdw/option.c
+++ b/contrib/postgres_fdw/option.c
@@ -20,6 +20,7 @@
#include "commands/extension.h"
#include "libpq/libpq-be.h"
#include "postgres_fdw.h"
+#include "storage/latch.h"
#include "utils/builtins.h"
#include "utils/guc.h"
#include "utils/varlena.h"
@@ -50,6 +51,7 @@ static PQconninfoOption *libpq_options;
* GUC parameters
*/
char *pgfdw_application_name = NULL;
+int pgfdw_health_check_interval;
/*
* Helper functions
@@ -58,6 +60,13 @@ static void InitPgFdwOptions(void);
static bool is_valid_option(const char *keyword, Oid context);
static bool is_libpq_option(const char *keyword);
+/*
+ * GUC hooks
+ */
+static bool check_pgfdw_health_check_interval(int *newval, void **extra,
+ GucSource source);
+static void assign_pgfdw_health_check_interval(int newval, void *extra);
+
#include "miscadmin.h"
/*
@@ -518,6 +527,47 @@ process_pgfdw_appname(const char *appname)
return buf.data;
}
+/*
+ * Check hook for pgfdw_health_check_interval
+ */
+static bool
+check_pgfdw_health_check_interval(int *newval, void **extra, GucSource source)
+{
+ if (!WaitEventSetCanReportClosed() && *newval != 0)
+ {
+ GUC_check_errdetail("postgres_fdw.health_check_interval must be set to 0 on this platform");
+ return false;
+ }
+ return true;
+}
+
+/*
+ * Assign hook for pgfdw_health_check_interval
+ */
+static void
+assign_pgfdw_health_check_interval(int newval, void *extra)
+{
+ /* Quick return if timeout is not registered yet. */
+ if (pgfdw_health_check_timeout == MAX_TIMEOUTS)
+ return;
+
+ if (get_timeout_active(pgfdw_health_check_timeout))
+ {
+ if (newval == 0)
+ disable_timeout(pgfdw_health_check_timeout, false);
+
+ /*
+ * we don't have to do anything because
+ * new value will be used in pgfdw_connection_check().
+ */
+ return;
+ }
+
+ /* Start timeout if wants to */
+ if (newval > 0)
+ enable_timeout_after(pgfdw_health_check_timeout, newval);
+}
+
/*
* Module load callback
*/
@@ -543,5 +593,18 @@ _PG_init(void)
NULL,
NULL);
+ DefineCustomIntVariable("postgres_fdw.health_check_interval",
+ "Sets the time interval between checks of remote servers.",
+ NULL,
+ &pgfdw_health_check_interval,
+ 0,
+ 0,
+ INT_MAX,
+ PGC_USERSET,
+ GUC_UNIT_MS,
+ check_pgfdw_health_check_interval,
+ assign_pgfdw_health_check_interval,
+ NULL);
+
MarkGUCPrefixReserved("postgres_fdw");
}
diff --git a/contrib/postgres_fdw/postgres_fdw.h b/contrib/postgres_fdw/postgres_fdw.h
index a11d45bedf..4670e8d391 100644
--- a/contrib/postgres_fdw/postgres_fdw.h
+++ b/contrib/postgres_fdw/postgres_fdw.h
@@ -18,6 +18,7 @@
#include "libpq-fe.h"
#include "nodes/execnodes.h"
#include "nodes/pathnodes.h"
+#include "utils/timeout.h"
#include "utils/relcache.h"
/*
@@ -151,6 +152,7 @@ extern PGresult *pgfdw_exec_query(PGconn *conn, const char *query,
PgFdwConnState *state);
extern void pgfdw_report_error(int elevel, PGresult *res, PGconn *conn,
bool clear, const char *sql);
+extern TimeoutId pgfdw_health_check_timeout;
/* in option.c */
extern int ExtractConnectionOptions(List *defelems,
@@ -160,6 +162,7 @@ extern List *ExtractExtensionList(const char *extensionsString,
bool warnOnMissing);
extern char *process_pgfdw_appname(const char *appname);
extern char *pgfdw_application_name;
+extern int pgfdw_health_check_interval;
/* in deparse.c */
extern void classifyConditions(PlannerInfo *root,
--
2.27.0
v17-0003-add-doc.patchapplication/octet-stream; name=v17-0003-add-doc.patchDownload
From d6aa86749753ddfaeb2eec3140e6ae0ccfc584e3 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:47:55 +0000
Subject: [PATCH v17 3/4] add doc
This patch adds descriptions about postgres_fdw.health_check_interval
---
doc/src/sgml/fdwhandler.sgml | 75 ++++++++++++++++++++++++++++++++++
doc/src/sgml/postgres-fdw.sgml | 26 ++++++++++++
2 files changed, 101 insertions(+)
diff --git a/doc/src/sgml/fdwhandler.sgml b/doc/src/sgml/fdwhandler.sgml
index 94263c628f..b28d58aa24 100644
--- a/doc/src/sgml/fdwhandler.sgml
+++ b/doc/src/sgml/fdwhandler.sgml
@@ -2138,4 +2138,79 @@ GetForeignServerByName(const char *name, bool missing_ok);
</sect1>
+ <sect1 id="fdw-health-check">
+ <title>Health check of Foreign servers</title>
+
+ <para>
+ Additionally, the FDW author can implement a function to check health of
+ foreign servers. PostgreSQL has a mechanism to call callback functions
+ registered by FDW, and they will be done when flags are set. To enable the
+ feature, FDW authors must 1) implement health check function, 2) register
+ the implemented function as health check callback function, and
+ 3) set flags in arbitrary ways.
+ </para>
+
+ <sect2 id="fdw-health-check-implement">
+ <title>Implement health check function</title>
+
+ <para>
+ The health check function must be defined as following datatype.
+<programlisting>
+typedef void (*CheckingRemoteServersCallback) (void *arg);
+</programlisting>
+ </para>
+
+ <para>
+ When FDW finds disconnections to foreign servers, the function must set
+ an error message and send SIGINT signal to its backend process. To fill
+ and check the message following APIs can be used, which are declared in
+ <filename>tcop/tcopprot.h</filename>.
+
+<programlisting>
+extern bool TrySetQueryCancelMessage(char *message);
+extern bool HasQueryCancelMessage(void);
+</programlisting>
+
+ Note that the message will be duplicated to the transactional memory
+ context. The message does not have to be allocated memory by FDW author.
+ </para>
+
+ </sect2>
+
+ <sect2 id="fdw-health-check-callback">
+ <title>Register a callback</title>
+
+ <para>
+ Authors need to register the callback function via following API.
+
+<programlisting>
+void
+RegisterCheckingRemoteServersCallback(CheckingRemoteServersCallback callback,
+ void *arg)
+</programlisting>
+ </para>
+
+ </sect2>
+
+ <sect2 id="fdw-health-check-timeout">
+ <title>Set flags in arbitrary ways</title>
+
+ <para>
+ Finally, authors must implement a mechanism to fire the health check
+ callbacks. It can be done by setting flags <literal>CheckingRemoteServersTimeoutPending</literal>
+ and <literal>InterruptPending</literal> to true. They are declared in <filename>miscadmin.h</filename>.
+
+<programlisting>
+volatile sig_atomic_t InterruptPending = false;
+volatile sig_atomic_t CheckingRemoteServersTimeoutPending = false;
+</programlisting>
+
+ Typically, the timeout mechanism can be used to set these flags. The
+ detailed description and usage are written in <filename>src/backend/utils/misc/timeout.c</filename>.
+ </para>
+
+ </sect2>
+
+ </sect1>
+
</chapter>
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 527f4deaaa..231ce85b35 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -1082,6 +1082,32 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</listitem>
</varlistentry>
+ <varlistentry id="guc-pgfdw-health-check-interval" xreflabel="postgres_fdw.health_check_interval">
+ <term>
+ <varname>postgres_fdw.health_check_interval</varname> (<type>integer</type>)
+ <indexterm>
+ <primary><varname>postgres_fdw.health_check_interval</varname> configuration parameter</primary>
+ </indexterm>
+ </term>
+ <listitem>
+ <para>
+ Sets the time interval between optional checks that remote servers
+ are still alive. When losing a remote connection is detected,
+ the running transaction is aborted. This feature is performed
+ by polling the socket.
+ </para>
+ <para>
+ This option relies on kernel events exposed by Linux, macOS,
+ illumos and the BSD family of operating systems, and is not currently available
+ on other systems.
+ </para>
+ <para>
+ If the value is specified without units, it is taken as milliseconds.
+ The default value is <literal>0</literal>, which disables connection
+ checks.
+ </para>
+ </listitem>
+ </varlistentry>
</variablelist>
</sect2>
--
2.27.0
v17-0004-add-test.patchapplication/octet-stream; name=v17-0004-add-test.patchDownload
From ad11ecb2b00dbef3fee4fb4197c9494d08858ed5 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v17 4/4] add test
Note that this test has some variant comparison files. One comparison file is needed
because some platforms like Windows cannot check the status of the socket.
Another file is because the output is not stabilized.
The ordering of ERROR and WARNING seems to depend on the timing of whether the timeout is fired.
---
.../postgres_fdw/expected/postgres_fdw.out | 41 +
.../postgres_fdw/expected/postgres_fdw_1.out | 11619 +++++++++++++++
.../postgres_fdw/expected/postgres_fdw_2.out | 11623 ++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 27 +
4 files changed, 23310 insertions(+)
create mode 100644 contrib/postgres_fdw/expected/postgres_fdw_1.out
create mode 100644 contrib/postgres_fdw/expected/postgres_fdw_2.out
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index b3c8ce0131..820ea91cec 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11576,3 +11576,44 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for health-check feature
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Set GUC for checking the health of remote servers
+SET postgres_fdw.health_check_interval TO '1s';
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+-- FIXME: this should be skipped in some platforms
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- While sleeping the process down will be detected.
+SELECT pg_sleep(3);
+ERROR: Foreign Server "loopback" might be down.
+WARNING: FATAL: terminating connection due to administrator command
+server closed the connection unexpectedly
+ This probably means the server terminated abnormally
+ before or while processing the request.
+COMMIT;
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/expected/postgres_fdw_1.out b/contrib/postgres_fdw/expected/postgres_fdw_1.out
new file mode 100644
index 0000000000..609478861b
--- /dev/null
+++ b/contrib/postgres_fdw/expected/postgres_fdw_1.out
@@ -0,0 +1,11619 @@
+-- ===================================================================
+-- create FDW objects
+-- ===================================================================
+CREATE EXTENSION postgres_fdw;
+CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw;
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback2 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback3 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+CREATE USER MAPPING FOR public SERVER testserver1
+ OPTIONS (user 'value', password 'value');
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback2;
+CREATE USER MAPPING FOR public SERVER loopback3;
+-- ===================================================================
+-- create objects used through FDW loopback server
+-- ===================================================================
+CREATE TYPE user_enum AS ENUM ('foo', 'bar', 'buz');
+CREATE SCHEMA "S 1";
+CREATE TABLE "S 1"."T 1" (
+ "C 1" int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10),
+ c8 user_enum,
+ CONSTRAINT t1_pkey PRIMARY KEY ("C 1")
+);
+CREATE TABLE "S 1"."T 2" (
+ c1 int NOT NULL,
+ c2 text,
+ CONSTRAINT t2_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 3" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t3_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 4" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t4_pkey PRIMARY KEY (c1)
+);
+-- Disable autovacuum for these tables to avoid unexpected effects of that
+ALTER TABLE "S 1"."T 1" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 2" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 3" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 4" SET (autovacuum_enabled = 'false');
+INSERT INTO "S 1"."T 1"
+ SELECT id,
+ id % 10,
+ to_char(id, 'FM00000'),
+ '1970-01-01'::timestamptz + ((id % 100) || ' days')::interval,
+ '1970-01-01'::timestamp + ((id % 100) || ' days')::interval,
+ id % 10,
+ id % 10,
+ 'foo'::user_enum
+ FROM generate_series(1, 1000) id;
+INSERT INTO "S 1"."T 2"
+ SELECT id,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+INSERT INTO "S 1"."T 3"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 3" WHERE c1 % 2 != 0; -- delete for outer join tests
+INSERT INTO "S 1"."T 4"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests
+ANALYZE "S 1"."T 1";
+ANALYZE "S 1"."T 2";
+ANALYZE "S 1"."T 3";
+ANALYZE "S 1"."T 4";
+-- ===================================================================
+-- create foreign tables
+-- ===================================================================
+CREATE FOREIGN TABLE ft1 (
+ c0 int,
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft1 DROP COLUMN c0;
+CREATE FOREIGN TABLE ft2 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ cx int,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft2',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft2 DROP COLUMN cx;
+CREATE FOREIGN TABLE ft4 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 3');
+CREATE FOREIGN TABLE ft5 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft6 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback2 OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft7 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback3 OPTIONS (schema_name 'S 1', table_name 'T 4');
+-- ===================================================================
+-- tests for validator
+-- ===================================================================
+-- requiressl and some other parameters are omitted because
+-- valid values for them depend on configure options
+ALTER SERVER testserver1 OPTIONS (
+ use_remote_estimate 'false',
+ updatable 'true',
+ fdw_startup_cost '123.456',
+ fdw_tuple_cost '0.123',
+ service 'value',
+ connect_timeout 'value',
+ dbname 'value',
+ host 'value',
+ hostaddr 'value',
+ port 'value',
+ --client_encoding 'value',
+ application_name 'value',
+ --fallback_application_name 'value',
+ keepalives 'value',
+ keepalives_idle 'value',
+ keepalives_interval 'value',
+ tcp_user_timeout 'value',
+ -- requiressl 'value',
+ sslcompression 'value',
+ sslmode 'value',
+ sslcert 'value',
+ sslkey 'value',
+ sslrootcert 'value',
+ sslcrl 'value',
+ --requirepeer 'value',
+ krbsrvname 'value',
+ gsslib 'value'
+ --replication 'value'
+);
+-- Error, invalid list syntax
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo; bar');
+ERROR: parameter "extensions" must be a list of extension names
+-- OK but gets a warning
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo, bar');
+WARNING: extension "foo" is not installed
+WARNING: extension "bar" is not installed
+ALTER SERVER testserver1 OPTIONS (DROP extensions);
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (DROP user, DROP password);
+-- Attempt to add a valid option that's not allowed in a user mapping
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslmode 'require');
+ERROR: invalid option "sslmode"
+-- But we can add valid ones fine
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslpassword 'dummy');
+-- Ensure valid options we haven't used in a user mapping yet are
+-- permitted to check validation.
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslkey 'value', ADD sslcert 'value');
+ALTER FOREIGN TABLE ft1 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft2 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+ALTER FOREIGN TABLE ft2 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+\det+
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------+-------+-----------+---------------------------------------+-------------
+ public | ft1 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft2 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft4 | loopback | (schema_name 'S 1', table_name 'T 3') |
+ public | ft5 | loopback | (schema_name 'S 1', table_name 'T 4') |
+ public | ft6 | loopback2 | (schema_name 'S 1', table_name 'T 4') |
+ public | ft7 | loopback3 | (schema_name 'S 1', table_name 'T 4') |
+(6 rows)
+
+-- Test that alteration of server options causes reconnection
+-- Remote's errors might be non-English, so hide them to ensure stable results
+\set VERBOSITY terse
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET dbname 'no such database');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+DO $d$
+ BEGIN
+ EXECUTE $$ALTER SERVER loopback
+ OPTIONS (SET dbname '$$||current_database()||$$')$$;
+ END;
+$d$;
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+-- Test that alteration of user mapping options causes reconnection
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (ADD user 'no such user');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (DROP user);
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+\set VERBOSITY default
+-- Now we should be able to run ANALYZE.
+-- To exercise multiple code paths, we use local stats on ft1
+-- and remote-estimate mode on ft2.
+ANALYZE ft1;
+ALTER FOREIGN TABLE ft2 OPTIONS (use_remote_estimate 'true');
+-- ===================================================================
+-- test error case for create publication on foreign table
+-- ===================================================================
+CREATE PUBLICATION testpub_ftbl FOR TABLE ft1; -- should fail
+ERROR: cannot add relation "ft1" to publication
+DETAIL: This operation is not supported for foreign tables.
+-- ===================================================================
+-- simple queries
+-- ===================================================================
+-- single table without alias
+EXPLAIN (COSTS OFF) SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------
+ Foreign Scan on ft1
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- single table with alias - also test that tableoid sort is not pushed to remote side
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ -> Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Sort Key: t1.c3, t1.c1, t1.tableoid
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(8 rows)
+
+SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF) SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: t1.*, c3, c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c3 ASC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(3 rows)
+
+SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ t1
+--------------------------------------------------------------------------------------------
+ (101,1,00101,"Fri Jan 02 00:00:00 1970 PST","Fri Jan 02 00:00:00 1970",1,"1 ",foo)
+ (102,2,00102,"Sat Jan 03 00:00:00 1970 PST","Sat Jan 03 00:00:00 1970",2,"2 ",foo)
+ (103,3,00103,"Sun Jan 04 00:00:00 1970 PST","Sun Jan 04 00:00:00 1970",3,"3 ",foo)
+ (104,4,00104,"Mon Jan 05 00:00:00 1970 PST","Mon Jan 05 00:00:00 1970",4,"4 ",foo)
+ (105,5,00105,"Tue Jan 06 00:00:00 1970 PST","Tue Jan 06 00:00:00 1970",5,"5 ",foo)
+ (106,6,00106,"Wed Jan 07 00:00:00 1970 PST","Wed Jan 07 00:00:00 1970",6,"6 ",foo)
+ (107,7,00107,"Thu Jan 08 00:00:00 1970 PST","Thu Jan 08 00:00:00 1970",7,"7 ",foo)
+ (108,8,00108,"Fri Jan 09 00:00:00 1970 PST","Fri Jan 09 00:00:00 1970",8,"8 ",foo)
+ (109,9,00109,"Sat Jan 10 00:00:00 1970 PST","Sat Jan 10 00:00:00 1970",9,"9 ",foo)
+ (110,0,00110,"Sun Jan 11 00:00:00 1970 PST","Sun Jan 11 00:00:00 1970",0,"0 ",foo)
+(10 rows)
+
+-- empty result
+SELECT * FROM ft1 WHERE false;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- with WHERE clause
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c7 >= '1')) AND (("C 1" = 101)) AND ((c6 = '1'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- with FOR UPDATE/SHARE
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 101)) FOR UPDATE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 102)) FOR SHARE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+-- aggregate
+SELECT COUNT(*) FROM ft1 t1;
+ count
+-------
+ 1000
+(1 row)
+
+-- subquery
+SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- subquery+MAX
+SELECT * FROM ft1 t1 WHERE t1.c3 = (SELECT MAX(c3) FROM ft2 t2) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+(1 row)
+
+-- used in CTE
+WITH t1 AS (SELECT * FROM ft1 WHERE c1 <= 10) SELECT t2.c1, t2.c2, t2.c3, t2.c4 FROM t1, ft2 t2 WHERE t1.c1 = t2.c1 ORDER BY t1.c1;
+ c1 | c2 | c3 | c4
+----+----+-------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+(10 rows)
+
+-- fixed values
+SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1;
+ ?column? | ?column?
+----------+----------
+ fixed |
+(1 row)
+
+-- Test forcing the remote server to produce sorted data for a merge join.
+SET enable_hashjoin TO false;
+SET enable_nestloop TO false;
+-- inner join; expressions in the clauses appear in the equivalence class list
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Left Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- A join between local table and foreign join. ORDER BY clause is added to the
+-- foreign join so that the local table can be joined using merge join strategy.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Merge Right Join
+ Output: t1."C 1"
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r3."C 1" FROM ("S 1"."T 1" r2 INNER JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r2."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- Test similar to above, except that the full join prevents any equivalence
+-- classes from being merged. This produces single relation equivalence classes
+-- included in join restrictions.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Right Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1, t2.c1
+ Relations: (public.ft2 t3) LEFT JOIN (public.ft1 t2)
+ Remote SQL: SELECT r3."C 1", r2."C 1" FROM ("S 1"."T 1" r3 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+-- Test similar to above with all full outer joins
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Full Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) FULL JOIN (public.ft2 t3)
+ Remote SQL: SELECT r2."C 1", r3."C 1" FROM ("S 1"."T 1" r2 FULL JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test executing assertion in estimate_path_cost_size() that makes sure that
+-- retrieved_rows for foreign rel re-used to cost pre-sorted foreign paths is
+-- a sensible value even when the rel has tuples=0
+CREATE TABLE loct_empty (c1 int NOT NULL, c2 text);
+CREATE FOREIGN TABLE ft_empty (c1 int NOT NULL, c2 text)
+ SERVER loopback OPTIONS (table_name 'loct_empty');
+INSERT INTO loct_empty
+ SELECT id, 'AAA' || to_char(id, 'FM000') FROM generate_series(1, 100) id;
+DELETE FROM loct_empty;
+ANALYZE ft_empty;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Foreign Scan on public.ft_empty
+ Output: c1, c2
+ Remote SQL: SELECT c1, c2 FROM public.loct_empty ORDER BY c1 ASC NULLS LAST
+(3 rows)
+
+-- ===================================================================
+-- WHERE with remotely-executable conditions
+-- ===================================================================
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1; -- Var, OpExpr(b), Const
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL; -- NullTest
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL; -- NullTest
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((round(abs("C 1"), 0) = 1::numeric))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1; -- OpExpr(l)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = (- "C 1")))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" IS NOT NULL) IS DISTINCT FROM ("C 1" IS NOT NULL)))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]); -- ScalarArrayOpExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ANY (ARRAY[c2, 1, ("C 1" + 0)])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1]; -- SubscriptingRef
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ((ARRAY["C 1", c2, 3])[1])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar'; -- check special chars
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c6 = E'foo''s\\bar'))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c8 = 'foo'; -- can't be sent to remote
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- parameterized remote path for foreign table
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM "S 1"."T 1" a, ft2 b WHERE a."C 1" = 47 AND b.c1 = a.c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Index Scan using t1_pkey on "S 1"."T 1" a
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Index Cond: (a."C 1" = 47)
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(8 rows)
+
+SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 47 | 7 | 00047 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo | 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+(1 row)
+
+-- check both safe and unsafe join conditions
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 a, ft2 b
+ WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Foreign Scan on public.ft2 a
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Filter: (a.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c2 = 6))
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Filter: (upper((a.c7)::text) = (b.c7)::text)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(10 rows)
+
+SELECT * FROM ft2 a, ft2 b
+WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+(100 rows)
+
+-- bug before 9.3.5 due to sloppy handling of remote-estimate parameters
+SELECT * FROM ft1 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft2 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+SELECT * FROM ft2 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft1 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+-- we should not push order by clause with volatile expressions or unsafe
+-- collations
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, random();
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, (random())
+ Sort Key: ft2.c1, (random())
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, random()
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, ft2.c3 collate "C";
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, ((c3)::text)
+ Sort Key: ft2.c1, ft2.c3 COLLATE "C"
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- user-defined operator/function
+CREATE FUNCTION postgres_fdw_abs(int) RETURNS int AS $$
+BEGIN
+RETURN abs($1);
+END
+$$ LANGUAGE plpgsql IMMUTABLE;
+CREATE OPERATOR === (
+ LEFTARG = int,
+ RIGHTARG = int,
+ PROCEDURE = int4eq,
+ COMMUTATOR = ===
+);
+-- built-in operators and functions can be shipped for remote execution
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ QUERY PLAN
+----------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- by default, user-defined ones cannot
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 = postgres_fdw_abs(t1.c2))
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- ORDER BY can be shipped, though
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- but let's put them in an extension ...
+ALTER EXTENSION postgres_fdw ADD FUNCTION postgres_fdw_abs(int);
+ALTER EXTENSION postgres_fdw ADD OPERATOR === (int, int);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- ... now they can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- and both ORDER BY and LIMIT can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2)) ORDER BY c2 ASC NULLS LAST LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- Test CASE pushdown
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE WHEN ("C 1" > 990) THEN "C 1" ELSE NULL::integer END) < 1000)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ c1 | c2 | c3
+-----+----+-------
+ 991 | 1 | 00991
+ 992 | 2 | 00992
+ 993 | 3 | 00993
+ 994 | 4 | 00994
+ 995 | 5 | 00995
+ 996 | 6 | 00996
+ 997 | 7 | 00997
+ 998 | 8 | 00998
+ 999 | 9 | 00999
+(9 rows)
+
+-- Nested CASE
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE (CASE WHEN (c2 > 0) THEN c2 ELSE NULL::integer END) WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END) > 600)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ c1 | c2 | c3
+----+----+----
+(0 rows)
+
+-- CASE arg WHEN
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE mod(c1, 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" > (CASE mod("C 1", 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)))
+(3 rows)
+
+-- CASE cannot be pushed down because of unshippable arg clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE random()::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (ft1.c1 > CASE (random())::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- these are shippable
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c6 WHEN 'foo' THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c6 WHEN 'foo'::text THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c3 WHEN c6 THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+-- but this is not because of collation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 COLLATE "C" WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: CASE (ft1.c3)::text WHEN ft1.c6 THEN true ELSE (ft1.c3 < 'bar'::text) END
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- a regconfig constant referring to this text search configuration
+-- is initially unshippable
+CREATE TEXT SEARCH CONFIGURATION public.custom_search
+ (COPY = pg_catalog.english);
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Filter: (length(to_tsvector('custom_search'::regconfig, ft1.c3)) > 0)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642))
+(4 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- but if it's in a shippable extension, it can be shipped
+ALTER EXTENSION postgres_fdw ADD TEXT SEARCH CONFIGURATION public.custom_search;
+-- however, that doesn't flush the shippability cache, so do a quick reconnect
+\c -
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642)) AND ((length(to_tsvector('public.custom_search'::regconfig, c3)) > 0))
+(3 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- ===================================================================
+-- JOIN queries
+-- ===================================================================
+-- Analyze ft4 and ft5 so that we have better statistics. These tables do not
+-- have use_remote_estimate set.
+ANALYZE ft4;
+ANALYZE ft5;
+-- join two tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3, t1.c3
+ Relations: ((public.ft1 t1) INNER JOIN (public.ft2 t2)) INNER JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3, r1.c3 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) INNER JOIN "S 1"."T 3" r4 ON (((r1."C 1" = r4.c1)))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 22 |
+ 24 | 24
+ 26 |
+ 28 |
+ 30 | 30
+ 32 |
+ 34 |
+ 36 | 36
+ 38 |
+ 40 |
+(10 rows)
+
+-- left outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + placement of clauses.
+-- clauses within the nullable side are not pulled up, but top level clause on
+-- non-nullable side is pushed into non-nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- clauses within the nullable side are not pulled up, but the top level clause
+-- on nullable side is not pushed down into nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE (((r4.c1 < 10) OR (r4.c1 IS NULL))) AND ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t2) LEFT JOIN (public.ft5 t1)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r1 ON (((r1.c1 = r2.c1)))) ORDER BY r2.c1 ASC NULLS LAST, r1.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ | 22
+ 24 | 24
+ | 26
+ | 28
+ 30 | 30
+ | 32
+ | 34
+ 36 | 36
+ | 38
+ | 40
+(10 rows)
+
+-- right outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 45::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ c1 | c1
+-----+----
+ 92 |
+ 94 |
+ 96 | 96
+ 98 |
+ 100 |
+ | 3
+ | 9
+ | 15
+ | 21
+ | 27
+(10 rows)
+
+-- full outer join with restrictions on the joining relations
+-- a. the joining relations are both base relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s4.c1, s5.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s5.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ c1 | c1
+----+----
+ 50 |
+ 52 |
+ 54 | 54
+ 56 |
+ 58 |
+ 60 | 60
+ | 51
+ | 57
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: 1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT NULL FROM ((SELECT NULL FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4 FULL JOIN (SELECT NULL FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5 ON (TRUE)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ ?column?
+----------
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- b. one of the joining relations is a base relation and the other is a join
+-- relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c1, t3.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 t2) LEFT JOIN (public.ft5 t3))
+ Remote SQL: SELECT s4.c1, s8.c1, s8.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT r5.c1, r6.c1 FROM ("S 1"."T 3" r5 LEFT JOIN "S 1"."T 4" r6 ON (((r5.c1 = r6.c1)))) WHERE ((r5.c1 >= 50)) AND ((r5.c1 <= 60))) s8(c1, c2) ON (((s4.c1 = s8.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s8.c1 ASC NULLS LAST, s8.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+(6 rows)
+
+-- c. test deparsing the remote query as nested subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft4_1.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 ft4_1) FULL JOIN (public.ft5))
+ Remote SQL: SELECT s4.c1, s10.c1, s10.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT s8.c1, s9.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL)))) s10(c1, c2) ON (((s4.c1 = s10.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s10.c1 ASC NULLS LAST, s10.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+ | | 51
+ | | 57
+(8 rows)
+
+-- d. test deparsing rowmarked relations as subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Nested Loop
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Foreign Scan
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s8.c1, s8.c2, s9.c1, s9.c2 FROM ((SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1, c2) FULL JOIN (SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1, c2) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL))) ORDER BY s8.c1 ASC NULLS LAST, s9.c1 ASC NULLS LAST
+ -> Sort
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Full Join
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Hash Cond: (ft4.c1 = ft5.c1)
+ Filter: ((ft4.c1 IS NULL) OR (ft4.c1 IS NOT NULL))
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Hash
+ Output: ft5.c1, ft5.*
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Materialize
+ Output: "T 3".c1, "T 3".ctid
+ -> Seq Scan on "S 1"."T 3"
+ Output: "T 3".c1, "T 3".ctid
+ Filter: ("T 3".c1 = 50)
+(28 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 50 | 52 |
+ 50 | 54 | 54
+ 50 | 56 |
+ 50 | 58 |
+ 50 | 60 | 60
+ 50 | | 51
+ 50 | | 57
+(8 rows)
+
+-- full outer join + inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t3.c1
+ Relations: ((public.ft4 t1) INNER JOIN (public.ft5 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1.c1, r2.c1, r4.c1 FROM (("S 1"."T 3" r1 INNER JOIN "S 1"."T 4" r2 ON (((r1.c1 = (r2.c1 + 1))) AND ((r1.c1 >= 50)) AND ((r1.c1 <= 60)))) FULL JOIN "S 1"."T 3" r4 ON (((r2.c1 = r4.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST, r4.c1 ASC NULLS LAST LIMIT 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ c1 | c1 | c1
+----+----+----
+ 52 | 51 |
+ 58 | 57 |
+ | | 2
+ | | 4
+ | | 6
+ | | 8
+ | | 10
+ | | 12
+ | | 14
+ | | 16
+(10 rows)
+
+-- full outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- right outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+SET enable_memoize TO off;
+-- right outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+RESET enable_memoize;
+-- left outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: (public.ft4 t3) LEFT JOIN ((public.ft2 t1) INNER JOIN (public.ft2 t2))
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM ("S 1"."T 3" r4 LEFT JOIN ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join + WHERE clause, only matched rows
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 = r2.c1) OR (r1.c1 IS NULL)))
+(9 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 66 | 66
+ 72 | 72
+ 78 | 78
+ 84 | 84
+ 90 | 90
+ 96 | 96
+ | 3
+ | 9
+ | 15
+ | 21
+(10 rows)
+
+-- full outer join + WHERE clause with shippable extensions set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) WHERE ((public.postgres_fdw_abs(r1."C 1") > 0)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+-- full outer join + WHERE clause with shippable extensions not set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c2, t1.c3
+ -> Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Filter: (postgres_fdw_abs(t1.c1) > 0)
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- join two tables with FOR UPDATE clause
+-- tests whole-row reference for row marks
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1 FOR UPDATE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join two tables with FOR SHARE clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1 FOR SHARE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join in CTE
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t.c1_1, t.c2_1, t.c1_3
+ CTE t
+ -> Foreign Scan
+ Output: t1.c1, t1.c3, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r1.c3, r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+ -> Sort
+ Output: t.c1_1, t.c2_1, t.c1_3
+ Sort Key: t.c1_3, t.c1_1
+ -> CTE Scan on t
+ Output: t.c1_1, t.c2_1, t.c1_3
+(12 rows)
+
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ c1_1 | c2_1
+------+------
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- ctid with whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.ctid, t1.*, t2.*, t1.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r1."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+-- SEMI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Semi Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c1)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- ANTI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Anti Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c2)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 110
+ 111
+ 112
+ 113
+ 114
+ 115
+ 116
+ 117
+ 118
+ 119
+(10 rows)
+
+-- CROSS JOIN can be pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (TRUE)) ORDER BY r1."C 1" ASC NULLS LAST, r2."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- different server, not pushed down. No result expected.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Merge Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft6 t2
+ Output: t2.c1, t2.c2, t2.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+ -> Materialize
+ Output: t1.c1, t1.c2, t1.c3
+ -> Foreign Scan on public.ft5 t1
+ Output: t1.c1, t1.c2, t1.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+(13 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+----
+(0 rows)
+
+-- unsafe join conditions (c8 has a UDT), not pushed down. Practically a CROSS
+-- JOIN since c8 in both tables has same value.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Merge Left Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t1.c8 = t2.c8)
+ -> Sort
+ Output: t1.c1, t1.c8
+ Sort Key: t1.c8
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+ -> Sort
+ Output: t2.c1, t2.c8
+ Sort Key: t2.c8
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1, t2.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+(20 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- unsafe conditions on one side (c8 has a UDT), not pushed down.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Hash Right Join
+ Output: t1.c1, t2.c1, t1.c3
+ Hash Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+ -> Hash
+ Output: t1.c1, t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c3
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c3, c8 FROM "S 1"."T 1"
+(17 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join where unsafe to pushdown condition in WHERE clause has a column not
+-- in the SELECT clause. In this test unsafe clause needs to have column
+-- references from both joining sides so that the clause is not pushed down
+-- into one of the joining sides.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Filter: (t1.c8 = t2.c8)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, r1.c8, r2.c8 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(10 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- Aggregate after UNION, for testing setrefs
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ -> Sort
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ Sort Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, avg((t1.c1 + t2.c1))
+ Group Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, t2.c1
+ Group Key: t1.c1, t2.c1
+ -> Append
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+ -> Foreign Scan
+ Output: t1_1.c1, t2_1.c1
+ Relations: (public.ft1 t1_1) INNER JOIN (public.ft2 t2_1)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(20 rows)
+
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ t1c1 | avg
+------+----------------------
+ 101 | 202.0000000000000000
+ 102 | 204.0000000000000000
+ 103 | 206.0000000000000000
+ 104 | 208.0000000000000000
+ 105 | 210.0000000000000000
+ 106 | 212.0000000000000000
+ 107 | 214.0000000000000000
+ 108 | 216.0000000000000000
+ 109 | 218.0000000000000000
+ 110 | 220.0000000000000000
+(10 rows)
+
+-- join with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Nested Loop
+ Output: t1."C 1"
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ -> Memoize
+ Cache Key: t1.c2
+ Cache Mode: binary
+ -> Subquery Scan on q
+ -> HashAggregate
+ Output: t2.c1, t3.c1
+ Group Key: t2.c1, t3.c1
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r1.c2 = $1::integer))))
+(17 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ C 1
+-----
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- non-Var items in targetlist of the nullable rel of a join preventing
+-- push-down in some cases
+-- unable to push {ft1, ft2}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: (13), ft2.c1
+ Join Filter: (13 = ft2.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" WHERE (("C 1" >= 10)) AND (("C 1" <= 15)) ORDER BY "C 1" ASC NULLS LAST
+ -> Materialize
+ Output: (13)
+ -> Foreign Scan on public.ft1
+ Output: 13
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 13))
+(11 rows)
+
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ a | c1
+----+----
+ | 10
+ | 11
+ | 12
+ 13 | 13
+ | 14
+ | 15
+(6 rows)
+
+-- ok to push {ft1, ft2} but not {ft1, ft2, ft4}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: ft4.c1, (13), ft1.c1, ft2.c1
+ Join Filter: (ft4.c1 = ft1.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
+ -> Materialize
+ Output: ft1.c1, ft2.c1, (13)
+ -> Foreign Scan
+ Output: ft1.c1, ft2.c1, 13
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r5."C 1" FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = 12)) AND ((r4."C 1" = 12)))) ORDER BY r4."C 1" ASC NULLS LAST
+(12 rows)
+
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ c1 | a | b | c
+----+----+----+----
+ 10 | | |
+ 12 | 13 | 12 | 12
+ 14 | | |
+(3 rows)
+
+-- join with nullable side with some columns with null values
+UPDATE ft5 SET c3 = null where c1 % 9 = 0;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2
+ Relations: (public.ft5) INNER JOIN (public.ft4)
+ Remote SQL: SELECT CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1.c1, r1.c2, r1.c3) END, r1.c1, r1.c2, r1.c3, r2.c1, r2.c2 FROM ("S 1"."T 4" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c1 = r2.c1)) AND ((r2.c1 >= 10)) AND ((r2.c1 <= 30)))) ORDER BY r1.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ ft5 | c1 | c2 | c3 | c1 | c2
+----------------+----+----+--------+----+----
+ (12,13,AAA012) | 12 | 13 | AAA012 | 12 | 13
+ (18,19,) | 18 | 19 | | 18 | 19
+ (24,25,AAA024) | 24 | 25 | AAA024 | 24 | 25
+ (30,31,AAA030) | 30 | 31 | AAA030 | 30 | 31
+(4 rows)
+
+-- multi-way join involving multiple merge joins
+-- (this case used to have EPQ-related planning problems)
+CREATE TABLE local_tbl (c1 int NOT NULL, c2 int NOT NULL, c3 text, CONSTRAINT local_tbl_pkey PRIMARY KEY (c1));
+INSERT INTO local_tbl SELECT id, id % 10, to_char(id, 'FM0000') FROM generate_series(1, 1000) id;
+ANALYZE local_tbl;
+SET enable_nestloop TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ Inner Unique: true
+ Merge Cond: (ft1.c2 = local_tbl.c1)
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Relations: (((public.ft1) INNER JOIN (public.ft2)) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r3.c1, r3.c2, r3.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r4.c1, r4.c2, r4.c3, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4.c1, r4.c2, r4.c3) END FROM ((("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r2."C 1" < 100)) AND ((r1."C 1" < 100)))) INNER JOIN "S 1"."T 3" r3 ON (((r1.c2 = r3.c1)))) INNER JOIN "S 1"."T 4" r4 ON (((r1.c2 = r4.c1)))) ORDER BY r1.c2 ASC NULLS LAST FOR UPDATE OF r1 FOR UPDATE OF r2 FOR UPDATE OF r3 FOR UPDATE OF r4
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Merge Cond: (ft1.c2 = ft5.c1)
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Merge Cond: (ft1.c2 = ft4.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Sort Key: ft1.c2
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Merge Cond: (ft1.c1 = ft2.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) FOR UPDATE
+ -> Materialize
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Sort
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Sort Key: ft4.c1
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" FOR UPDATE
+ -> Sort
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Sort Key: ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" FOR UPDATE
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+(47 rows)
+
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3 | c1 | c2 | c3
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+--------+----+----+--------+----+----+------
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+(10 rows)
+
+RESET enable_nestloop;
+RESET enable_hashjoin;
+-- test that add_paths_with_pathkeys_for_rel() arranges for the epq_path to
+-- return columns needed by the parent ForeignScan node
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.*, COALESCE(ft1.c3 || ft2.c3, 'foobar') FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100)) ss ON (local_tbl.c1 = ss.c1) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ -> Merge Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ Merge Cond: (local_tbl.c1 = ft1.c1)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text))
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c3 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r4."C 1" = r5."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4."C 1" ASC NULLS LAST
+ -> Result
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c3
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), ft2.c3
+ Sort Key: ft1.c1
+ -> Hash Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text), ft2.c3
+ Hash Cond: (ft1.c1 = ft2.c1)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Hash
+ Output: ft2.*, ft2.c1, ft2.c3
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(29 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD fdw_startup_cost '10000.0');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.* FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100 AND ft1.c1 = postgres_fdw_abs(ft2.c2))) ss ON (local_tbl.c3 = ss.c3) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ -> Nested Loop Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ Join Filter: (local_tbl.c3 = ft1.c3)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ Filter: (ft1.c1 = postgres_fdw_abs(ft2.c2))
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c2 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r4."C 1" = r5."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4.c3 ASC NULLS LAST
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Sort Key: ft1.c3
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Merge Cond: ((ft1.c1 = (postgres_fdw_abs(ft2.c2))) AND (ft1.c1 = ft2.c1))
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Sort
+ Output: ft2.*, ft2.c1, ft2.c2, (postgres_fdw_abs(ft2.c2))
+ Sort Key: (postgres_fdw_abs(ft2.c2)), ft2.c1
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, postgres_fdw_abs(ft2.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(32 rows)
+
+ALTER SERVER loopback OPTIONS (DROP fdw_startup_cost);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+DROP TABLE local_tbl;
+-- check join pushdown in situations where multiple userids are involved
+CREATE ROLE regress_view_owner SUPERUSER;
+CREATE USER MAPPING FOR regress_view_owner SERVER loopback;
+GRANT SELECT ON ft4 TO regress_view_owner;
+GRANT SELECT ON ft5 TO regress_view_owner;
+CREATE VIEW v4 AS SELECT * FROM ft4;
+CREATE VIEW v5 AS SELECT * FROM ft5;
+ALTER VIEW v5 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, different view owners
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, ft5.c2, ft5.c1
+ -> Sort
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Left Join
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.c2, ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c2, ft5.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r6.c1, r9.c2, r9.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r9 ON (((r6.c1 = r9.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r9.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, view owner not current user
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, t2.c2, t2.c1
+ -> Sort
+ Output: ft4.c1, t2.c2, t2.c1
+ Sort Key: ft4.c1, t2.c1
+ -> Hash Left Join
+ Output: ft4.c1, t2.c2, t2.c1
+ Hash Cond: (ft4.c1 = t2.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: t2.c2, t2.c1
+ -> Foreign Scan on public.ft5 t2
+ Output: t2.c2, t2.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO CURRENT_USER;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c2, t2.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r6.c1, r2.c2, r2.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r2 ON (((r6.c1 = r2.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+-- cleanup
+DROP OWNED BY regress_view_owner;
+DROP ROLE regress_view_owner;
+-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+------+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+ 100 | 49700 | 497.0000000000000000 | 2 | 992 | 0 | 49700
+ 100 | 49800 | 498.0000000000000000 | 3 | 993 | 0 | 49800
+ 100 | 49900 | 499.0000000000000000 | 4 | 994 | 0 | 49900
+ 100 | 50500 | 505.0000000000000000 | 0 | 1000 | 0 | 50500
+(5 rows)
+
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST LIMIT 1::bigint
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+-----+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+(1 row)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * (random() <= 1)::int) as sum, avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Aggregate
+ Output: sum((c1 * ((random() <= '1'::double precision))::integer)), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT count(*), sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ count | sum | avg
+-------+---------+----------------------
+ 10000 | 5010000 | 501.0000000000000000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where ((t1.c1 * t2.c1)/(t1.c1 * t2.c1)) * random() <= 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(t1.c1), count(t2.c1)
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Filter: (((((t1.c1 * t2.c1) / (t1.c1 * t2.c1)))::double precision * random()) <= '1'::double precision)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY 1 ORDER BY (c2 / 2) ASC NULLS LAST
+(4 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 500
+ 2 | 1800
+ 3 | 3900
+ 4 | 6800
+(5 rows)
+
+-- Aggregates in subquery are pushed down.
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 ORDER BY c2 ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(6 rows)
+
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+------
+ 1000 | 4500
+(1 row)
+
+-- Aggregate is still pushed down by taking unshippable expression out
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer)), ((sum(c1) * c2)), c2
+ Sort Key: ((ft1.c2 * ((random() <= '1'::double precision))::integer)), ((sum(ft1.c1) * ft1.c2))
+ -> Foreign Scan
+ Output: (c2 * ((random() <= '1'::double precision))::integer), ((sum(c1) * c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum("C 1") * c2), c2 FROM "S 1"."T 1" GROUP BY 2
+(7 rows)
+
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ sum1 | sum2
+------+--------
+ 0 | 0
+ 1 | 49600
+ 2 | 99400
+ 3 | 149400
+ 4 | 199600
+ 5 | 250000
+ 6 | 300600
+ 7 | 351400
+ 8 | 402400
+ 9 | 453600
+(10 rows)
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::int order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Sort Key: ((ft2.c2 * ((random() <= '1'::double precision))::integer))
+ -> HashAggregate
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Group Key: (ft2.c2 * ((random() <= '1'::double precision))::integer)
+ -> Foreign Scan on public.ft2
+ Output: (c2 * ((random() <= '1'::double precision))::integer)
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- GROUP BY clause in various forms, cardinal, alias and constant expression
+explain (verbose, costs off)
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), c2, 5, 7.0, 9 FROM "S 1"."T 1" GROUP BY 2, 3, 5
+(7 rows)
+
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ w | x | y | z
+-----+---+---+-----
+ 100 | 0 | 5 | 7.0
+ 100 | 1 | 5 | 7.0
+ 100 | 2 | 5 | 7.0
+ 100 | 3 | 5 | 7.0
+ 100 | 4 | 5 | 7.0
+ 100 | 5 | 5 | 7.0
+ 100 | 6 | 5 | 7.0
+ 100 | 7 | 5 | 7.0
+ 100 | 8 | 5 | 7.0
+ 100 | 9 | 5 | 7.0
+(10 rows)
+
+-- GROUP BY clause referring to same column multiple times
+-- Also, ORDER BY contains an aggregate function
+explain (verbose, costs off)
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, c2, (sum(c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, c2, sum("C 1") FROM "S 1"."T 1" WHERE ((c2 > 6)) GROUP BY 1, 2 ORDER BY sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ c2 | c2
+----+----
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(3 rows)
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 49800)) ORDER BY c2 ASC NULLS LAST
+(4 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ c2 | sum
+----+-------
+ 1 | 49600
+ 2 | 49700
+(2 rows)
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, NULL::bigint, (sqrt((ft1.c2)::double precision))
+ Filter: (((((avg(ft1.c1)) / (avg(ft1.c1))))::double precision * random()) <= '1'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ count
+-------
+ 49
+(1 row)
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * (random() <= 1)::int) > 100 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1)), c2
+ Sort Key: (sum(ft1.c1))
+ -> HashAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Filter: (avg((ft1.c1 * ((random() <= '1'::double precision))::integer)) > '100'::numeric)
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(10 rows)
+
+-- Remote aggregate in combination with a local Param (for the output
+-- of an initplan) can be trouble, per bug #15781
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ QUERY PLAN
+--------------------------------------------------
+ Foreign Scan
+ Output: $0, (sum(ft1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1"
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+(6 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ QUERY PLAN
+---------------------------------------------------
+ GroupAggregate
+ Output: ($0), sum(ft1.c1)
+ Group Key: $0
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+ -> Foreign Scan on public.ft1
+ Output: $0, ft1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(8 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY 2 ORDER BY array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1,11,21,31,41,51,61,71,81,91}
+ {2,12,22,32,42,52,62,72,82,92}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {5,15,25,35,45,55,65,75,85,95}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+(10 rows)
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5)) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY 2 ORDER BY sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))) ASC NULLS LAST
+(4 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+(10 rows)
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3) ORDER BY (("C 1" % 3)) ASC NULLS LAST) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY 3
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft2 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where (c1 / c1) * random() <= 1) from ft1 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((((ft1.c1 / ft1.c1))::double precision * random()) <= '1'::double precision)))
+ -> HashAggregate
+ Output: sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST), percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
+(7 rows)
+
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | rank | percentile_cont
+----+------+-----------------
+ 0 | 101 | 10
+ 1 | 101 | 100
+ 2 | 1 | 200
+ 3 | 1 | 300
+ 4 | 1 | 400
+(5 rows)
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY 1, 3
+(4 rows)
+
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ c1 | rank
+----+------
+ 6 | 1
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Disable hash aggregation for plan stability.
+set enable_hashagg to false;
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY 1
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 0 | 10
+ 1 | 1
+ 2 | 2
+ 3 | 3
+ 4 | 4
+ 5 | 5
+ 6 | 6
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(10 rows)
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Cleanup
+reset enable_hashagg;
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+create operator family my_op_family using btree;
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- This should not be pushed either.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- Update local stats on ft2
+ANALYZE ft2;
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now this will be pushed as sort operator is part of the extension.
+alter server loopback options (add fdw_tuple_cost '0.5');
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY 2
+(4 rows)
+
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+alter server loopback options (drop fdw_tuple_cost);
+-- This should be pushed too.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST
+(3 rows)
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft2 t1 left join ft2 t2 on (t1.c1 = random() * t2.c2);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop Left Join
+ Output: t1.c3
+ Join Filter: ((t1.c1)::double precision = (random() * (t2.c2)::double precision))
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c3, t1.c1
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1"
+ -> Materialize
+ Output: t2.c2
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(13 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Inner Unique: true
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1 ft1_1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1
+(21 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 100 | 49600
+ 100 | 49700
+ 100 | 49800
+ 100 | 49900
+ 100 | 50000
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(10 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY 3 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL))) ORDER BY avg(r1.c1) ASC NULLS LAST, sum(r2.c1) ASC NULLS LAST
+(4 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- Aggregate over FULL join needing to deparse the joining relations as
+-- subqueries.
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(ft4.c1)), (avg(ft5.c1))
+ Relations: Aggregate on ((public.ft4) FULL JOIN (public.ft5))
+ Remote SQL: SELECT count(*), sum(s4.c1), avg(s5.c1) FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ count | sum | avg
+-------+-----+---------------------
+ 8 | 330 | 55.5000000000000000
+(1 row)
+
+-- ORDER BY expression is part of the target list but not pushed down to
+-- foreign server.
+explain (verbose, costs off)
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: (((sum(c2)) * ((random() <= '1'::double precision))::integer))
+ Sort Key: (((sum(ft1.c2)) * ((random() <= '1'::double precision))::integer))
+ -> Foreign Scan
+ Output: ((sum(c2)) * ((random() <= '1'::double precision))::integer)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
+(7 rows)
+
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ sum
+------
+ 4500
+(1 row)
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c2, qry.sum
+ Sort Key: t1.c2
+ -> Nested Loop
+ Output: t1.c2, qry.sum
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Index Cond: (t1."C 1" < 100)
+ Filter: (t1.c2 < 3)
+ -> Subquery Scan on qry
+ Output: qry.sum, t2.c1
+ Filter: ((t1.c2 * 2) = qry.sum)
+ -> Foreign Scan
+ Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY 2
+(16 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ c2 | sum
+----+-----
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+reset enable_hashagg;
+-- bug #15613: bad plan for foreign table scan with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: ref_0.c2, ref_0."C 1", (ref_0.c2), ref_1.c3, ref_0."C 1"
+ -> Nested Loop
+ Output: ref_0.c2, ref_0."C 1", ref_1.c3, (ref_0.c2)
+ -> Index Scan using t1_pkey on "S 1"."T 1" ref_0
+ Output: ref_0."C 1", ref_0.c2, ref_0.c3, ref_0.c4, ref_0.c5, ref_0.c6, ref_0.c7, ref_0.c8
+ Index Cond: (ref_0."C 1" < 10)
+ -> Foreign Scan on public.ft1 ref_1
+ Output: ref_1.c3, ref_0.c2
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+ -> Materialize
+ Output: ref_3.c3
+ -> Foreign Scan on public.ft2 ref_3
+ Output: ref_3.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+(15 rows)
+
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ c2 | c1 | c2 | c3
+----+----+----+-------
+ 1 | 1 | 1 | 00001
+ 2 | 2 | 2 | 00001
+ 3 | 3 | 3 | 00001
+ 4 | 4 | 4 | 00001
+ 5 | 5 | 5 | 00001
+ 6 | 6 | 6 | 00001
+ 7 | 7 | 7 | 00001
+ 8 | 8 | 8 | 00001
+ 9 | 9 | 9 | 00001
+(9 rows)
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(q.a), count(q.b)
+ -> Nested Loop Left Join
+ Output: q.a, q.b
+ Inner Unique: true
+ Join Filter: ((ft4.c1)::numeric <= q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Materialize
+ Output: q.a, q.b
+ -> Subquery Scan on q
+ Output: q.a, q.b
+ -> Foreign Scan
+ Output: 13, (avg(ft1.c1)), NULL::bigint
+ Relations: Aggregate on ((public.ft2) LEFT JOIN (public.ft1))
+ Remote SQL: SELECT 13, avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1"))))
+(17 rows)
+
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ sum | count
+-----+-------
+ 650 | 50
+(1 row)
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: c2, c6, (sum(c1))
+ Sort Key: ft1.c2, ft1.c6
+ -> HashAggregate
+ Output: c2, c6, sum(c1)
+ Hash Key: ft1.c2
+ Hash Key: ft1.c6
+ -> Foreign Scan on public.ft1
+ Output: c2, c6, c1
+ Remote SQL: SELECT "C 1", c2, c6 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 0 | | 50500
+ 1 | | 49600
+ 2 | | 49700
+ | 0 | 50500
+ | 1 | 49600
+ | 2 | 49700
+(6 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1)), (GROUPING(c2))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, sum(c1), GROUPING(c2)
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(9 rows)
+
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 0 | 50500 | 0
+ 1 | 49600 | 0
+ 2 | 49700 | 0
+(3 rows)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((sum(c1) / 1000)), c2
+ -> Sort
+ Output: ((sum(c1) / 1000)), c2
+ Sort Key: ((sum(ft2.c1) / 1000))
+ -> Foreign Scan
+ Output: ((sum(c1) / 1000)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT (sum("C 1") / 1000), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY 2
+(9 rows)
+
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ s
+----
+ 49
+ 50
+(2 rows)
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2)), (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, (sum(c2)), count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ c2 | sum | count
+----+-----+-------
+ 0 | 0 | 5
+ 1 | 100 | 5
+ 2 | 200 | 5
+ 3 | 300 | 5
+ 4 | 400 | 5
+ 5 | 500 | 5
+ 6 | 600 | 5
+ 7 | 700 | 5
+ 8 | 800 | 5
+ 9 | 900 | 5
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2 DESC
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {8,6,4,2,0}
+ 1 | {9,7,5,3,1}
+ 2 | {8,6,4,2}
+ 3 | {9,7,5,3}
+ 4 | {8,6,4}
+ 5 | {9,7,5}
+ 6 | {8,6}
+ 7 | {9,7}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {0,2,4,6,8}
+ 1 | {1,3,5,7,9}
+ 2 | {2,4,6,8}
+ 3 | {3,5,7,9}
+ 4 | {4,6,8}
+ 5 | {5,7,9}
+ 6 | {6,8}
+ 7 | {7,9}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+-- ===================================================================
+-- parameterized queries
+-- ===================================================================
+-- simple join
+PREPARE st1(int, int) AS SELECT t1.c3, t2.c3 FROM ft1 t1, ft2 t2 WHERE t1.c1 = $1 AND t2.c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st1(1, 2);
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c3, t2.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.c3, r2.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 2)) AND ((r1."C 1" = 1))))
+(4 rows)
+
+EXECUTE st1(1, 1);
+ c3 | c3
+-------+-------
+ 00001 | 00001
+(1 row)
+
+EXECUTE st1(101, 101);
+ c3 | c3
+-------+-------
+ 00101 | 00101
+(1 row)
+
+-- subquery using stable function (can't be sent to remote)
+PREPARE st2(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c4) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st2(10, 20);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t1.c3 = t2.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Filter: (date(t2.c4) = '01-17-1970'::date)
+ Remote SQL: SELECT c3, c4 FROM "S 1"."T 1" WHERE (("C 1" > 10))
+(15 rows)
+
+EXECUTE st2(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st2(101, 121);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+-- subquery using immutable function (can be sent to remote)
+PREPARE st3(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c5) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st3(10, 20);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t1.c3 = t2.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" > 10)) AND ((date(c5) = '1970-01-17'::date))
+(14 rows)
+
+EXECUTE st3(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st3(20, 30);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- custom plan should be chosen initially
+PREPARE st4(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 = $1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+-- once we try it enough times, should switch to generic plan
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(3 rows)
+
+-- value of $1 should not be sent to remote
+PREPARE st5(user_enum,int) AS SELECT * FROM ft1 t1 WHERE c8 = $1 and c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = $1)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(4 rows)
+
+EXECUTE st5('foo', 1);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- altering FDW options requires replanning
+PREPARE st6 AS SELECT * FROM ft1 t1 WHERE t1.c1 = t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(3 rows)
+
+PREPARE st7 AS INSERT INTO ft1 (c1,c2,c3) VALUES (1001,101,'foo');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 1" RENAME TO "T 0";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 0');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 0" WHERE (("C 1" = c2))
+(3 rows)
+
+EXECUTE st6;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 0"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 0" RENAME TO "T 1";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 1');
+PREPARE st8 AS SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+EXECUTE st8;
+ count
+-------
+ 9
+(1 row)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- cleanup
+DEALLOCATE st1;
+DEALLOCATE st2;
+DEALLOCATE st3;
+DEALLOCATE st4;
+DEALLOCATE st5;
+DEALLOCATE st6;
+DEALLOCATE st7;
+DEALLOCATE st8;
+-- System columns, except ctid and oid, should not be sent to remote
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'pg_class'::regclass LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.tableoid = '1259'::oid)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'ft1'::regclass LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: (tableoid)::regclass, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ tableoid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ ft1 | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((ctid = '(0,2)'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: ctid, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ ctid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ (0,1) | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- ===================================================================
+-- used in PL/pgSQL function
+-- ===================================================================
+CREATE OR REPLACE FUNCTION f_test(p_c1 int) RETURNS int AS $$
+DECLARE
+ v_c1 int;
+BEGIN
+ SELECT c1 INTO v_c1 FROM ft1 WHERE c1 = p_c1 LIMIT 1;
+ PERFORM c1 FROM ft1 WHERE c1 = p_c1 AND p_c1 = v_c1 LIMIT 1;
+ RETURN v_c1;
+END;
+$$ LANGUAGE plpgsql;
+SELECT f_test(100);
+ f_test
+--------
+ 100
+(1 row)
+
+DROP FUNCTION f_test(int);
+-- ===================================================================
+-- REINDEX
+-- ===================================================================
+-- remote table is not created here
+CREATE FOREIGN TABLE reindex_foreign (c1 int, c2 int)
+ SERVER loopback2 OPTIONS (table_name 'reindex_local');
+REINDEX TABLE reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+REINDEX TABLE CONCURRENTLY reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+DROP FOREIGN TABLE reindex_foreign;
+-- partitions and foreign tables
+CREATE TABLE reind_fdw_parent (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE reind_fdw_0_10 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (0) TO (10);
+CREATE FOREIGN TABLE reind_fdw_10_20 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (10) TO (20)
+ SERVER loopback OPTIONS (table_name 'reind_local_10_20');
+REINDEX TABLE reind_fdw_parent; -- ok
+REINDEX TABLE CONCURRENTLY reind_fdw_parent; -- ok
+DROP TABLE reind_fdw_parent;
+-- ===================================================================
+-- conversion error
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int;
+SELECT * FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8) WHERE x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx.x8 FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: whole-row reference to foreign table "ftx"
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: processing expression at position 2 in select list
+ANALYZE ft1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "c8" of foreign table "ft1"
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- local type can be different from remote type in some cases,
+-- in particular if similarly-named operators do equivalent things
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE text;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 = 'foo')) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (('foo' = c8)) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- we declared c8 to be text locally, but it's still the same type on
+-- the remote which will balk if we try to do anything incompatible
+-- with that remote type
+SELECT * FROM ft1 WHERE c8 LIKE 'foo' LIMIT 1; -- ERROR
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+SELECT * FROM ft1 WHERE c8::text LIKE 'foo' LIMIT 1; -- ERROR; cast not pushed down
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- subtransaction
+-- + local/remote error doesn't break cursor
+-- ===================================================================
+BEGIN;
+DECLARE c CURSOR FOR SELECT * FROM ft1 ORDER BY c1;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+SAVEPOINT s;
+ERROR OUT; -- ERROR
+ERROR: syntax error at or near "ERROR"
+LINE 1: ERROR OUT;
+ ^
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+SAVEPOINT s;
+SELECT * FROM ft1 WHERE 1 / (c1 - 1) > 0; -- ERROR
+ERROR: division by zero
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (((1 / ("C 1" - 1)) > 0))
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c1 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+COMMIT;
+-- ===================================================================
+-- test handling of collations
+-- ===================================================================
+create table loct3 (f1 text collate "C" unique, f2 text, f3 varchar(10) unique);
+create foreign table ft3 (f1 text collate "C", f2 text, f3 varchar(10))
+ server loopback options (table_name 'loct3', use_remote_estimate 'true');
+-- can be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "C" = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f2 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f3 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 and l.f1 = 'foo';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE (($1::character varying(10) = f3))
+(8 rows)
+
+-- can't be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "POSIX" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f1)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f1 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 COLLATE "C" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f2)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f2 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 COLLATE "POSIX" and l.f1 = 'foo';
+ QUERY PLAN
+-------------------------------------------------------------
+ Hash Join
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ Inner Unique: true
+ Hash Cond: ((f.f3)::text = (l.f3)::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+ -> Hash
+ Output: l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+(12 rows)
+
+-- ===================================================================
+-- test writable foreign table stuff
+-- ===================================================================
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Subquery Scan on "*SELECT*"
+ Output: "*SELECT*"."?column?", "*SELECT*"."?column?_1", NULL::integer, "*SELECT*"."?column?_2", NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+ -> Foreign Scan on public.ft2 ft2_1
+ Output: (ft2_1.c1 + 1000), (ft2_1.c2 + 100), (ft2_1.c3 || ft2_1.c3)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" LIMIT 20::bigint
+(8 rows)
+
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+INSERT INTO ft2 (c1,c2,c3)
+ VALUES (1101,201,'aaa'), (1102,202,'bbb'), (1103,203,'ccc') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----+----+----+----+------------+----
+ 1101 | 201 | aaa | | | | ft2 |
+ 1102 | 202 | bbb | | | | ft2 |
+ 1103 | 203 | ccc | | | | ft2 |
+(3 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1104,204,'ddd'), (1105,205,'eee');
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 300), c3 = (c3 || '_update3') WHERE ((("C 1" % 10) = 3))
+(3 rows)
+
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 400), c3 = (c3 || '_update7') WHERE ((("C 1" % 10) = 7)) RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+(4 rows)
+
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+----+------------+-----
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 1007 | 507 | 0000700007_update7 | | | | ft2 |
+ 1017 | 507 | 0001700017_update7 | | | | ft2 |
+(102 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9; -- can be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c2 = (r1.c2 + 500), c3 = (r1.c3 || '_update9'), c7 = 'ft2 '::character(10) FROM "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 9))
+(3 rows)
+
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9;
+EXPLAIN (verbose, costs off)
+ DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: c1, c4
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 5)) RETURNING "C 1", c4
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4;
+ c1 | c4
+------+------------------------------
+ 5 | Tue Jan 06 00:00:00 1970 PST
+ 15 | Fri Jan 16 00:00:00 1970 PST
+ 25 | Mon Jan 26 00:00:00 1970 PST
+ 35 | Thu Feb 05 00:00:00 1970 PST
+ 45 | Sun Feb 15 00:00:00 1970 PST
+ 55 | Wed Feb 25 00:00:00 1970 PST
+ 65 | Sat Mar 07 00:00:00 1970 PST
+ 75 | Tue Mar 17 00:00:00 1970 PST
+ 85 | Fri Mar 27 00:00:00 1970 PST
+ 95 | Mon Apr 06 00:00:00 1970 PST
+ 105 | Tue Jan 06 00:00:00 1970 PST
+ 115 | Fri Jan 16 00:00:00 1970 PST
+ 125 | Mon Jan 26 00:00:00 1970 PST
+ 135 | Thu Feb 05 00:00:00 1970 PST
+ 145 | Sun Feb 15 00:00:00 1970 PST
+ 155 | Wed Feb 25 00:00:00 1970 PST
+ 165 | Sat Mar 07 00:00:00 1970 PST
+ 175 | Tue Mar 17 00:00:00 1970 PST
+ 185 | Fri Mar 27 00:00:00 1970 PST
+ 195 | Mon Apr 06 00:00:00 1970 PST
+ 205 | Tue Jan 06 00:00:00 1970 PST
+ 215 | Fri Jan 16 00:00:00 1970 PST
+ 225 | Mon Jan 26 00:00:00 1970 PST
+ 235 | Thu Feb 05 00:00:00 1970 PST
+ 245 | Sun Feb 15 00:00:00 1970 PST
+ 255 | Wed Feb 25 00:00:00 1970 PST
+ 265 | Sat Mar 07 00:00:00 1970 PST
+ 275 | Tue Mar 17 00:00:00 1970 PST
+ 285 | Fri Mar 27 00:00:00 1970 PST
+ 295 | Mon Apr 06 00:00:00 1970 PST
+ 305 | Tue Jan 06 00:00:00 1970 PST
+ 315 | Fri Jan 16 00:00:00 1970 PST
+ 325 | Mon Jan 26 00:00:00 1970 PST
+ 335 | Thu Feb 05 00:00:00 1970 PST
+ 345 | Sun Feb 15 00:00:00 1970 PST
+ 355 | Wed Feb 25 00:00:00 1970 PST
+ 365 | Sat Mar 07 00:00:00 1970 PST
+ 375 | Tue Mar 17 00:00:00 1970 PST
+ 385 | Fri Mar 27 00:00:00 1970 PST
+ 395 | Mon Apr 06 00:00:00 1970 PST
+ 405 | Tue Jan 06 00:00:00 1970 PST
+ 415 | Fri Jan 16 00:00:00 1970 PST
+ 425 | Mon Jan 26 00:00:00 1970 PST
+ 435 | Thu Feb 05 00:00:00 1970 PST
+ 445 | Sun Feb 15 00:00:00 1970 PST
+ 455 | Wed Feb 25 00:00:00 1970 PST
+ 465 | Sat Mar 07 00:00:00 1970 PST
+ 475 | Tue Mar 17 00:00:00 1970 PST
+ 485 | Fri Mar 27 00:00:00 1970 PST
+ 495 | Mon Apr 06 00:00:00 1970 PST
+ 505 | Tue Jan 06 00:00:00 1970 PST
+ 515 | Fri Jan 16 00:00:00 1970 PST
+ 525 | Mon Jan 26 00:00:00 1970 PST
+ 535 | Thu Feb 05 00:00:00 1970 PST
+ 545 | Sun Feb 15 00:00:00 1970 PST
+ 555 | Wed Feb 25 00:00:00 1970 PST
+ 565 | Sat Mar 07 00:00:00 1970 PST
+ 575 | Tue Mar 17 00:00:00 1970 PST
+ 585 | Fri Mar 27 00:00:00 1970 PST
+ 595 | Mon Apr 06 00:00:00 1970 PST
+ 605 | Tue Jan 06 00:00:00 1970 PST
+ 615 | Fri Jan 16 00:00:00 1970 PST
+ 625 | Mon Jan 26 00:00:00 1970 PST
+ 635 | Thu Feb 05 00:00:00 1970 PST
+ 645 | Sun Feb 15 00:00:00 1970 PST
+ 655 | Wed Feb 25 00:00:00 1970 PST
+ 665 | Sat Mar 07 00:00:00 1970 PST
+ 675 | Tue Mar 17 00:00:00 1970 PST
+ 685 | Fri Mar 27 00:00:00 1970 PST
+ 695 | Mon Apr 06 00:00:00 1970 PST
+ 705 | Tue Jan 06 00:00:00 1970 PST
+ 715 | Fri Jan 16 00:00:00 1970 PST
+ 725 | Mon Jan 26 00:00:00 1970 PST
+ 735 | Thu Feb 05 00:00:00 1970 PST
+ 745 | Sun Feb 15 00:00:00 1970 PST
+ 755 | Wed Feb 25 00:00:00 1970 PST
+ 765 | Sat Mar 07 00:00:00 1970 PST
+ 775 | Tue Mar 17 00:00:00 1970 PST
+ 785 | Fri Mar 27 00:00:00 1970 PST
+ 795 | Mon Apr 06 00:00:00 1970 PST
+ 805 | Tue Jan 06 00:00:00 1970 PST
+ 815 | Fri Jan 16 00:00:00 1970 PST
+ 825 | Mon Jan 26 00:00:00 1970 PST
+ 835 | Thu Feb 05 00:00:00 1970 PST
+ 845 | Sun Feb 15 00:00:00 1970 PST
+ 855 | Wed Feb 25 00:00:00 1970 PST
+ 865 | Sat Mar 07 00:00:00 1970 PST
+ 875 | Tue Mar 17 00:00:00 1970 PST
+ 885 | Fri Mar 27 00:00:00 1970 PST
+ 895 | Mon Apr 06 00:00:00 1970 PST
+ 905 | Tue Jan 06 00:00:00 1970 PST
+ 915 | Fri Jan 16 00:00:00 1970 PST
+ 925 | Mon Jan 26 00:00:00 1970 PST
+ 935 | Thu Feb 05 00:00:00 1970 PST
+ 945 | Sun Feb 15 00:00:00 1970 PST
+ 955 | Wed Feb 25 00:00:00 1970 PST
+ 965 | Sat Mar 07 00:00:00 1970 PST
+ 975 | Tue Mar 17 00:00:00 1970 PST
+ 985 | Fri Mar 27 00:00:00 1970 PST
+ 995 | Mon Apr 06 00:00:00 1970 PST
+ 1005 |
+ 1015 |
+ 1105 |
+(103 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 2))
+(3 rows)
+
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2;
+SELECT c1,c2,c3,c4 FROM ft2 ORDER BY c1;
+ c1 | c2 | c3 | c4
+------+-----+--------------------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 3 | 303 | 00003_update3 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+ 11 | 1 | 00011 | Mon Jan 12 00:00:00 1970 PST
+ 13 | 303 | 00013_update3 | Wed Jan 14 00:00:00 1970 PST
+ 14 | 4 | 00014 | Thu Jan 15 00:00:00 1970 PST
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST
+ 18 | 8 | 00018 | Mon Jan 19 00:00:00 1970 PST
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST
+ 20 | 0 | 00020 | Wed Jan 21 00:00:00 1970 PST
+ 21 | 1 | 00021 | Thu Jan 22 00:00:00 1970 PST
+ 23 | 303 | 00023_update3 | Sat Jan 24 00:00:00 1970 PST
+ 24 | 4 | 00024 | Sun Jan 25 00:00:00 1970 PST
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST
+ 28 | 8 | 00028 | Thu Jan 29 00:00:00 1970 PST
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST
+ 30 | 0 | 00030 | Sat Jan 31 00:00:00 1970 PST
+ 31 | 1 | 00031 | Sun Feb 01 00:00:00 1970 PST
+ 33 | 303 | 00033_update3 | Tue Feb 03 00:00:00 1970 PST
+ 34 | 4 | 00034 | Wed Feb 04 00:00:00 1970 PST
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST
+ 38 | 8 | 00038 | Sun Feb 08 00:00:00 1970 PST
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST
+ 40 | 0 | 00040 | Tue Feb 10 00:00:00 1970 PST
+ 41 | 1 | 00041 | Wed Feb 11 00:00:00 1970 PST
+ 43 | 303 | 00043_update3 | Fri Feb 13 00:00:00 1970 PST
+ 44 | 4 | 00044 | Sat Feb 14 00:00:00 1970 PST
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST
+ 48 | 8 | 00048 | Wed Feb 18 00:00:00 1970 PST
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST
+ 50 | 0 | 00050 | Fri Feb 20 00:00:00 1970 PST
+ 51 | 1 | 00051 | Sat Feb 21 00:00:00 1970 PST
+ 53 | 303 | 00053_update3 | Mon Feb 23 00:00:00 1970 PST
+ 54 | 4 | 00054 | Tue Feb 24 00:00:00 1970 PST
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST
+ 58 | 8 | 00058 | Sat Feb 28 00:00:00 1970 PST
+ 59 | 509 | 00059_update9 | Sun Mar 01 00:00:00 1970 PST
+ 60 | 0 | 00060 | Mon Mar 02 00:00:00 1970 PST
+ 61 | 1 | 00061 | Tue Mar 03 00:00:00 1970 PST
+ 63 | 303 | 00063_update3 | Thu Mar 05 00:00:00 1970 PST
+ 64 | 4 | 00064 | Fri Mar 06 00:00:00 1970 PST
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST
+ 68 | 8 | 00068 | Tue Mar 10 00:00:00 1970 PST
+ 69 | 509 | 00069_update9 | Wed Mar 11 00:00:00 1970 PST
+ 70 | 0 | 00070 | Thu Mar 12 00:00:00 1970 PST
+ 71 | 1 | 00071 | Fri Mar 13 00:00:00 1970 PST
+ 73 | 303 | 00073_update3 | Sun Mar 15 00:00:00 1970 PST
+ 74 | 4 | 00074 | Mon Mar 16 00:00:00 1970 PST
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST
+ 78 | 8 | 00078 | Fri Mar 20 00:00:00 1970 PST
+ 79 | 509 | 00079_update9 | Sat Mar 21 00:00:00 1970 PST
+ 80 | 0 | 00080 | Sun Mar 22 00:00:00 1970 PST
+ 81 | 1 | 00081 | Mon Mar 23 00:00:00 1970 PST
+ 83 | 303 | 00083_update3 | Wed Mar 25 00:00:00 1970 PST
+ 84 | 4 | 00084 | Thu Mar 26 00:00:00 1970 PST
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST
+ 88 | 8 | 00088 | Mon Mar 30 00:00:00 1970 PST
+ 89 | 509 | 00089_update9 | Tue Mar 31 00:00:00 1970 PST
+ 90 | 0 | 00090 | Wed Apr 01 00:00:00 1970 PST
+ 91 | 1 | 00091 | Thu Apr 02 00:00:00 1970 PST
+ 93 | 303 | 00093_update3 | Sat Apr 04 00:00:00 1970 PST
+ 94 | 4 | 00094 | Sun Apr 05 00:00:00 1970 PST
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST
+ 98 | 8 | 00098 | Thu Apr 09 00:00:00 1970 PST
+ 99 | 509 | 00099_update9 | Fri Apr 10 00:00:00 1970 PST
+ 100 | 0 | 00100 | Thu Jan 01 00:00:00 1970 PST
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST
+ 103 | 303 | 00103_update3 | Sun Jan 04 00:00:00 1970 PST
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST
+ 109 | 509 | 00109_update9 | Sat Jan 10 00:00:00 1970 PST
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST
+ 111 | 1 | 00111 | Mon Jan 12 00:00:00 1970 PST
+ 113 | 303 | 00113_update3 | Wed Jan 14 00:00:00 1970 PST
+ 114 | 4 | 00114 | Thu Jan 15 00:00:00 1970 PST
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST
+ 118 | 8 | 00118 | Mon Jan 19 00:00:00 1970 PST
+ 119 | 509 | 00119_update9 | Tue Jan 20 00:00:00 1970 PST
+ 120 | 0 | 00120 | Wed Jan 21 00:00:00 1970 PST
+ 121 | 1 | 00121 | Thu Jan 22 00:00:00 1970 PST
+ 123 | 303 | 00123_update3 | Sat Jan 24 00:00:00 1970 PST
+ 124 | 4 | 00124 | Sun Jan 25 00:00:00 1970 PST
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST
+ 128 | 8 | 00128 | Thu Jan 29 00:00:00 1970 PST
+ 129 | 509 | 00129_update9 | Fri Jan 30 00:00:00 1970 PST
+ 130 | 0 | 00130 | Sat Jan 31 00:00:00 1970 PST
+ 131 | 1 | 00131 | Sun Feb 01 00:00:00 1970 PST
+ 133 | 303 | 00133_update3 | Tue Feb 03 00:00:00 1970 PST
+ 134 | 4 | 00134 | Wed Feb 04 00:00:00 1970 PST
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST
+ 138 | 8 | 00138 | Sun Feb 08 00:00:00 1970 PST
+ 139 | 509 | 00139_update9 | Mon Feb 09 00:00:00 1970 PST
+ 140 | 0 | 00140 | Tue Feb 10 00:00:00 1970 PST
+ 141 | 1 | 00141 | Wed Feb 11 00:00:00 1970 PST
+ 143 | 303 | 00143_update3 | Fri Feb 13 00:00:00 1970 PST
+ 144 | 4 | 00144 | Sat Feb 14 00:00:00 1970 PST
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST
+ 148 | 8 | 00148 | Wed Feb 18 00:00:00 1970 PST
+ 149 | 509 | 00149_update9 | Thu Feb 19 00:00:00 1970 PST
+ 150 | 0 | 00150 | Fri Feb 20 00:00:00 1970 PST
+ 151 | 1 | 00151 | Sat Feb 21 00:00:00 1970 PST
+ 153 | 303 | 00153_update3 | Mon Feb 23 00:00:00 1970 PST
+ 154 | 4 | 00154 | Tue Feb 24 00:00:00 1970 PST
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST
+ 158 | 8 | 00158 | Sat Feb 28 00:00:00 1970 PST
+ 159 | 509 | 00159_update9 | Sun Mar 01 00:00:00 1970 PST
+ 160 | 0 | 00160 | Mon Mar 02 00:00:00 1970 PST
+ 161 | 1 | 00161 | Tue Mar 03 00:00:00 1970 PST
+ 163 | 303 | 00163_update3 | Thu Mar 05 00:00:00 1970 PST
+ 164 | 4 | 00164 | Fri Mar 06 00:00:00 1970 PST
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST
+ 168 | 8 | 00168 | Tue Mar 10 00:00:00 1970 PST
+ 169 | 509 | 00169_update9 | Wed Mar 11 00:00:00 1970 PST
+ 170 | 0 | 00170 | Thu Mar 12 00:00:00 1970 PST
+ 171 | 1 | 00171 | Fri Mar 13 00:00:00 1970 PST
+ 173 | 303 | 00173_update3 | Sun Mar 15 00:00:00 1970 PST
+ 174 | 4 | 00174 | Mon Mar 16 00:00:00 1970 PST
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST
+ 178 | 8 | 00178 | Fri Mar 20 00:00:00 1970 PST
+ 179 | 509 | 00179_update9 | Sat Mar 21 00:00:00 1970 PST
+ 180 | 0 | 00180 | Sun Mar 22 00:00:00 1970 PST
+ 181 | 1 | 00181 | Mon Mar 23 00:00:00 1970 PST
+ 183 | 303 | 00183_update3 | Wed Mar 25 00:00:00 1970 PST
+ 184 | 4 | 00184 | Thu Mar 26 00:00:00 1970 PST
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST
+ 188 | 8 | 00188 | Mon Mar 30 00:00:00 1970 PST
+ 189 | 509 | 00189_update9 | Tue Mar 31 00:00:00 1970 PST
+ 190 | 0 | 00190 | Wed Apr 01 00:00:00 1970 PST
+ 191 | 1 | 00191 | Thu Apr 02 00:00:00 1970 PST
+ 193 | 303 | 00193_update3 | Sat Apr 04 00:00:00 1970 PST
+ 194 | 4 | 00194 | Sun Apr 05 00:00:00 1970 PST
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST
+ 198 | 8 | 00198 | Thu Apr 09 00:00:00 1970 PST
+ 199 | 509 | 00199_update9 | Fri Apr 10 00:00:00 1970 PST
+ 200 | 0 | 00200 | Thu Jan 01 00:00:00 1970 PST
+ 201 | 1 | 00201 | Fri Jan 02 00:00:00 1970 PST
+ 203 | 303 | 00203_update3 | Sun Jan 04 00:00:00 1970 PST
+ 204 | 4 | 00204 | Mon Jan 05 00:00:00 1970 PST
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST
+ 208 | 8 | 00208 | Fri Jan 09 00:00:00 1970 PST
+ 209 | 509 | 00209_update9 | Sat Jan 10 00:00:00 1970 PST
+ 210 | 0 | 00210 | Sun Jan 11 00:00:00 1970 PST
+ 211 | 1 | 00211 | Mon Jan 12 00:00:00 1970 PST
+ 213 | 303 | 00213_update3 | Wed Jan 14 00:00:00 1970 PST
+ 214 | 4 | 00214 | Thu Jan 15 00:00:00 1970 PST
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST
+ 218 | 8 | 00218 | Mon Jan 19 00:00:00 1970 PST
+ 219 | 509 | 00219_update9 | Tue Jan 20 00:00:00 1970 PST
+ 220 | 0 | 00220 | Wed Jan 21 00:00:00 1970 PST
+ 221 | 1 | 00221 | Thu Jan 22 00:00:00 1970 PST
+ 223 | 303 | 00223_update3 | Sat Jan 24 00:00:00 1970 PST
+ 224 | 4 | 00224 | Sun Jan 25 00:00:00 1970 PST
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST
+ 228 | 8 | 00228 | Thu Jan 29 00:00:00 1970 PST
+ 229 | 509 | 00229_update9 | Fri Jan 30 00:00:00 1970 PST
+ 230 | 0 | 00230 | Sat Jan 31 00:00:00 1970 PST
+ 231 | 1 | 00231 | Sun Feb 01 00:00:00 1970 PST
+ 233 | 303 | 00233_update3 | Tue Feb 03 00:00:00 1970 PST
+ 234 | 4 | 00234 | Wed Feb 04 00:00:00 1970 PST
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST
+ 238 | 8 | 00238 | Sun Feb 08 00:00:00 1970 PST
+ 239 | 509 | 00239_update9 | Mon Feb 09 00:00:00 1970 PST
+ 240 | 0 | 00240 | Tue Feb 10 00:00:00 1970 PST
+ 241 | 1 | 00241 | Wed Feb 11 00:00:00 1970 PST
+ 243 | 303 | 00243_update3 | Fri Feb 13 00:00:00 1970 PST
+ 244 | 4 | 00244 | Sat Feb 14 00:00:00 1970 PST
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST
+ 248 | 8 | 00248 | Wed Feb 18 00:00:00 1970 PST
+ 249 | 509 | 00249_update9 | Thu Feb 19 00:00:00 1970 PST
+ 250 | 0 | 00250 | Fri Feb 20 00:00:00 1970 PST
+ 251 | 1 | 00251 | Sat Feb 21 00:00:00 1970 PST
+ 253 | 303 | 00253_update3 | Mon Feb 23 00:00:00 1970 PST
+ 254 | 4 | 00254 | Tue Feb 24 00:00:00 1970 PST
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST
+ 258 | 8 | 00258 | Sat Feb 28 00:00:00 1970 PST
+ 259 | 509 | 00259_update9 | Sun Mar 01 00:00:00 1970 PST
+ 260 | 0 | 00260 | Mon Mar 02 00:00:00 1970 PST
+ 261 | 1 | 00261 | Tue Mar 03 00:00:00 1970 PST
+ 263 | 303 | 00263_update3 | Thu Mar 05 00:00:00 1970 PST
+ 264 | 4 | 00264 | Fri Mar 06 00:00:00 1970 PST
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST
+ 268 | 8 | 00268 | Tue Mar 10 00:00:00 1970 PST
+ 269 | 509 | 00269_update9 | Wed Mar 11 00:00:00 1970 PST
+ 270 | 0 | 00270 | Thu Mar 12 00:00:00 1970 PST
+ 271 | 1 | 00271 | Fri Mar 13 00:00:00 1970 PST
+ 273 | 303 | 00273_update3 | Sun Mar 15 00:00:00 1970 PST
+ 274 | 4 | 00274 | Mon Mar 16 00:00:00 1970 PST
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST
+ 278 | 8 | 00278 | Fri Mar 20 00:00:00 1970 PST
+ 279 | 509 | 00279_update9 | Sat Mar 21 00:00:00 1970 PST
+ 280 | 0 | 00280 | Sun Mar 22 00:00:00 1970 PST
+ 281 | 1 | 00281 | Mon Mar 23 00:00:00 1970 PST
+ 283 | 303 | 00283_update3 | Wed Mar 25 00:00:00 1970 PST
+ 284 | 4 | 00284 | Thu Mar 26 00:00:00 1970 PST
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST
+ 288 | 8 | 00288 | Mon Mar 30 00:00:00 1970 PST
+ 289 | 509 | 00289_update9 | Tue Mar 31 00:00:00 1970 PST
+ 290 | 0 | 00290 | Wed Apr 01 00:00:00 1970 PST
+ 291 | 1 | 00291 | Thu Apr 02 00:00:00 1970 PST
+ 293 | 303 | 00293_update3 | Sat Apr 04 00:00:00 1970 PST
+ 294 | 4 | 00294 | Sun Apr 05 00:00:00 1970 PST
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST
+ 298 | 8 | 00298 | Thu Apr 09 00:00:00 1970 PST
+ 299 | 509 | 00299_update9 | Fri Apr 10 00:00:00 1970 PST
+ 300 | 0 | 00300 | Thu Jan 01 00:00:00 1970 PST
+ 301 | 1 | 00301 | Fri Jan 02 00:00:00 1970 PST
+ 303 | 303 | 00303_update3 | Sun Jan 04 00:00:00 1970 PST
+ 304 | 4 | 00304 | Mon Jan 05 00:00:00 1970 PST
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST
+ 308 | 8 | 00308 | Fri Jan 09 00:00:00 1970 PST
+ 309 | 509 | 00309_update9 | Sat Jan 10 00:00:00 1970 PST
+ 310 | 0 | 00310 | Sun Jan 11 00:00:00 1970 PST
+ 311 | 1 | 00311 | Mon Jan 12 00:00:00 1970 PST
+ 313 | 303 | 00313_update3 | Wed Jan 14 00:00:00 1970 PST
+ 314 | 4 | 00314 | Thu Jan 15 00:00:00 1970 PST
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST
+ 318 | 8 | 00318 | Mon Jan 19 00:00:00 1970 PST
+ 319 | 509 | 00319_update9 | Tue Jan 20 00:00:00 1970 PST
+ 320 | 0 | 00320 | Wed Jan 21 00:00:00 1970 PST
+ 321 | 1 | 00321 | Thu Jan 22 00:00:00 1970 PST
+ 323 | 303 | 00323_update3 | Sat Jan 24 00:00:00 1970 PST
+ 324 | 4 | 00324 | Sun Jan 25 00:00:00 1970 PST
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST
+ 328 | 8 | 00328 | Thu Jan 29 00:00:00 1970 PST
+ 329 | 509 | 00329_update9 | Fri Jan 30 00:00:00 1970 PST
+ 330 | 0 | 00330 | Sat Jan 31 00:00:00 1970 PST
+ 331 | 1 | 00331 | Sun Feb 01 00:00:00 1970 PST
+ 333 | 303 | 00333_update3 | Tue Feb 03 00:00:00 1970 PST
+ 334 | 4 | 00334 | Wed Feb 04 00:00:00 1970 PST
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST
+ 338 | 8 | 00338 | Sun Feb 08 00:00:00 1970 PST
+ 339 | 509 | 00339_update9 | Mon Feb 09 00:00:00 1970 PST
+ 340 | 0 | 00340 | Tue Feb 10 00:00:00 1970 PST
+ 341 | 1 | 00341 | Wed Feb 11 00:00:00 1970 PST
+ 343 | 303 | 00343_update3 | Fri Feb 13 00:00:00 1970 PST
+ 344 | 4 | 00344 | Sat Feb 14 00:00:00 1970 PST
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST
+ 348 | 8 | 00348 | Wed Feb 18 00:00:00 1970 PST
+ 349 | 509 | 00349_update9 | Thu Feb 19 00:00:00 1970 PST
+ 350 | 0 | 00350 | Fri Feb 20 00:00:00 1970 PST
+ 351 | 1 | 00351 | Sat Feb 21 00:00:00 1970 PST
+ 353 | 303 | 00353_update3 | Mon Feb 23 00:00:00 1970 PST
+ 354 | 4 | 00354 | Tue Feb 24 00:00:00 1970 PST
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST
+ 358 | 8 | 00358 | Sat Feb 28 00:00:00 1970 PST
+ 359 | 509 | 00359_update9 | Sun Mar 01 00:00:00 1970 PST
+ 360 | 0 | 00360 | Mon Mar 02 00:00:00 1970 PST
+ 361 | 1 | 00361 | Tue Mar 03 00:00:00 1970 PST
+ 363 | 303 | 00363_update3 | Thu Mar 05 00:00:00 1970 PST
+ 364 | 4 | 00364 | Fri Mar 06 00:00:00 1970 PST
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST
+ 368 | 8 | 00368 | Tue Mar 10 00:00:00 1970 PST
+ 369 | 509 | 00369_update9 | Wed Mar 11 00:00:00 1970 PST
+ 370 | 0 | 00370 | Thu Mar 12 00:00:00 1970 PST
+ 371 | 1 | 00371 | Fri Mar 13 00:00:00 1970 PST
+ 373 | 303 | 00373_update3 | Sun Mar 15 00:00:00 1970 PST
+ 374 | 4 | 00374 | Mon Mar 16 00:00:00 1970 PST
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST
+ 378 | 8 | 00378 | Fri Mar 20 00:00:00 1970 PST
+ 379 | 509 | 00379_update9 | Sat Mar 21 00:00:00 1970 PST
+ 380 | 0 | 00380 | Sun Mar 22 00:00:00 1970 PST
+ 381 | 1 | 00381 | Mon Mar 23 00:00:00 1970 PST
+ 383 | 303 | 00383_update3 | Wed Mar 25 00:00:00 1970 PST
+ 384 | 4 | 00384 | Thu Mar 26 00:00:00 1970 PST
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST
+ 388 | 8 | 00388 | Mon Mar 30 00:00:00 1970 PST
+ 389 | 509 | 00389_update9 | Tue Mar 31 00:00:00 1970 PST
+ 390 | 0 | 00390 | Wed Apr 01 00:00:00 1970 PST
+ 391 | 1 | 00391 | Thu Apr 02 00:00:00 1970 PST
+ 393 | 303 | 00393_update3 | Sat Apr 04 00:00:00 1970 PST
+ 394 | 4 | 00394 | Sun Apr 05 00:00:00 1970 PST
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST
+ 398 | 8 | 00398 | Thu Apr 09 00:00:00 1970 PST
+ 399 | 509 | 00399_update9 | Fri Apr 10 00:00:00 1970 PST
+ 400 | 0 | 00400 | Thu Jan 01 00:00:00 1970 PST
+ 401 | 1 | 00401 | Fri Jan 02 00:00:00 1970 PST
+ 403 | 303 | 00403_update3 | Sun Jan 04 00:00:00 1970 PST
+ 404 | 4 | 00404 | Mon Jan 05 00:00:00 1970 PST
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST
+ 408 | 8 | 00408 | Fri Jan 09 00:00:00 1970 PST
+ 409 | 509 | 00409_update9 | Sat Jan 10 00:00:00 1970 PST
+ 410 | 0 | 00410 | Sun Jan 11 00:00:00 1970 PST
+ 411 | 1 | 00411 | Mon Jan 12 00:00:00 1970 PST
+ 413 | 303 | 00413_update3 | Wed Jan 14 00:00:00 1970 PST
+ 414 | 4 | 00414 | Thu Jan 15 00:00:00 1970 PST
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST
+ 418 | 8 | 00418 | Mon Jan 19 00:00:00 1970 PST
+ 419 | 509 | 00419_update9 | Tue Jan 20 00:00:00 1970 PST
+ 420 | 0 | 00420 | Wed Jan 21 00:00:00 1970 PST
+ 421 | 1 | 00421 | Thu Jan 22 00:00:00 1970 PST
+ 423 | 303 | 00423_update3 | Sat Jan 24 00:00:00 1970 PST
+ 424 | 4 | 00424 | Sun Jan 25 00:00:00 1970 PST
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST
+ 428 | 8 | 00428 | Thu Jan 29 00:00:00 1970 PST
+ 429 | 509 | 00429_update9 | Fri Jan 30 00:00:00 1970 PST
+ 430 | 0 | 00430 | Sat Jan 31 00:00:00 1970 PST
+ 431 | 1 | 00431 | Sun Feb 01 00:00:00 1970 PST
+ 433 | 303 | 00433_update3 | Tue Feb 03 00:00:00 1970 PST
+ 434 | 4 | 00434 | Wed Feb 04 00:00:00 1970 PST
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST
+ 438 | 8 | 00438 | Sun Feb 08 00:00:00 1970 PST
+ 439 | 509 | 00439_update9 | Mon Feb 09 00:00:00 1970 PST
+ 440 | 0 | 00440 | Tue Feb 10 00:00:00 1970 PST
+ 441 | 1 | 00441 | Wed Feb 11 00:00:00 1970 PST
+ 443 | 303 | 00443_update3 | Fri Feb 13 00:00:00 1970 PST
+ 444 | 4 | 00444 | Sat Feb 14 00:00:00 1970 PST
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST
+ 448 | 8 | 00448 | Wed Feb 18 00:00:00 1970 PST
+ 449 | 509 | 00449_update9 | Thu Feb 19 00:00:00 1970 PST
+ 450 | 0 | 00450 | Fri Feb 20 00:00:00 1970 PST
+ 451 | 1 | 00451 | Sat Feb 21 00:00:00 1970 PST
+ 453 | 303 | 00453_update3 | Mon Feb 23 00:00:00 1970 PST
+ 454 | 4 | 00454 | Tue Feb 24 00:00:00 1970 PST
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST
+ 458 | 8 | 00458 | Sat Feb 28 00:00:00 1970 PST
+ 459 | 509 | 00459_update9 | Sun Mar 01 00:00:00 1970 PST
+ 460 | 0 | 00460 | Mon Mar 02 00:00:00 1970 PST
+ 461 | 1 | 00461 | Tue Mar 03 00:00:00 1970 PST
+ 463 | 303 | 00463_update3 | Thu Mar 05 00:00:00 1970 PST
+ 464 | 4 | 00464 | Fri Mar 06 00:00:00 1970 PST
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST
+ 468 | 8 | 00468 | Tue Mar 10 00:00:00 1970 PST
+ 469 | 509 | 00469_update9 | Wed Mar 11 00:00:00 1970 PST
+ 470 | 0 | 00470 | Thu Mar 12 00:00:00 1970 PST
+ 471 | 1 | 00471 | Fri Mar 13 00:00:00 1970 PST
+ 473 | 303 | 00473_update3 | Sun Mar 15 00:00:00 1970 PST
+ 474 | 4 | 00474 | Mon Mar 16 00:00:00 1970 PST
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST
+ 478 | 8 | 00478 | Fri Mar 20 00:00:00 1970 PST
+ 479 | 509 | 00479_update9 | Sat Mar 21 00:00:00 1970 PST
+ 480 | 0 | 00480 | Sun Mar 22 00:00:00 1970 PST
+ 481 | 1 | 00481 | Mon Mar 23 00:00:00 1970 PST
+ 483 | 303 | 00483_update3 | Wed Mar 25 00:00:00 1970 PST
+ 484 | 4 | 00484 | Thu Mar 26 00:00:00 1970 PST
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST
+ 488 | 8 | 00488 | Mon Mar 30 00:00:00 1970 PST
+ 489 | 509 | 00489_update9 | Tue Mar 31 00:00:00 1970 PST
+ 490 | 0 | 00490 | Wed Apr 01 00:00:00 1970 PST
+ 491 | 1 | 00491 | Thu Apr 02 00:00:00 1970 PST
+ 493 | 303 | 00493_update3 | Sat Apr 04 00:00:00 1970 PST
+ 494 | 4 | 00494 | Sun Apr 05 00:00:00 1970 PST
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST
+ 498 | 8 | 00498 | Thu Apr 09 00:00:00 1970 PST
+ 499 | 509 | 00499_update9 | Fri Apr 10 00:00:00 1970 PST
+ 500 | 0 | 00500 | Thu Jan 01 00:00:00 1970 PST
+ 501 | 1 | 00501 | Fri Jan 02 00:00:00 1970 PST
+ 503 | 303 | 00503_update3 | Sun Jan 04 00:00:00 1970 PST
+ 504 | 4 | 00504 | Mon Jan 05 00:00:00 1970 PST
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST
+ 508 | 8 | 00508 | Fri Jan 09 00:00:00 1970 PST
+ 509 | 509 | 00509_update9 | Sat Jan 10 00:00:00 1970 PST
+ 510 | 0 | 00510 | Sun Jan 11 00:00:00 1970 PST
+ 511 | 1 | 00511 | Mon Jan 12 00:00:00 1970 PST
+ 513 | 303 | 00513_update3 | Wed Jan 14 00:00:00 1970 PST
+ 514 | 4 | 00514 | Thu Jan 15 00:00:00 1970 PST
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST
+ 518 | 8 | 00518 | Mon Jan 19 00:00:00 1970 PST
+ 519 | 509 | 00519_update9 | Tue Jan 20 00:00:00 1970 PST
+ 520 | 0 | 00520 | Wed Jan 21 00:00:00 1970 PST
+ 521 | 1 | 00521 | Thu Jan 22 00:00:00 1970 PST
+ 523 | 303 | 00523_update3 | Sat Jan 24 00:00:00 1970 PST
+ 524 | 4 | 00524 | Sun Jan 25 00:00:00 1970 PST
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST
+ 528 | 8 | 00528 | Thu Jan 29 00:00:00 1970 PST
+ 529 | 509 | 00529_update9 | Fri Jan 30 00:00:00 1970 PST
+ 530 | 0 | 00530 | Sat Jan 31 00:00:00 1970 PST
+ 531 | 1 | 00531 | Sun Feb 01 00:00:00 1970 PST
+ 533 | 303 | 00533_update3 | Tue Feb 03 00:00:00 1970 PST
+ 534 | 4 | 00534 | Wed Feb 04 00:00:00 1970 PST
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST
+ 538 | 8 | 00538 | Sun Feb 08 00:00:00 1970 PST
+ 539 | 509 | 00539_update9 | Mon Feb 09 00:00:00 1970 PST
+ 540 | 0 | 00540 | Tue Feb 10 00:00:00 1970 PST
+ 541 | 1 | 00541 | Wed Feb 11 00:00:00 1970 PST
+ 543 | 303 | 00543_update3 | Fri Feb 13 00:00:00 1970 PST
+ 544 | 4 | 00544 | Sat Feb 14 00:00:00 1970 PST
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST
+ 548 | 8 | 00548 | Wed Feb 18 00:00:00 1970 PST
+ 549 | 509 | 00549_update9 | Thu Feb 19 00:00:00 1970 PST
+ 550 | 0 | 00550 | Fri Feb 20 00:00:00 1970 PST
+ 551 | 1 | 00551 | Sat Feb 21 00:00:00 1970 PST
+ 553 | 303 | 00553_update3 | Mon Feb 23 00:00:00 1970 PST
+ 554 | 4 | 00554 | Tue Feb 24 00:00:00 1970 PST
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST
+ 558 | 8 | 00558 | Sat Feb 28 00:00:00 1970 PST
+ 559 | 509 | 00559_update9 | Sun Mar 01 00:00:00 1970 PST
+ 560 | 0 | 00560 | Mon Mar 02 00:00:00 1970 PST
+ 561 | 1 | 00561 | Tue Mar 03 00:00:00 1970 PST
+ 563 | 303 | 00563_update3 | Thu Mar 05 00:00:00 1970 PST
+ 564 | 4 | 00564 | Fri Mar 06 00:00:00 1970 PST
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST
+ 568 | 8 | 00568 | Tue Mar 10 00:00:00 1970 PST
+ 569 | 509 | 00569_update9 | Wed Mar 11 00:00:00 1970 PST
+ 570 | 0 | 00570 | Thu Mar 12 00:00:00 1970 PST
+ 571 | 1 | 00571 | Fri Mar 13 00:00:00 1970 PST
+ 573 | 303 | 00573_update3 | Sun Mar 15 00:00:00 1970 PST
+ 574 | 4 | 00574 | Mon Mar 16 00:00:00 1970 PST
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST
+ 578 | 8 | 00578 | Fri Mar 20 00:00:00 1970 PST
+ 579 | 509 | 00579_update9 | Sat Mar 21 00:00:00 1970 PST
+ 580 | 0 | 00580 | Sun Mar 22 00:00:00 1970 PST
+ 581 | 1 | 00581 | Mon Mar 23 00:00:00 1970 PST
+ 583 | 303 | 00583_update3 | Wed Mar 25 00:00:00 1970 PST
+ 584 | 4 | 00584 | Thu Mar 26 00:00:00 1970 PST
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST
+ 588 | 8 | 00588 | Mon Mar 30 00:00:00 1970 PST
+ 589 | 509 | 00589_update9 | Tue Mar 31 00:00:00 1970 PST
+ 590 | 0 | 00590 | Wed Apr 01 00:00:00 1970 PST
+ 591 | 1 | 00591 | Thu Apr 02 00:00:00 1970 PST
+ 593 | 303 | 00593_update3 | Sat Apr 04 00:00:00 1970 PST
+ 594 | 4 | 00594 | Sun Apr 05 00:00:00 1970 PST
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST
+ 598 | 8 | 00598 | Thu Apr 09 00:00:00 1970 PST
+ 599 | 509 | 00599_update9 | Fri Apr 10 00:00:00 1970 PST
+ 600 | 0 | 00600 | Thu Jan 01 00:00:00 1970 PST
+ 601 | 1 | 00601 | Fri Jan 02 00:00:00 1970 PST
+ 603 | 303 | 00603_update3 | Sun Jan 04 00:00:00 1970 PST
+ 604 | 4 | 00604 | Mon Jan 05 00:00:00 1970 PST
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST
+ 608 | 8 | 00608 | Fri Jan 09 00:00:00 1970 PST
+ 609 | 509 | 00609_update9 | Sat Jan 10 00:00:00 1970 PST
+ 610 | 0 | 00610 | Sun Jan 11 00:00:00 1970 PST
+ 611 | 1 | 00611 | Mon Jan 12 00:00:00 1970 PST
+ 613 | 303 | 00613_update3 | Wed Jan 14 00:00:00 1970 PST
+ 614 | 4 | 00614 | Thu Jan 15 00:00:00 1970 PST
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST
+ 618 | 8 | 00618 | Mon Jan 19 00:00:00 1970 PST
+ 619 | 509 | 00619_update9 | Tue Jan 20 00:00:00 1970 PST
+ 620 | 0 | 00620 | Wed Jan 21 00:00:00 1970 PST
+ 621 | 1 | 00621 | Thu Jan 22 00:00:00 1970 PST
+ 623 | 303 | 00623_update3 | Sat Jan 24 00:00:00 1970 PST
+ 624 | 4 | 00624 | Sun Jan 25 00:00:00 1970 PST
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST
+ 628 | 8 | 00628 | Thu Jan 29 00:00:00 1970 PST
+ 629 | 509 | 00629_update9 | Fri Jan 30 00:00:00 1970 PST
+ 630 | 0 | 00630 | Sat Jan 31 00:00:00 1970 PST
+ 631 | 1 | 00631 | Sun Feb 01 00:00:00 1970 PST
+ 633 | 303 | 00633_update3 | Tue Feb 03 00:00:00 1970 PST
+ 634 | 4 | 00634 | Wed Feb 04 00:00:00 1970 PST
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST
+ 638 | 8 | 00638 | Sun Feb 08 00:00:00 1970 PST
+ 639 | 509 | 00639_update9 | Mon Feb 09 00:00:00 1970 PST
+ 640 | 0 | 00640 | Tue Feb 10 00:00:00 1970 PST
+ 641 | 1 | 00641 | Wed Feb 11 00:00:00 1970 PST
+ 643 | 303 | 00643_update3 | Fri Feb 13 00:00:00 1970 PST
+ 644 | 4 | 00644 | Sat Feb 14 00:00:00 1970 PST
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST
+ 648 | 8 | 00648 | Wed Feb 18 00:00:00 1970 PST
+ 649 | 509 | 00649_update9 | Thu Feb 19 00:00:00 1970 PST
+ 650 | 0 | 00650 | Fri Feb 20 00:00:00 1970 PST
+ 651 | 1 | 00651 | Sat Feb 21 00:00:00 1970 PST
+ 653 | 303 | 00653_update3 | Mon Feb 23 00:00:00 1970 PST
+ 654 | 4 | 00654 | Tue Feb 24 00:00:00 1970 PST
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST
+ 658 | 8 | 00658 | Sat Feb 28 00:00:00 1970 PST
+ 659 | 509 | 00659_update9 | Sun Mar 01 00:00:00 1970 PST
+ 660 | 0 | 00660 | Mon Mar 02 00:00:00 1970 PST
+ 661 | 1 | 00661 | Tue Mar 03 00:00:00 1970 PST
+ 663 | 303 | 00663_update3 | Thu Mar 05 00:00:00 1970 PST
+ 664 | 4 | 00664 | Fri Mar 06 00:00:00 1970 PST
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST
+ 668 | 8 | 00668 | Tue Mar 10 00:00:00 1970 PST
+ 669 | 509 | 00669_update9 | Wed Mar 11 00:00:00 1970 PST
+ 670 | 0 | 00670 | Thu Mar 12 00:00:00 1970 PST
+ 671 | 1 | 00671 | Fri Mar 13 00:00:00 1970 PST
+ 673 | 303 | 00673_update3 | Sun Mar 15 00:00:00 1970 PST
+ 674 | 4 | 00674 | Mon Mar 16 00:00:00 1970 PST
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST
+ 678 | 8 | 00678 | Fri Mar 20 00:00:00 1970 PST
+ 679 | 509 | 00679_update9 | Sat Mar 21 00:00:00 1970 PST
+ 680 | 0 | 00680 | Sun Mar 22 00:00:00 1970 PST
+ 681 | 1 | 00681 | Mon Mar 23 00:00:00 1970 PST
+ 683 | 303 | 00683_update3 | Wed Mar 25 00:00:00 1970 PST
+ 684 | 4 | 00684 | Thu Mar 26 00:00:00 1970 PST
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST
+ 688 | 8 | 00688 | Mon Mar 30 00:00:00 1970 PST
+ 689 | 509 | 00689_update9 | Tue Mar 31 00:00:00 1970 PST
+ 690 | 0 | 00690 | Wed Apr 01 00:00:00 1970 PST
+ 691 | 1 | 00691 | Thu Apr 02 00:00:00 1970 PST
+ 693 | 303 | 00693_update3 | Sat Apr 04 00:00:00 1970 PST
+ 694 | 4 | 00694 | Sun Apr 05 00:00:00 1970 PST
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST
+ 698 | 8 | 00698 | Thu Apr 09 00:00:00 1970 PST
+ 699 | 509 | 00699_update9 | Fri Apr 10 00:00:00 1970 PST
+ 700 | 0 | 00700 | Thu Jan 01 00:00:00 1970 PST
+ 701 | 1 | 00701 | Fri Jan 02 00:00:00 1970 PST
+ 703 | 303 | 00703_update3 | Sun Jan 04 00:00:00 1970 PST
+ 704 | 4 | 00704 | Mon Jan 05 00:00:00 1970 PST
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST
+ 708 | 8 | 00708 | Fri Jan 09 00:00:00 1970 PST
+ 709 | 509 | 00709_update9 | Sat Jan 10 00:00:00 1970 PST
+ 710 | 0 | 00710 | Sun Jan 11 00:00:00 1970 PST
+ 711 | 1 | 00711 | Mon Jan 12 00:00:00 1970 PST
+ 713 | 303 | 00713_update3 | Wed Jan 14 00:00:00 1970 PST
+ 714 | 4 | 00714 | Thu Jan 15 00:00:00 1970 PST
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST
+ 718 | 8 | 00718 | Mon Jan 19 00:00:00 1970 PST
+ 719 | 509 | 00719_update9 | Tue Jan 20 00:00:00 1970 PST
+ 720 | 0 | 00720 | Wed Jan 21 00:00:00 1970 PST
+ 721 | 1 | 00721 | Thu Jan 22 00:00:00 1970 PST
+ 723 | 303 | 00723_update3 | Sat Jan 24 00:00:00 1970 PST
+ 724 | 4 | 00724 | Sun Jan 25 00:00:00 1970 PST
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST
+ 728 | 8 | 00728 | Thu Jan 29 00:00:00 1970 PST
+ 729 | 509 | 00729_update9 | Fri Jan 30 00:00:00 1970 PST
+ 730 | 0 | 00730 | Sat Jan 31 00:00:00 1970 PST
+ 731 | 1 | 00731 | Sun Feb 01 00:00:00 1970 PST
+ 733 | 303 | 00733_update3 | Tue Feb 03 00:00:00 1970 PST
+ 734 | 4 | 00734 | Wed Feb 04 00:00:00 1970 PST
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST
+ 738 | 8 | 00738 | Sun Feb 08 00:00:00 1970 PST
+ 739 | 509 | 00739_update9 | Mon Feb 09 00:00:00 1970 PST
+ 740 | 0 | 00740 | Tue Feb 10 00:00:00 1970 PST
+ 741 | 1 | 00741 | Wed Feb 11 00:00:00 1970 PST
+ 743 | 303 | 00743_update3 | Fri Feb 13 00:00:00 1970 PST
+ 744 | 4 | 00744 | Sat Feb 14 00:00:00 1970 PST
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST
+ 748 | 8 | 00748 | Wed Feb 18 00:00:00 1970 PST
+ 749 | 509 | 00749_update9 | Thu Feb 19 00:00:00 1970 PST
+ 750 | 0 | 00750 | Fri Feb 20 00:00:00 1970 PST
+ 751 | 1 | 00751 | Sat Feb 21 00:00:00 1970 PST
+ 753 | 303 | 00753_update3 | Mon Feb 23 00:00:00 1970 PST
+ 754 | 4 | 00754 | Tue Feb 24 00:00:00 1970 PST
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST
+ 758 | 8 | 00758 | Sat Feb 28 00:00:00 1970 PST
+ 759 | 509 | 00759_update9 | Sun Mar 01 00:00:00 1970 PST
+ 760 | 0 | 00760 | Mon Mar 02 00:00:00 1970 PST
+ 761 | 1 | 00761 | Tue Mar 03 00:00:00 1970 PST
+ 763 | 303 | 00763_update3 | Thu Mar 05 00:00:00 1970 PST
+ 764 | 4 | 00764 | Fri Mar 06 00:00:00 1970 PST
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST
+ 768 | 8 | 00768 | Tue Mar 10 00:00:00 1970 PST
+ 769 | 509 | 00769_update9 | Wed Mar 11 00:00:00 1970 PST
+ 770 | 0 | 00770 | Thu Mar 12 00:00:00 1970 PST
+ 771 | 1 | 00771 | Fri Mar 13 00:00:00 1970 PST
+ 773 | 303 | 00773_update3 | Sun Mar 15 00:00:00 1970 PST
+ 774 | 4 | 00774 | Mon Mar 16 00:00:00 1970 PST
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST
+ 778 | 8 | 00778 | Fri Mar 20 00:00:00 1970 PST
+ 779 | 509 | 00779_update9 | Sat Mar 21 00:00:00 1970 PST
+ 780 | 0 | 00780 | Sun Mar 22 00:00:00 1970 PST
+ 781 | 1 | 00781 | Mon Mar 23 00:00:00 1970 PST
+ 783 | 303 | 00783_update3 | Wed Mar 25 00:00:00 1970 PST
+ 784 | 4 | 00784 | Thu Mar 26 00:00:00 1970 PST
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST
+ 788 | 8 | 00788 | Mon Mar 30 00:00:00 1970 PST
+ 789 | 509 | 00789_update9 | Tue Mar 31 00:00:00 1970 PST
+ 790 | 0 | 00790 | Wed Apr 01 00:00:00 1970 PST
+ 791 | 1 | 00791 | Thu Apr 02 00:00:00 1970 PST
+ 793 | 303 | 00793_update3 | Sat Apr 04 00:00:00 1970 PST
+ 794 | 4 | 00794 | Sun Apr 05 00:00:00 1970 PST
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST
+ 798 | 8 | 00798 | Thu Apr 09 00:00:00 1970 PST
+ 799 | 509 | 00799_update9 | Fri Apr 10 00:00:00 1970 PST
+ 800 | 0 | 00800 | Thu Jan 01 00:00:00 1970 PST
+ 801 | 1 | 00801 | Fri Jan 02 00:00:00 1970 PST
+ 803 | 303 | 00803_update3 | Sun Jan 04 00:00:00 1970 PST
+ 804 | 4 | 00804 | Mon Jan 05 00:00:00 1970 PST
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST
+ 808 | 8 | 00808 | Fri Jan 09 00:00:00 1970 PST
+ 809 | 509 | 00809_update9 | Sat Jan 10 00:00:00 1970 PST
+ 810 | 0 | 00810 | Sun Jan 11 00:00:00 1970 PST
+ 811 | 1 | 00811 | Mon Jan 12 00:00:00 1970 PST
+ 813 | 303 | 00813_update3 | Wed Jan 14 00:00:00 1970 PST
+ 814 | 4 | 00814 | Thu Jan 15 00:00:00 1970 PST
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST
+ 818 | 8 | 00818 | Mon Jan 19 00:00:00 1970 PST
+ 819 | 509 | 00819_update9 | Tue Jan 20 00:00:00 1970 PST
+ 820 | 0 | 00820 | Wed Jan 21 00:00:00 1970 PST
+ 821 | 1 | 00821 | Thu Jan 22 00:00:00 1970 PST
+ 823 | 303 | 00823_update3 | Sat Jan 24 00:00:00 1970 PST
+ 824 | 4 | 00824 | Sun Jan 25 00:00:00 1970 PST
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST
+ 828 | 8 | 00828 | Thu Jan 29 00:00:00 1970 PST
+ 829 | 509 | 00829_update9 | Fri Jan 30 00:00:00 1970 PST
+ 830 | 0 | 00830 | Sat Jan 31 00:00:00 1970 PST
+ 831 | 1 | 00831 | Sun Feb 01 00:00:00 1970 PST
+ 833 | 303 | 00833_update3 | Tue Feb 03 00:00:00 1970 PST
+ 834 | 4 | 00834 | Wed Feb 04 00:00:00 1970 PST
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST
+ 838 | 8 | 00838 | Sun Feb 08 00:00:00 1970 PST
+ 839 | 509 | 00839_update9 | Mon Feb 09 00:00:00 1970 PST
+ 840 | 0 | 00840 | Tue Feb 10 00:00:00 1970 PST
+ 841 | 1 | 00841 | Wed Feb 11 00:00:00 1970 PST
+ 843 | 303 | 00843_update3 | Fri Feb 13 00:00:00 1970 PST
+ 844 | 4 | 00844 | Sat Feb 14 00:00:00 1970 PST
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST
+ 848 | 8 | 00848 | Wed Feb 18 00:00:00 1970 PST
+ 849 | 509 | 00849_update9 | Thu Feb 19 00:00:00 1970 PST
+ 850 | 0 | 00850 | Fri Feb 20 00:00:00 1970 PST
+ 851 | 1 | 00851 | Sat Feb 21 00:00:00 1970 PST
+ 853 | 303 | 00853_update3 | Mon Feb 23 00:00:00 1970 PST
+ 854 | 4 | 00854 | Tue Feb 24 00:00:00 1970 PST
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST
+ 858 | 8 | 00858 | Sat Feb 28 00:00:00 1970 PST
+ 859 | 509 | 00859_update9 | Sun Mar 01 00:00:00 1970 PST
+ 860 | 0 | 00860 | Mon Mar 02 00:00:00 1970 PST
+ 861 | 1 | 00861 | Tue Mar 03 00:00:00 1970 PST
+ 863 | 303 | 00863_update3 | Thu Mar 05 00:00:00 1970 PST
+ 864 | 4 | 00864 | Fri Mar 06 00:00:00 1970 PST
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST
+ 868 | 8 | 00868 | Tue Mar 10 00:00:00 1970 PST
+ 869 | 509 | 00869_update9 | Wed Mar 11 00:00:00 1970 PST
+ 870 | 0 | 00870 | Thu Mar 12 00:00:00 1970 PST
+ 871 | 1 | 00871 | Fri Mar 13 00:00:00 1970 PST
+ 873 | 303 | 00873_update3 | Sun Mar 15 00:00:00 1970 PST
+ 874 | 4 | 00874 | Mon Mar 16 00:00:00 1970 PST
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST
+ 878 | 8 | 00878 | Fri Mar 20 00:00:00 1970 PST
+ 879 | 509 | 00879_update9 | Sat Mar 21 00:00:00 1970 PST
+ 880 | 0 | 00880 | Sun Mar 22 00:00:00 1970 PST
+ 881 | 1 | 00881 | Mon Mar 23 00:00:00 1970 PST
+ 883 | 303 | 00883_update3 | Wed Mar 25 00:00:00 1970 PST
+ 884 | 4 | 00884 | Thu Mar 26 00:00:00 1970 PST
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST
+ 888 | 8 | 00888 | Mon Mar 30 00:00:00 1970 PST
+ 889 | 509 | 00889_update9 | Tue Mar 31 00:00:00 1970 PST
+ 890 | 0 | 00890 | Wed Apr 01 00:00:00 1970 PST
+ 891 | 1 | 00891 | Thu Apr 02 00:00:00 1970 PST
+ 893 | 303 | 00893_update3 | Sat Apr 04 00:00:00 1970 PST
+ 894 | 4 | 00894 | Sun Apr 05 00:00:00 1970 PST
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST
+ 898 | 8 | 00898 | Thu Apr 09 00:00:00 1970 PST
+ 899 | 509 | 00899_update9 | Fri Apr 10 00:00:00 1970 PST
+ 900 | 0 | 00900 | Thu Jan 01 00:00:00 1970 PST
+ 901 | 1 | 00901 | Fri Jan 02 00:00:00 1970 PST
+ 903 | 303 | 00903_update3 | Sun Jan 04 00:00:00 1970 PST
+ 904 | 4 | 00904 | Mon Jan 05 00:00:00 1970 PST
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST
+ 908 | 8 | 00908 | Fri Jan 09 00:00:00 1970 PST
+ 909 | 509 | 00909_update9 | Sat Jan 10 00:00:00 1970 PST
+ 910 | 0 | 00910 | Sun Jan 11 00:00:00 1970 PST
+ 911 | 1 | 00911 | Mon Jan 12 00:00:00 1970 PST
+ 913 | 303 | 00913_update3 | Wed Jan 14 00:00:00 1970 PST
+ 914 | 4 | 00914 | Thu Jan 15 00:00:00 1970 PST
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST
+ 918 | 8 | 00918 | Mon Jan 19 00:00:00 1970 PST
+ 919 | 509 | 00919_update9 | Tue Jan 20 00:00:00 1970 PST
+ 920 | 0 | 00920 | Wed Jan 21 00:00:00 1970 PST
+ 921 | 1 | 00921 | Thu Jan 22 00:00:00 1970 PST
+ 923 | 303 | 00923_update3 | Sat Jan 24 00:00:00 1970 PST
+ 924 | 4 | 00924 | Sun Jan 25 00:00:00 1970 PST
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST
+ 928 | 8 | 00928 | Thu Jan 29 00:00:00 1970 PST
+ 929 | 509 | 00929_update9 | Fri Jan 30 00:00:00 1970 PST
+ 930 | 0 | 00930 | Sat Jan 31 00:00:00 1970 PST
+ 931 | 1 | 00931 | Sun Feb 01 00:00:00 1970 PST
+ 933 | 303 | 00933_update3 | Tue Feb 03 00:00:00 1970 PST
+ 934 | 4 | 00934 | Wed Feb 04 00:00:00 1970 PST
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST
+ 938 | 8 | 00938 | Sun Feb 08 00:00:00 1970 PST
+ 939 | 509 | 00939_update9 | Mon Feb 09 00:00:00 1970 PST
+ 940 | 0 | 00940 | Tue Feb 10 00:00:00 1970 PST
+ 941 | 1 | 00941 | Wed Feb 11 00:00:00 1970 PST
+ 943 | 303 | 00943_update3 | Fri Feb 13 00:00:00 1970 PST
+ 944 | 4 | 00944 | Sat Feb 14 00:00:00 1970 PST
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST
+ 948 | 8 | 00948 | Wed Feb 18 00:00:00 1970 PST
+ 949 | 509 | 00949_update9 | Thu Feb 19 00:00:00 1970 PST
+ 950 | 0 | 00950 | Fri Feb 20 00:00:00 1970 PST
+ 951 | 1 | 00951 | Sat Feb 21 00:00:00 1970 PST
+ 953 | 303 | 00953_update3 | Mon Feb 23 00:00:00 1970 PST
+ 954 | 4 | 00954 | Tue Feb 24 00:00:00 1970 PST
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST
+ 958 | 8 | 00958 | Sat Feb 28 00:00:00 1970 PST
+ 959 | 509 | 00959_update9 | Sun Mar 01 00:00:00 1970 PST
+ 960 | 0 | 00960 | Mon Mar 02 00:00:00 1970 PST
+ 961 | 1 | 00961 | Tue Mar 03 00:00:00 1970 PST
+ 963 | 303 | 00963_update3 | Thu Mar 05 00:00:00 1970 PST
+ 964 | 4 | 00964 | Fri Mar 06 00:00:00 1970 PST
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST
+ 968 | 8 | 00968 | Tue Mar 10 00:00:00 1970 PST
+ 969 | 509 | 00969_update9 | Wed Mar 11 00:00:00 1970 PST
+ 970 | 0 | 00970 | Thu Mar 12 00:00:00 1970 PST
+ 971 | 1 | 00971 | Fri Mar 13 00:00:00 1970 PST
+ 973 | 303 | 00973_update3 | Sun Mar 15 00:00:00 1970 PST
+ 974 | 4 | 00974 | Mon Mar 16 00:00:00 1970 PST
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST
+ 978 | 8 | 00978 | Fri Mar 20 00:00:00 1970 PST
+ 979 | 509 | 00979_update9 | Sat Mar 21 00:00:00 1970 PST
+ 980 | 0 | 00980 | Sun Mar 22 00:00:00 1970 PST
+ 981 | 1 | 00981 | Mon Mar 23 00:00:00 1970 PST
+ 983 | 303 | 00983_update3 | Wed Mar 25 00:00:00 1970 PST
+ 984 | 4 | 00984 | Thu Mar 26 00:00:00 1970 PST
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST
+ 988 | 8 | 00988 | Mon Mar 30 00:00:00 1970 PST
+ 989 | 509 | 00989_update9 | Tue Mar 31 00:00:00 1970 PST
+ 990 | 0 | 00990 | Wed Apr 01 00:00:00 1970 PST
+ 991 | 1 | 00991 | Thu Apr 02 00:00:00 1970 PST
+ 993 | 303 | 00993_update3 | Sat Apr 04 00:00:00 1970 PST
+ 994 | 4 | 00994 | Sun Apr 05 00:00:00 1970 PST
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST
+ 998 | 8 | 00998 | Thu Apr 09 00:00:00 1970 PST
+ 999 | 509 | 00999_update9 | Fri Apr 10 00:00:00 1970 PST
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST
+ 1001 | 101 | 0000100001 |
+ 1003 | 403 | 0000300003_update3 |
+ 1004 | 104 | 0000400004 |
+ 1006 | 106 | 0000600006 |
+ 1007 | 507 | 0000700007_update7 |
+ 1008 | 108 | 0000800008 |
+ 1009 | 609 | 0000900009_update9 |
+ 1010 | 100 | 0001000010 |
+ 1011 | 101 | 0001100011 |
+ 1013 | 403 | 0001300013_update3 |
+ 1014 | 104 | 0001400014 |
+ 1016 | 106 | 0001600016 |
+ 1017 | 507 | 0001700017_update7 |
+ 1018 | 108 | 0001800018 |
+ 1019 | 609 | 0001900019_update9 |
+ 1020 | 100 | 0002000020 |
+ 1101 | 201 | aaa |
+ 1103 | 503 | ccc_update3 |
+ 1104 | 204 | ddd |
+(819 rows)
+
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Output: (ft2.tableoid)::regclass
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: 1200, 999, NULL::integer, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+(6 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = 'bar'::text WHERE (("C 1" = 1200))
+(4 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------
+ Delete on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE (("C 1" = 1200))
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+-- Test UPDATE/DELETE with RETURNING on a three-table join
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id - 1200, to_char(id, 'FM00000') FROM generate_series(1201, 1300) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.*, ft4.c1, ft4.c2, ft4.c3
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c3 = 'foo'::text FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (TRUE)) WHERE ((r2.c1 = r3.c1)) AND ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) RETURNING r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3
+(4 rows)
+
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*;
+ ft2 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | ft4 | c1 | c2 | c3
+--------------------------------+------+----+-----+----+----+----+------------+----+----------------+----+----+--------
+ (1206,6,foo,,,,"ft2 ",) | 1206 | 6 | foo | | | | ft2 | | (6,7,AAA006) | 6 | 7 | AAA006
+ (1212,12,foo,,,,"ft2 ",) | 1212 | 12 | foo | | | | ft2 | | (12,13,AAA012) | 12 | 13 | AAA012
+ (1218,18,foo,,,,"ft2 ",) | 1218 | 18 | foo | | | | ft2 | | (18,19,AAA018) | 18 | 19 | AAA018
+ (1224,24,foo,,,,"ft2 ",) | 1224 | 24 | foo | | | | ft2 | | (24,25,AAA024) | 24 | 25 | AAA024
+ (1230,30,foo,,,,"ft2 ",) | 1230 | 30 | foo | | | | ft2 | | (30,31,AAA030) | 30 | 31 | AAA030
+ (1236,36,foo,,,,"ft2 ",) | 1236 | 36 | foo | | | | ft2 | | (36,37,AAA036) | 36 | 37 | AAA036
+ (1242,42,foo,,,,"ft2 ",) | 1242 | 42 | foo | | | | ft2 | | (42,43,AAA042) | 42 | 43 | AAA042
+ (1248,48,foo,,,,"ft2 ",) | 1248 | 48 | foo | | | | ft2 | | (48,49,AAA048) | 48 | 49 | AAA048
+ (1254,54,foo,,,,"ft2 ",) | 1254 | 54 | foo | | | | ft2 | | (54,55,AAA054) | 54 | 55 | AAA054
+ (1260,60,foo,,,,"ft2 ",) | 1260 | 60 | foo | | | | ft2 | | (60,61,AAA060) | 60 | 61 | AAA060
+ (1266,66,foo,,,,"ft2 ",) | 1266 | 66 | foo | | | | ft2 | | (66,67,AAA066) | 66 | 67 | AAA066
+ (1272,72,foo,,,,"ft2 ",) | 1272 | 72 | foo | | | | ft2 | | (72,73,AAA072) | 72 | 73 | AAA072
+ (1278,78,foo,,,,"ft2 ",) | 1278 | 78 | foo | | | | ft2 | | (78,79,AAA078) | 78 | 79 | AAA078
+ (1284,84,foo,,,,"ft2 ",) | 1284 | 84 | foo | | | | ft2 | | (84,85,AAA084) | 84 | 85 | AAA084
+ (1290,90,foo,,,,"ft2 ",) | 1290 | 90 | foo | | | | ft2 | | (90,91,AAA090) | 90 | 91 | AAA090
+ (1296,96,foo,,,,"ft2 ",) | 1296 | 96 | foo | | | | ft2 | | (96,97,AAA096) | 96 | 97 | AAA096
+(16 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: 100
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1)))) WHERE ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) AND (((r1."C 1" % 10) = 0))
+(4 rows)
+
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100;
+ ?column?
+----------
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+(10 rows)
+
+DELETE FROM ft2 WHERE ft2.c1 > 1200;
+-- Test UPDATE with a MULTIEXPR sub-select
+-- (maybe someday this'll be remotely executable, but not today)
+EXPLAIN (verbose, costs off)
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 target
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2, c7 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.ft2 target
+ Output: $1, $2, (SubPlan 1 (returns $1,$2)), target.ctid, target.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1100)) FOR UPDATE
+ SubPlan 1 (returns $1,$2)
+ -> Foreign Scan on public.ft2 src
+ Output: (src.c2 * 10), src.c7
+ Remote SQL: SELECT c2, c7 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(9 rows)
+
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+UPDATE ft2 AS target SET (c2) = (
+ SELECT c2 / 10
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+-- Test UPDATE involving a join that can be pushed down,
+-- but a SET clause that can't be
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 d
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2 WHERE ctid = $1
+ -> Foreign Scan
+ Output: CASE WHEN (random() >= '0'::double precision) THEN d.c2 ELSE 0 END, d.ctid, d.*, t.*
+ Relations: (public.ft2 d) INNER JOIN (public.ft2 t)
+ Remote SQL: SELECT r1.c2, r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r1."C 1" > 1000)))) FOR UPDATE OF r1
+ -> Hash Join
+ Output: d.c2, d.ctid, d.*, t.*
+ Hash Cond: (d.c1 = t.c1)
+ -> Foreign Scan on public.ft2 d
+ Output: d.c2, d.ctid, d.*, d.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1000)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Hash
+ Output: t.*, t.c1
+ -> Foreign Scan on public.ft2 t
+ Output: t.*, t.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(17 rows)
+
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+-- Test UPDATE/DELETE with WHERE or JOIN/ON conditions containing
+-- user-defined operators/functions
+ALTER SERVER loopback OPTIONS (DROP extensions);
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id % 10, to_char(id, 'FM00000') FROM generate_series(2001, 2010) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft2
+ Output: 'bar'::text, ctid, ft2.*
+ Filter: (postgres_fdw_abs(ft2.c1) > 2000)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" FOR UPDATE
+(7 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-----+----+----+----+------------+----
+ 2001 | 1 | bar | | | | ft2 |
+ 2002 | 2 | bar | | | | ft2 |
+ 2003 | 3 | bar | | | | ft2 |
+ 2004 | 4 | bar | | | | ft2 |
+ 2005 | 5 | bar | | | | ft2 |
+ 2006 | 6 | bar | | | | ft2 |
+ 2007 | 7 | bar | | | | ft2 |
+ 2008 | 8 | bar | | | | ft2 |
+ 2009 | 9 | bar | | | | ft2 |
+ 2010 | 0 | bar | | | | ft2 |
+(10 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Nested Loop
+ Output: 'baz'::text, ft2.ctid, ft2.*, ft4.*, ft5.*, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Join Filter: (ft2.c2 === ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.*, ft2.c2
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Relations: (public.ft4) INNER JOIN (public.ft5)
+ Remote SQL: SELECT CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r3.c1, r3.c2, r3.c3 FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1))))
+ -> Hash Join
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(24 rows)
+
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3
+------+----+-----+----+----+----+------------+----+----+----+--------+----+----+--------
+ 2006 | 6 | baz | | | | ft2 | | 6 | 7 | AAA006 | 6 | 7 | AAA006
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ctid = $1 RETURNING "C 1", c2, c3
+ -> Foreign Scan
+ Output: ft2.ctid, ft4.*, ft5.*
+ Filter: (ft4.c1 === ft5.c1)
+ Relations: ((public.ft2) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r2.c1, r3.c1 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c2 = r2.c1)) AND ((r1."C 1" > 2000)))) INNER JOIN "S 1"."T 4" r3 ON (TRUE)) FOR UPDATE OF r1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft5.*, ft4.c1, ft5.c1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft4.c1
+ Join Filter: (ft2.c2 = ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.c2
+ Remote SQL: SELECT c2, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(22 rows)
+
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3;
+ c1 | c2 | c3
+------+----+-----
+ 2006 | 6 | baz
+(1 row)
+
+DELETE FROM ft2 WHERE ft2.c1 > 2000;
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- Test that trigger on remote table works as expected
+CREATE OR REPLACE FUNCTION "S 1".F_BRTRIG() RETURNS trigger AS $$
+BEGIN
+ NEW.c3 = NEW.c3 || '_trig_update';
+ RETURN NEW;
+END;
+$$ LANGUAGE plpgsql;
+CREATE TRIGGER t1_br_insert BEFORE INSERT OR UPDATE
+ ON "S 1"."T 1" FOR EACH ROW EXECUTE PROCEDURE "S 1".F_BRTRIG();
+INSERT INTO ft2 (c1,c2,c3) VALUES (1208, 818, 'fff') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+----+------------+----
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+(1 row)
+
+INSERT INTO ft2 (c1,c2,c3,c6) VALUES (1218, 818, 'ggg', '(--;') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+------+------------+----
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+(1 row)
+
+UPDATE ft2 SET c2 = c2 + 600 WHERE c1 % 10 = 8 AND c1 < 1200 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+------------------------+------------------------------+--------------------------+----+------------+-----
+ 8 | 608 | 00008_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 18 | 608 | 00018_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 28 | 608 | 00028_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 38 | 608 | 00038_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 48 | 608 | 00048_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 58 | 608 | 00058_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 68 | 608 | 00068_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 78 | 608 | 00078_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 88 | 608 | 00088_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 98 | 608 | 00098_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 108 | 608 | 00108_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 118 | 608 | 00118_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 128 | 608 | 00128_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 138 | 608 | 00138_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 148 | 608 | 00148_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 158 | 608 | 00158_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 168 | 608 | 00168_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 178 | 608 | 00178_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 188 | 608 | 00188_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 198 | 608 | 00198_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 208 | 608 | 00208_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 218 | 608 | 00218_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 228 | 608 | 00228_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 238 | 608 | 00238_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 248 | 608 | 00248_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 258 | 608 | 00258_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 268 | 608 | 00268_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 278 | 608 | 00278_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 288 | 608 | 00288_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 298 | 608 | 00298_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 308 | 608 | 00308_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 318 | 608 | 00318_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 328 | 608 | 00328_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 338 | 608 | 00338_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 348 | 608 | 00348_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 358 | 608 | 00358_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 368 | 608 | 00368_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 378 | 608 | 00378_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 388 | 608 | 00388_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 398 | 608 | 00398_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 408 | 608 | 00408_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 418 | 608 | 00418_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 428 | 608 | 00428_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 438 | 608 | 00438_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 448 | 608 | 00448_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 458 | 608 | 00458_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 468 | 608 | 00468_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 478 | 608 | 00478_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 488 | 608 | 00488_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 498 | 608 | 00498_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 508 | 608 | 00508_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 518 | 608 | 00518_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 528 | 608 | 00528_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 538 | 608 | 00538_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 548 | 608 | 00548_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 558 | 608 | 00558_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 568 | 608 | 00568_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 578 | 608 | 00578_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 588 | 608 | 00588_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 598 | 608 | 00598_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 608 | 608 | 00608_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 618 | 608 | 00618_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 628 | 608 | 00628_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 638 | 608 | 00638_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 648 | 608 | 00648_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 658 | 608 | 00658_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 668 | 608 | 00668_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 678 | 608 | 00678_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 688 | 608 | 00688_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 698 | 608 | 00698_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 708 | 608 | 00708_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 718 | 608 | 00718_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 728 | 608 | 00728_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 738 | 608 | 00738_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 748 | 608 | 00748_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 758 | 608 | 00758_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 768 | 608 | 00768_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 778 | 608 | 00778_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 788 | 608 | 00788_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 798 | 608 | 00798_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 808 | 608 | 00808_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 818 | 608 | 00818_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 828 | 608 | 00828_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 838 | 608 | 00838_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 848 | 608 | 00848_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 858 | 608 | 00858_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 868 | 608 | 00868_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 878 | 608 | 00878_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 888 | 608 | 00888_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 898 | 608 | 00898_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 908 | 608 | 00908_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 918 | 608 | 00918_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 928 | 608 | 00928_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 938 | 608 | 00938_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 948 | 608 | 00948_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 958 | 608 | 00958_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 968 | 608 | 00968_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 978 | 608 | 00978_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 988 | 608 | 00988_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 998 | 608 | 00998_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 1008 | 708 | 0000800008_trig_update | | | | ft2 |
+ 1018 | 708 | 0001800018_trig_update | | | | ft2 |
+(102 rows)
+
+-- Test errors thrown on remote side during update
+ALTER TABLE "S 1"."T 1" ADD CONSTRAINT c2positive CHECK (c2 >= 0);
+INSERT INTO ft1(c1, c2) VALUES(11, 12); -- duplicate key
+ERROR: duplicate key value violates unique constraint "t1_pkey"
+DETAIL: Key ("C 1")=(11) already exists.
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT DO NOTHING; -- works
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO NOTHING; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO UPDATE SET c3 = 'ffg'; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+-- Test savepoint/rollback behavior
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+begin;
+update ft2 set c2 = 42 where c2 = 0;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 42 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s1;
+update ft2 set c2 = 44 where c2 = 4;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s1;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s2;
+update ft2 set c2 = 46 where c2 = 6;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 42 | 100
+ 44 | 100
+ 46 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+rollback to savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s3;
+update ft2 set c2 = -2 where c2 = 42 and c1 = 10; -- fail on remote side
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (10, -2, 00010_trig_update_trig_update, 1970-01-11 08:00:00+00, 1970-01-11 00:00:00, 0, 0 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (-2) WHERE ((c2 = 42)) AND (("C 1" = 10))
+rollback to savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+-- none of the above is committed yet remotely
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+commit;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+VACUUM ANALYZE "S 1"."T 1";
+-- Above DMLs add data with c6 as NULL in ft1, so test ORDER BY NULLS LAST and NULLs
+-- FIRST behavior here.
+-- ORDER BY DESC NULLS LAST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 795::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+------+------------+-----
+ 960 | 42 | 00960_trig_update | Mon Mar 02 00:00:00 1970 PST | Mon Mar 02 00:00:00 1970 | 0 | 0 | foo
+ 970 | 42 | 00970_trig_update | Thu Mar 12 00:00:00 1970 PST | Thu Mar 12 00:00:00 1970 | 0 | 0 | foo
+ 980 | 42 | 00980_trig_update | Sun Mar 22 00:00:00 1970 PST | Sun Mar 22 00:00:00 1970 | 0 | 0 | foo
+ 990 | 42 | 00990_trig_update | Wed Apr 01 00:00:00 1970 PST | Wed Apr 01 00:00:00 1970 | 0 | 0 | foo
+ 1000 | 42 | 01000_trig_update | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 1001 | 101 | 0000100001 | | | | ft2 |
+ 1003 | 403 | 0000300003_update3 | | | | ft2 |
+ 1004 | 104 | 0000400004 | | | | ft2 |
+ 1006 | 106 | 0000600006 | | | | ft2 |
+(10 rows)
+
+-- ORDER BY DESC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+------------------------------+--------------------------+----+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | ft2 | foo
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST | Tue Jan 20 00:00:00 1970 | 9 | ft2 | foo
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST | Fri Jan 30 00:00:00 1970 | 9 | ft2 | foo
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST | Mon Feb 09 00:00:00 1970 | 9 | ft2 | foo
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST | Thu Feb 19 00:00:00 1970 | 9 | ft2 | foo
+(10 rows)
+
+-- ORDER BY ASC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 ASC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-------------------+------------------------------+--------------------------+------+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 10 | 42 | 00010_trig_update | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+ 20 | 42 | 00020_trig_update | Wed Jan 21 00:00:00 1970 PST | Wed Jan 21 00:00:00 1970 | 0 | 0 | foo
+ 30 | 42 | 00030_trig_update | Sat Jan 31 00:00:00 1970 PST | Sat Jan 31 00:00:00 1970 | 0 | 0 | foo
+ 40 | 42 | 00040_trig_update | Tue Feb 10 00:00:00 1970 PST | Tue Feb 10 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- ===================================================================
+-- test check constraints
+-- ===================================================================
+-- Consistent check constraints provide consistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- check constraint is enforced on the remote side, not locally
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
+-- But inconsistent check constraints provide inconsistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 821
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- local check constraint is not actually enforced
+INSERT INTO ft1(c1, c2) VALUES(1111, 2);
+UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
+-- ===================================================================
+-- test WITH CHECK OPTION constraints
+-- ===================================================================
+CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
+CREATE TABLE base_tbl (a int, b int);
+ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE VIEW rw_view AS SELECT * FROM foreign_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT foreign_tbl.a,
+ foreign_tbl.b
+ FROM foreign_tbl
+ WHERE foreign_tbl.a < foreign_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 5
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 15
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 5), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 15), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP TRIGGER row_before_insupd_trigger ON base_tbl;
+DROP TABLE base_tbl;
+-- test WCO for partitions
+CREATE TABLE child_tbl (a int, b int);
+ALTER TABLE child_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON child_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'child_tbl');
+CREATE TABLE parent_tbl (a int, b int) PARTITION BY RANGE(a);
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+-- Detach and re-attach once, to stress the concurrent detach case.
+ALTER TABLE parent_tbl DETACH PARTITION foreign_tbl CONCURRENTLY;
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+CREATE VIEW rw_view AS SELECT * FROM parent_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT parent_tbl.a,
+ parent_tbl.b
+ FROM parent_tbl
+ WHERE parent_tbl.a < parent_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 5
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 15
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 5), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 15), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------
+ Insert on public.parent_tbl
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+DROP TRIGGER row_before_insupd_trigger ON child_tbl;
+DROP TABLE parent_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP FUNCTION row_before_insupd_trigfunc;
+-- ===================================================================
+-- test serial columns (ie, sequence-based defaults)
+-- ===================================================================
+create table loc1 (f1 serial, f2 text);
+alter table loc1 set (autovacuum_enabled = 'false');
+create foreign table rem1 (f1 serial, f2 text)
+ server loopback options(table_name 'loc1');
+select pg_catalog.setval('rem1_f1_seq', 10, false);
+ setval
+--------
+ 10
+(1 row)
+
+insert into loc1(f2) values('hi');
+insert into rem1(f2) values('hi remote');
+insert into loc1(f2) values('bye');
+insert into rem1(f2) values('bye remote');
+select * from loc1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+select * from rem1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+-- ===================================================================
+-- test generated columns
+-- ===================================================================
+create table gloc1 (
+ a int,
+ b int generated always as (a * 2) stored);
+alter table gloc1 set (autovacuum_enabled = 'false');
+create foreign table grem1 (
+ a int,
+ b int generated always as (a * 2) stored)
+ server loopback options(table_name 'gloc1');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+explain (verbose, costs off)
+update grem1 set a = 22 where a = 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.grem1
+ Remote SQL: UPDATE public.gloc1 SET a = $2, b = DEFAULT WHERE ctid = $1
+ -> Foreign Scan on public.grem1
+ Output: 22, ctid, grem1.*
+ Remote SQL: SELECT a, b, ctid FROM public.gloc1 WHERE ((a = 2)) FOR UPDATE
+(5 rows)
+
+update grem1 set a = 22 where a = 2;
+select * from gloc1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+select * from grem1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+delete from grem1;
+-- test copy from
+copy grem1 from stdin;
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+-- test batch insert
+alter server loopback options (add batch_size '10');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 10
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test local triggers
+-- ===================================================================
+-- Trigger functions "borrowed" from triggers regress test.
+CREATE FUNCTION trigger_func() RETURNS trigger LANGUAGE plpgsql AS $$
+BEGIN
+ RAISE NOTICE 'trigger_func(%) called: action = %, when = %, level = %',
+ TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN NULL;
+END;$$;
+CREATE TRIGGER trig_stmt_before BEFORE DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE TRIGGER trig_stmt_after AFTER DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE OR REPLACE FUNCTION trigger_data() RETURNS trigger
+LANGUAGE plpgsql AS $$
+
+declare
+ oldnew text[];
+ relid text;
+ argstr text;
+begin
+
+ relid := TG_relid::regclass;
+ argstr := '';
+ for i in 0 .. TG_nargs - 1 loop
+ if i > 0 then
+ argstr := argstr || ', ';
+ end if;
+ argstr := argstr || TG_argv[i];
+ end loop;
+
+ RAISE NOTICE '%(%) % % % ON %',
+ tg_name, argstr, TG_when, TG_level, TG_OP, relid;
+ oldnew := '{}'::text[];
+ if TG_OP != 'INSERT' then
+ oldnew := array_append(oldnew, format('OLD: %s', OLD));
+ end if;
+
+ if TG_OP != 'DELETE' then
+ oldnew := array_append(oldnew, format('NEW: %s', NEW));
+ end if;
+
+ RAISE NOTICE '%', array_to_string(oldnew, ',');
+
+ if TG_OP = 'DELETE' then
+ return OLD;
+ else
+ return NEW;
+ end if;
+end;
+$$;
+-- Test basic functionality
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+delete from rem1;
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = AFTER, level = STATEMENT
+insert into rem1 values(1,'insert');
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+update rem1 set f2 = f2 || f2;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+truncate rem1;
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = BEFORE, level = STATEMENT
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = AFTER, level = STATEMENT
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_stmt_before ON rem1;
+DROP TRIGGER trig_stmt_after ON rem1;
+DELETE from rem1;
+-- Test multiple AFTER ROW triggers on a foreign table
+CREATE TRIGGER trig_row_after1
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after2
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+insert into rem1 values(1,'insert');
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+update rem1 set f2 = f2 || f2;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+delete from rem1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+-- cleanup
+DROP TRIGGER trig_row_after1 ON rem1;
+DROP TRIGGER trig_row_after2 ON rem1;
+-- Test WHEN conditions
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_insupd
+AFTER INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Insert or update not matching: nothing happens
+INSERT INTO rem1 values(1, 'insert');
+UPDATE rem1 set f2 = 'test';
+-- Insert or update matching: triggers are fired
+INSERT INTO rem1 values(2, 'update');
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+UPDATE rem1 set f2 = 'update update' where f1 = '2';
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Trigger is fired for f1=2, not for f1=1
+DELETE FROM rem1;
+NOTICE: trig_row_before_delete(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+NOTICE: trig_row_after_delete(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+-- cleanup
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_after_insupd ON rem1;
+DROP TRIGGER trig_row_before_delete ON rem1;
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- Test various RETURN statements in BEFORE triggers.
+CREATE FUNCTION trig_row_before_insupdate() RETURNS TRIGGER AS $$
+ BEGIN
+ NEW.f2 := NEW.f2 || ' triggered !';
+ RETURN NEW;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+-- The new values should have 'triggered' appended
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------
+ insert triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+ 2 | insert triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------
+ 1 | triggered !
+ 2 | triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------
+ skidoo triggered !
+ skidoo triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | skidoo triggered !
+ 2 | skidoo triggered !
+(2 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f1 = 10; -- all columns should be transmitted
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: 10, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+UPDATE rem1 set f1 = 10;
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 10 | skidoo triggered ! triggered !
+ 10 | skidoo triggered ! triggered !
+(2 rows)
+
+DELETE FROM rem1;
+-- Add a second trigger, to check that the changes are propagated correctly
+-- from trigger to trigger
+CREATE TRIGGER trig_row_before_insupd2
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------------------
+ insert triggered ! triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+ 2 | insert triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------
+ 1 | triggered ! triggered !
+ 2 | triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------------------
+ skidoo triggered ! triggered !
+ skidoo triggered ! triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | skidoo triggered ! triggered !
+ 2 | skidoo triggered ! triggered !
+(2 rows)
+
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_before_insupd2 ON rem1;
+DELETE from rem1;
+INSERT INTO rem1 VALUES (1, 'test');
+-- Test with a trigger returning NULL
+CREATE FUNCTION trig_null() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_null
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_null();
+-- Nothing should have changed.
+INSERT INTO rem1 VALUES (2, 'test2');
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+UPDATE rem1 SET f2 = 'test2';
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DELETE from rem1;
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DROP TRIGGER trig_null ON rem1;
+DELETE from rem1;
+-- Test a combination of local and remote triggers
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_local_before BEFORE INSERT OR UPDATE ON loc1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1(f2) VALUES ('test');
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (12,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (12,"test triggered !")
+UPDATE rem1 SET f2 = 'testo';
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,testo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,"testo triggered !")
+-- Test returning a system attribute
+INSERT INTO rem1(f2) VALUES ('test') RETURNING ctid;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (13,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (13,"test triggered !")
+ ctid
+--------
+ (0,25)
+(1 row)
+
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_local_before ON loc1;
+-- Test direct foreign table modification functionality
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1 WHERE false; -- currently can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Result
+ Output: ctid
+ One-Time Filter: false
+(5 rows)
+
+-- Test with statement-level triggers
+CREATE TRIGGER trig_stmt_before
+ BEFORE DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_before ON rem1;
+CREATE TRIGGER trig_stmt_after
+ AFTER DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_after ON rem1;
+-- Test with row-level ON INSERT triggers
+CREATE TRIGGER trig_row_before_insert
+BEFORE INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_insert ON rem1;
+CREATE TRIGGER trig_row_after_insert
+AFTER INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_insert ON rem1;
+-- Test with row-level ON UPDATE triggers
+CREATE TRIGGER trig_row_before_update
+BEFORE UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_update ON rem1;
+CREATE TRIGGER trig_row_after_update
+AFTER UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = $2 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_update ON rem1;
+-- Test with row-level ON DELETE triggers
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_before_delete ON rem1;
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- ===================================================================
+-- test inheritance features
+-- ===================================================================
+CREATE TABLE a (aa TEXT);
+CREATE TABLE loct (aa TEXT, bb TEXT);
+ALTER TABLE a SET (autovacuum_enabled = 'false');
+ALTER TABLE loct SET (autovacuum_enabled = 'false');
+CREATE FOREIGN TABLE b (bb TEXT) INHERITS (a)
+ SERVER loopback OPTIONS (table_name 'loct');
+INSERT INTO a(aa) VALUES('aaa');
+INSERT INTO a(aa) VALUES('aaaa');
+INSERT INTO a(aa) VALUES('aaaaa');
+INSERT INTO b(aa) VALUES('bbb');
+INSERT INTO b(aa) VALUES('bbbb');
+INSERT INTO b(aa) VALUES('bbbbb');
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+(3 rows)
+
+UPDATE a SET aa = 'zzzzzz' WHERE aa LIKE 'aaaa%';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE b SET aa = 'new';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | new
+ b | new
+ b | new
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-----+----
+ b | new |
+ b | new |
+ b | new |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE a SET aa = 'newtoo';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+ b | newtoo
+ b | newtoo
+ b | newtoo
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+--------+----
+ b | newtoo |
+ b | newtoo |
+ b | newtoo |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+(3 rows)
+
+DELETE FROM a;
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+----+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+DROP TABLE a CASCADE;
+NOTICE: drop cascades to foreign table b
+DROP TABLE loct;
+-- Check SELECT FOR UPDATE/SHARE with an inherited source table
+create table loct1 (f1 int, f2 int, f3 int);
+create table loct2 (f1 int, f2 int, f3 int);
+alter table loct1 set (autovacuum_enabled = 'false');
+alter table loct2 set (autovacuum_enabled = 'false');
+create table foo (f1 int, f2 int);
+create foreign table foo2 (f3 int) inherits (foo)
+ server loopback options (table_name 'loct1');
+create table bar (f1 int, f2 int);
+create foreign table bar2 (f3 int) inherits (bar)
+ server loopback options (table_name 'loct2');
+alter table foo set (autovacuum_enabled = 'false');
+alter table bar set (autovacuum_enabled = 'false');
+insert into foo values(1,1);
+insert into foo values(3,3);
+insert into foo2 values(2,2,2);
+insert into foo2 values(4,4,4);
+insert into bar values(1,11);
+insert into bar values(2,22);
+insert into bar values(6,66);
+insert into bar2 values(3,33,33);
+insert into bar2 values(4,44,44);
+insert into bar2 values(7,77,77);
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for update;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for update;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for share;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for share;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+-- Now check SELECT FOR UPDATE/SHARE with an inherited source table,
+-- where the parent is itself a foreign table
+create table loct4 (f1 int, f2 int, f3 int);
+create foreign table foo2child (f3 int) inherits (foo2)
+ server loopback options (table_name 'loct4');
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct1
+ -> Foreign Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct4
+(24 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop foreign table foo2child;
+-- And with a local child relation of the foreign table parent
+create table foo2child (f3 int) inherits (foo2);
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.ctid, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+ -> Seq Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.ctid, foo2_2.tableoid
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop table foo2child;
+-- Check UPDATE with inherited target and an inherited source table
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Hash Join
+ Output: (bar.f2 + 100), foo.ctid, bar.tableoid, bar.ctid, (NULL::record), foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(25 rows)
+
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 111
+ bar | 2 | 122
+ bar | 6 | 66
+ bar2 | 3 | 133
+ bar2 | 4 | 144
+ bar2 | 7 | 77
+(6 rows)
+
+-- Check UPDATE with inherited target and an appendrel subquery
+explain (verbose, costs off)
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Merge Join
+ Output: (bar.f2 + 100), (ROW(foo.f1)), bar.tableoid, bar.ctid, (NULL::record)
+ Merge Cond: (bar.f1 = foo.f1)
+ -> Sort
+ Output: bar.f2, bar.f1, bar.tableoid, bar.ctid, (NULL::record)
+ Sort Key: bar.f1
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Sort
+ Output: (ROW(foo.f1)), foo.f1
+ Sort Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: ROW(foo.f1), foo.f1
+ -> Foreign Scan on public.foo2 foo_1
+ Output: ROW(foo_1.f1), foo_1.f1
+ Remote SQL: SELECT f1 FROM public.loct1
+ -> Seq Scan on public.foo foo_2
+ Output: ROW((foo_2.f1 + 3)), (foo_2.f1 + 3)
+ -> Foreign Scan on public.foo2 foo_3
+ Output: ROW((foo_3.f1 + 3)), (foo_3.f1 + 3)
+ Remote SQL: SELECT f1 FROM public.loct1
+(30 rows)
+
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 211
+ bar | 2 | 222
+ bar | 6 | 166
+ bar2 | 3 | 233
+ bar2 | 4 | 244
+ bar2 | 7 | 177
+(6 rows)
+
+-- Test forcing the remote server to produce sorted data for a merge join,
+-- but the foreign table is an inheritance child.
+truncate table loct1;
+truncate table only foo;
+\set num_rows_foo 2000
+insert into loct1 select generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2);
+insert into foo select generate_series(1, :num_rows_foo, 2), generate_series(1, :num_rows_foo, 2);
+SET enable_hashjoin to false;
+SET enable_nestloop to false;
+alter foreign table foo2 options (use_remote_estimate 'true');
+create index i_loct1_f1 on loct1(f1);
+create index i_foo_f1 on foo(f1);
+analyze foo;
+analyze loct1;
+-- inner join; expressions in the clauses appear in the equivalence class list
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 20 | 20
+ 22 | 22
+ 24 | 24
+ 26 | 26
+ 28 | 28
+ 30 | 30
+ 32 | 32
+ 34 | 34
+ 36 | 36
+ 38 | 38
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Left Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 10 | 10
+ 11 |
+ 12 | 12
+ 13 |
+ 14 | 14
+ 15 |
+ 16 | 16
+ 17 |
+ 18 | 18
+ 19 |
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test that WHERE CURRENT OF is not supported
+begin;
+declare c cursor for select * from bar where f1 = 7;
+fetch from c;
+ f1 | f2
+----+-----
+ 7 | 177
+(1 row)
+
+update bar set f2 = null where current of c;
+ERROR: WHERE CURRENT OF is not supported for this table type
+rollback;
+explain (verbose, costs off)
+delete from foo where f1 < 5 returning *;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Delete on public.foo
+ Output: foo_1.f1, foo_1.f2
+ Delete on public.foo foo_1
+ Foreign Delete on public.foo2 foo_2
+ -> Append
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.tableoid, foo_1.ctid
+ Index Cond: (foo_1.f1 < 5)
+ -> Foreign Delete on public.foo2 foo_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ((f1 < 5)) RETURNING f1, f2
+(10 rows)
+
+delete from foo where f1 < 5 returning *;
+ f1 | f2
+----+----
+ 1 | 1
+ 3 | 3
+ 0 | 0
+ 2 | 2
+ 4 | 4
+(5 rows)
+
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Update on public.bar
+ Output: bar_1.f1, bar_1.f2
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = (f2 + 100) RETURNING f1, f2
+(11 rows)
+
+update bar set f2 = f2 + 100 returning *;
+ f1 | f2
+----+-----
+ 1 | 311
+ 2 | 322
+ 6 | 266
+ 3 | 333
+ 4 | 344
+ 7 | 277
+(6 rows)
+
+-- Test that UPDATE/DELETE with inherited target works with row-level triggers
+CREATE TRIGGER trig_row_before
+BEFORE UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+explain (verbose, costs off)
+update bar set f2 = f2 + 100;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f1 = $2, f2 = $3, f3 = $4 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+(12 rows)
+
+update bar set f2 = f2 + 100;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+explain (verbose, costs off)
+delete from bar where f2 < 400;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Delete on public.bar
+ Delete on public.bar bar_1
+ Foreign Delete on public.bar2 bar_2
+ Remote SQL: DELETE FROM public.loct2 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.tableoid, bar_1.ctid, NULL::record
+ Filter: (bar_1.f2 < 400)
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 WHERE ((f2 < 400)) FOR UPDATE
+(11 rows)
+
+delete from bar where f2 < 400;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+-- cleanup
+drop table foo cascade;
+NOTICE: drop cascades to foreign table foo2
+drop table bar cascade;
+NOTICE: drop cascades to foreign table bar2
+drop table loct1;
+drop table loct2;
+-- Test pushing down UPDATE/DELETE joins to the remote server
+create table parent (a int, b text);
+create table loct1 (a int, b text);
+create table loct2 (a int, b text);
+create foreign table remt1 (a int, b text)
+ server loopback options (table_name 'loct1');
+create foreign table remt2 (a int, b text)
+ server loopback options (table_name 'loct2');
+alter foreign table remt1 inherit parent;
+insert into remt1 values (1, 'foo');
+insert into remt1 values (2, 'bar');
+insert into remt2 values (1, 'foo');
+insert into remt2 values (2, 'bar');
+analyze remt1;
+analyze remt2;
+explain (verbose, costs off)
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.parent
+ Output: parent_1.a, parent_1.b, remt2.a, remt2.b
+ Update on public.parent parent_1
+ Foreign Update on public.remt1 parent_2
+ Remote SQL: UPDATE public.loct1 SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: (parent.b || remt2.b), remt2.*, remt2.a, remt2.b, parent.tableoid, parent.ctid, (NULL::record)
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.b, parent_1.a, parent_1.tableoid, parent_1.ctid, NULL::record
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.b, parent_2.a, parent_2.tableoid, parent_2.ctid, parent_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.b, remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.b, remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ a | b | a | b
+---+--------+---+-----
+ 1 | foofoo | 1 | foo
+ 2 | barbar | 2 | bar
+(2 rows)
+
+explain (verbose, costs off)
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Delete on public.parent
+ Output: parent_1.*
+ Delete on public.parent parent_1
+ Foreign Delete on public.remt1 parent_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: remt2.*, parent.tableoid, parent.ctid
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.a, parent_1.tableoid, parent_1.ctid
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.a, parent_2.tableoid, parent_2.ctid
+ Remote SQL: SELECT a, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ parent
+------------
+ (1,foofoo)
+ (2,barbar)
+(2 rows)
+
+-- cleanup
+drop foreign table remt1;
+drop foreign table remt2;
+drop table loct1;
+drop table loct2;
+drop table parent;
+-- ===================================================================
+-- test tuple routing for foreign-table partitions
+-- ===================================================================
+-- Test insert tuple routing
+create table itrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table itrtest attach partition remp1 for values in (1);
+alter table itrtest attach partition remp2 for values in (2);
+insert into itrtest values (1, 'foo');
+insert into itrtest values (1, 'bar') returning *;
+ a | b
+---+-----
+ 1 | bar
+(1 row)
+
+insert into itrtest values (2, 'baz');
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----
+ 2 | qux
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------
+ 1 | test1
+ 2 | test2
+(2 rows)
+
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from itrtest;
+-- MERGE ought to fail cleanly
+merge into itrtest using (select 1, 'foo') as source on (true)
+ when matched then do nothing;
+ERROR: cannot execute MERGE on relation "remp1"
+DETAIL: This operation is not supported for foreign tables.
+create unique index loct1_idx on loct1 (a);
+-- DO NOTHING without an inference specification is supported
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+-----
+ 1 | foo
+(1 row)
+
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+---
+(0 rows)
+
+-- But other cases are not supported
+insert into itrtest values (1, 'bar') on conflict (a) do nothing;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+insert into itrtest values (1, 'bar') on conflict (a) do update set b = excluded.b;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+delete from itrtest;
+drop index loct1_idx;
+-- Test that remote triggers work with insert tuple routing
+create function br_insert_trigfunc() returns trigger as $$
+begin
+ new.b := new.b || ' triggered !';
+ return new;
+end
+$$ language plpgsql;
+create trigger loct1_br_insert_trigger before insert on loct1
+ for each row execute procedure br_insert_trigfunc();
+create trigger loct2_br_insert_trigger before insert on loct2
+ for each row execute procedure br_insert_trigfunc();
+-- The new values are concatenated with ' triggered !'
+insert into itrtest values (1, 'foo') returning *;
+ a | b
+---+-----------------
+ 1 | foo triggered !
+(1 row)
+
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----------------
+ 2 | qux triggered !
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+with result as (insert into itrtest values (1, 'test1'), (2, 'test2') returning *) select * from result;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+drop trigger loct1_br_insert_trigger on loct1;
+drop trigger loct2_br_insert_trigger on loct2;
+drop table itrtest;
+drop table loct1;
+drop table loct2;
+-- Test update tuple routing
+create table utrtest (a int, b text) partition by list (a);
+create table loct (a int check (a in (1)), b text);
+create foreign table remp (a int check (a in (1)), b text) server loopback options (table_name 'loct');
+create table locp (a int check (a in (2)), b text);
+alter table utrtest attach partition remp for values in (1);
+alter table utrtest attach partition locp for values in (2);
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- It's not allowed to move a row from a partition that is foreign to another
+update utrtest set a = 2 where b = 'foo' returning *;
+ERROR: new row for relation "loct" violates check constraint "loct_a_check"
+DETAIL: Failing row contains (2, foo).
+CONTEXT: remote SQL command: UPDATE public.loct SET a = 2 WHERE ((b = 'foo')) RETURNING a, b
+-- But the reverse is allowed
+update utrtest set a = 1 where b = 'qux' returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- The executor should not let unexercised FDWs shut down
+update utrtest set a = 1 where b = 'foo';
+-- Test that remote triggers work with update tuple routing
+create trigger loct_br_insert_trigger before insert on loct
+ for each row execute procedure br_insert_trigfunc();
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition is a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 WHERE (((a = 1) OR (a = 2))) RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ Filter: ((utrtest_2.a = 1) OR (utrtest_2.a = 2))
+(10 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition isn't a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 2 returning *;
+ QUERY PLAN
+-------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ -> Seq Scan on public.locp utrtest_1
+ Output: 1, utrtest_1.tableoid, utrtest_1.ctid
+ Filter: (utrtest_1.a = 2)
+(6 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 2 returning *;
+ a | b
+---+-----------------
+ 1 | qux triggered !
+(1 row)
+
+drop trigger loct_br_insert_trigger on loct;
+-- We can move rows to a foreign partition that has been updated already,
+-- but can't move rows to a foreign partition that hasn't been updated yet
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- Test the former case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+(9 rows)
+
+update utrtest set a = 1 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ Update on public.locp utrtest_2
+ -> Hash Join
+ Output: 1, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, utrtest.*
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Foreign Scan on public.remp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, utrtest_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Seq Scan on public.locp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- Change the definition of utrtest so that the foreign partition get updated
+-- after the local partition
+delete from utrtest;
+alter table utrtest detach partition remp;
+drop foreign table remp;
+alter table loct drop constraint loct_a_check;
+alter table loct add check (a in (3));
+create foreign table remp (a int check (a in (3)), b text) server loopback options (table_name 'loct');
+alter table utrtest attach partition remp for values in (3);
+insert into utrtest values (2, 'qux');
+insert into utrtest values (3, 'xyzzy');
+-- Test the latter case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: 3, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = 3 RETURNING a, b
+(9 rows)
+
+update utrtest set a = 3 returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ -> Hash Join
+ Output: 3, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, (NULL::record)
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Scan on public.remp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, utrtest_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+drop table utrtest;
+drop table loct;
+-- Test copy tuple routing
+create table ctrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table ctrtest attach partition remp1 for values in (1);
+alter table ctrtest attach partition remp2 for values in (2);
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp2 | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-----+---
+ remp2 | qux | 2
+(1 row)
+
+-- Copying into foreign partitions directly should work as well
+copy remp1 from stdin;
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+(2 rows)
+
+delete from ctrtest;
+-- Test copy tuple routing with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from ctrtest;
+alter server loopback options (drop batch_size);
+drop table ctrtest;
+drop table loct1;
+drop table loct2;
+-- ===================================================================
+-- test COPY FROM
+-- ===================================================================
+create table loc2 (f1 int, f2 text);
+alter table loc2 set (autovacuum_enabled = 'false');
+create foreign table rem2 (f1 int, f2 text) server loopback options(table_name 'loc2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2, line 1: "-1 xyzzy"
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test local triggers
+create trigger trig_stmt_before before insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_stmt_after after insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+copy rem2 from stdin;
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop trigger trig_row_before on rem2;
+drop trigger trig_row_after on rem2;
+drop trigger trig_stmt_before on rem2;
+drop trigger trig_stmt_after on rem2;
+delete from rem2;
+create trigger trig_row_before_insert before insert on rem2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on rem2;
+delete from rem2;
+create trigger trig_null before insert on rem2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on rem2;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Test a combination of local and remote triggers
+create trigger rem2_trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger rem2_trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger loc2_trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+copy rem2 from stdin;
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,"foo triggered !")
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,"bar triggered !")
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger rem2_trig_row_before on rem2;
+drop trigger rem2_trig_row_after on rem2;
+drop trigger loc2_trig_row_before_insert on loc2;
+delete from rem2;
+-- test COPY FROM with foreign table created in the same transaction
+create table loc3 (f1 int, f2 text);
+begin;
+create foreign table rem3 (f1 int, f2 text)
+ server loopback options(table_name 'loc3');
+copy rem3 from stdin;
+commit;
+select * from rem3;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop foreign table rem3;
+drop table loc3;
+-- Test COPY FROM with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+ 3 | baz triggered !
+(3 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Check with zero-column foreign table; batch insert will be disabled
+alter table loc2 drop column f1;
+alter table loc2 drop column f2;
+alter table rem2 drop column f1;
+alter table rem2 drop column f2;
+copy rem2 from stdin;
+select * from rem2;
+--
+(3 rows)
+
+delete from rem2;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test for TRUNCATE
+-- ===================================================================
+CREATE TABLE tru_rtable0 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable0');
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(1,10) x);
+CREATE TABLE tru_ptable (id int) PARTITION BY HASH(id);
+CREATE TABLE tru_ptable__p0 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tru_rtable1 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable__p1 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback OPTIONS (table_name 'tru_rtable1');
+INSERT INTO tru_ptable (SELECT x FROM generate_series(11,20) x);
+CREATE TABLE tru_pk_table(id int primary key);
+CREATE TABLE tru_fk_table(fkey int references tru_pk_table(id));
+INSERT INTO tru_pk_table (SELECT x FROM generate_series(1,10) x);
+INSERT INTO tru_fk_table (SELECT x % 10 + 1 FROM generate_series(5,25) x);
+CREATE FOREIGN TABLE tru_pk_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_pk_table');
+CREATE TABLE tru_rtable_parent (id int);
+CREATE TABLE tru_rtable_child (id int);
+CREATE FOREIGN TABLE tru_ftable_parent (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_parent');
+CREATE FOREIGN TABLE tru_ftable_child () INHERITS (tru_ftable_parent)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_child');
+INSERT INTO tru_rtable_parent (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_rtable_child (SELECT x FROM generate_series(10, 18) x);
+-- normal truncate
+SELECT sum(id) FROM tru_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_ftable;
+SELECT count(*) FROM tru_rtable0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'truncatable' option
+ALTER SERVER loopback OPTIONS (ADD truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (ADD truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER SERVER loopback OPTIONS (DROP truncatable);
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+-- partitioned table with both local and foreign tables as partitions
+SELECT sum(id) FROM tru_ptable; -- 155
+ sum
+-----
+ 155
+(1 row)
+
+TRUNCATE tru_ptable;
+SELECT count(*) FROM tru_ptable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ptable__p0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable__p1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_rtable1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'CASCADE' option
+SELECT sum(id) FROM tru_pk_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_pk_ftable; -- failed by FK reference
+ERROR: cannot truncate a table referenced in a foreign key constraint
+DETAIL: Table "tru_fk_table" references "tru_pk_table".
+HINT: Truncate table "tru_fk_table" at the same time, or use TRUNCATE ... CASCADE.
+CONTEXT: remote SQL command: TRUNCATE public.tru_pk_table CONTINUE IDENTITY RESTRICT
+TRUNCATE tru_pk_ftable CASCADE;
+SELECT count(*) FROM tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_fk_table; -- also truncated,0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate two tables at a command
+INSERT INTO tru_ftable (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_pk_ftable (SELECT x FROM generate_series(3,10) x);
+SELECT count(*) from tru_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+TRUNCATE tru_ftable, tru_pk_ftable CASCADE;
+SELECT count(*) from tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate with ONLY clause
+-- Since ONLY is specified, the table tru_ftable_child that inherits
+-- tru_ftable_parent locally is not truncated.
+TRUNCATE ONLY tru_ftable_parent;
+SELECT sum(id) FROM tru_ftable_parent; -- 126
+ sum
+-----
+ 126
+(1 row)
+
+TRUNCATE tru_ftable_parent;
+SELECT count(*) FROM tru_ftable_parent; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- in case when remote table has inherited children
+CREATE TABLE tru_rtable0_child () INHERITS (tru_rtable0);
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(5,9) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(10,14) x);
+SELECT sum(id) FROM tru_ftable; -- 95
+ sum
+-----
+ 95
+(1 row)
+
+-- Both parent and child tables in the foreign server are truncated
+-- even though ONLY is specified because ONLY has no effect
+-- when truncating a foreign table.
+TRUNCATE ONLY tru_ftable;
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(21,25) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(26,30) x);
+SELECT sum(id) FROM tru_ftable; -- 255
+ sum
+-----
+ 255
+(1 row)
+
+TRUNCATE tru_ftable; -- truncate both of parent and child
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- cleanup
+DROP FOREIGN TABLE tru_ftable_parent, tru_ftable_child, tru_pk_ftable,tru_ftable__p1,tru_ftable;
+DROP TABLE tru_rtable0, tru_rtable1, tru_ptable, tru_ptable__p0, tru_pk_table, tru_fk_table,
+tru_rtable_parent,tru_rtable_child, tru_rtable0_child;
+-- ===================================================================
+-- test IMPORT FOREIGN SCHEMA
+-- ===================================================================
+CREATE SCHEMA import_source;
+CREATE TABLE import_source.t1 (c1 int, c2 varchar NOT NULL);
+CREATE TABLE import_source.t2 (c1 int default 42, c2 varchar NULL, c3 text collate "POSIX");
+CREATE TYPE typ1 AS (m1 int, m2 varchar);
+CREATE TABLE import_source.t3 (c1 timestamptz default now(), c2 typ1);
+CREATE TABLE import_source."x 4" (c1 float8, "C 2" text, c3 varchar(42));
+CREATE TABLE import_source."x 5" (c1 float8);
+ALTER TABLE import_source."x 5" DROP COLUMN c1;
+CREATE TABLE import_source."x 6" (c1 int, c2 int generated always as (c1 * 2) stored);
+CREATE TABLE import_source.t4 (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE import_source.t4_part PARTITION OF import_source.t4
+ FOR VALUES FROM (1) TO (100);
+CREATE TABLE import_source.t4_part2 PARTITION OF import_source.t4
+ FOR VALUES FROM (100) TO (200);
+CREATE SCHEMA import_dest1;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest1;
+\det+ import_dest1.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest1 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest1 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest1 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest1 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest1 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest1 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest1 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest1.*
+ Foreign table "import_dest1.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest1.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest1.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest1.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest1.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest1.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest1.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Options
+CREATE SCHEMA import_dest2;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest2
+ OPTIONS (import_default 'true');
+\det+ import_dest2.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest2 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest2 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest2 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest2 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest2 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest2 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest2 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest2.*
+ Foreign table "import_dest2.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest2.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | 42 | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest2.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | now() | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest2.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest2.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest2.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest2.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+CREATE SCHEMA import_dest3;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest3
+ OPTIONS (import_collate 'false', import_generated 'false', import_not_null 'false');
+\det+ import_dest3.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest3 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest3 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest3 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest3 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest3 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest3 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest3 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest3.*
+ Foreign table "import_dest3.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest3.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest3.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest3.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest3.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest3.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest3.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Check LIMIT TO and EXCEPT
+CREATE SCHEMA import_dest4;
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t1, nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+(2 rows)
+
+IMPORT FOREIGN SCHEMA import_source EXCEPT (t1, "x 4", nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest4 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest4 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+ import_dest4 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest4 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+-- Assorted error cases
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest4;
+ERROR: relation "t1" already exists
+CONTEXT: importing foreign table "t1"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO import_dest4;
+ERROR: schema "nonesuch" is not present on foreign server "loopback"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO notthere;
+ERROR: schema "notthere" does not exist
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER nowhere INTO notthere;
+ERROR: server "nowhere" does not exist
+-- Check case of a type present only on the remote server.
+-- We can fake this by dropping the type locally in our transaction.
+CREATE TYPE "Colors" AS ENUM ('red', 'green', 'blue');
+CREATE TABLE import_source.t5 (c1 int, c2 text collate "C", "Col" "Colors");
+CREATE SCHEMA import_dest5;
+BEGIN;
+DROP TYPE "Colors" CASCADE;
+NOTICE: drop cascades to column Col of table import_source.t5
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t5)
+ FROM SERVER loopback INTO import_dest5; -- ERROR
+ERROR: type "public.Colors" does not exist
+LINE 4: "Col" public."Colors" OPTIONS (column_name 'Col')
+ ^
+QUERY: CREATE FOREIGN TABLE t5 (
+ c1 integer OPTIONS (column_name 'c1'),
+ c2 text OPTIONS (column_name 'c2') COLLATE pg_catalog."C",
+ "Col" public."Colors" OPTIONS (column_name 'Col')
+) SERVER loopback
+OPTIONS (schema_name 'import_source', table_name 't5');
+CONTEXT: importing foreign table "t5"
+ROLLBACK;
+BEGIN;
+CREATE SERVER fetch101 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( fetch_size '101' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER fetch101 OPTIONS( SET fetch_size '202' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=202'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30000 ( x int ) SERVER fetch101 OPTIONS ( fetch_size '30000' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '60000');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=60000'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- ===================================================================
+-- test partitionwise joins
+-- ===================================================================
+SET enable_partitionwise_join=on;
+CREATE TABLE fprt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE fprt1_p1 (LIKE fprt1);
+CREATE TABLE fprt1_p2 (LIKE fprt1);
+ALTER TABLE fprt1_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt1_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt1_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 2) i;
+INSERT INTO fprt1_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 2) i;
+CREATE FOREIGN TABLE ftprt1_p1 PARTITION OF fprt1 FOR VALUES FROM (0) TO (250)
+ SERVER loopback OPTIONS (table_name 'fprt1_p1', use_remote_estimate 'true');
+CREATE FOREIGN TABLE ftprt1_p2 PARTITION OF fprt1 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (TABLE_NAME 'fprt1_p2');
+ANALYZE fprt1;
+ANALYZE fprt1_p1;
+ANALYZE fprt1_p2;
+CREATE TABLE fprt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE fprt2_p1 (LIKE fprt2);
+CREATE TABLE fprt2_p2 (LIKE fprt2);
+ALTER TABLE fprt2_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt2_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt2_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 3) i;
+INSERT INTO fprt2_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 3) i;
+CREATE FOREIGN TABLE ftprt2_p1 (b int, c varchar, a int)
+ SERVER loopback OPTIONS (table_name 'fprt2_p1', use_remote_estimate 'true');
+ALTER TABLE fprt2 ATTACH PARTITION ftprt2_p1 FOR VALUES FROM (0) TO (250);
+CREATE FOREIGN TABLE ftprt2_p2 PARTITION OF fprt2 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (table_name 'fprt2_p2', use_remote_estimate 'true');
+ANALYZE fprt2;
+ANALYZE fprt2_p1;
+ANALYZE fprt2_p2;
+-- inner join three tables
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t3.c
+ -> Append
+ -> Foreign Scan
+ Relations: ((ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)) INNER JOIN (ftprt1_p1 t3_1)
+ -> Foreign Scan
+ Relations: ((ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)) INNER JOIN (ftprt1_p2 t3_2)
+(7 rows)
+
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0003
+ 250 | 250 | 0005
+ 400 | 400 | 0008
+(4 rows)
+
+-- left outer join + nullable clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.a, fprt2.b, fprt2.c
+ Relations: (public.ftprt1_p1 t1) LEFT JOIN (public.ftprt2_p1 fprt2)
+ Remote SQL: SELECT r5.a, r6.b, r6.c FROM (public.fprt1_p1 r5 LEFT JOIN public.fprt2_p1 r6 ON (((r5.a = r6.b)) AND ((r5.b = r6.a)) AND ((r6.a < 10)))) WHERE ((r5.a < 10)) ORDER BY r5.a ASC NULLS LAST, r6.b ASC NULLS LAST, r6.c ASC NULLS LAST
+(4 rows)
+
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ a | b | c
+---+---+------
+ 0 | 0 | 0000
+ 2 | |
+ 4 | |
+ 6 | 6 | 0000
+ 8 | |
+(5 rows)
+
+-- with whole-row reference; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ QUERY PLAN
+--------------------------------------------------------
+ Sort
+ Sort Key: ((t1.*)::fprt1), ((t2.*)::fprt2)
+ -> Hash Full Join
+ Hash Cond: (t1.a = t2.b)
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+(11 rows)
+
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ wr | wr
+----------------+----------------
+ (0,0,0000) | (0,0,0000)
+ (50,50,0001) |
+ (100,100,0002) |
+ (150,150,0003) | (150,150,0003)
+ (200,200,0004) |
+ (250,250,0005) | (250,250,0005)
+ (300,300,0006) |
+ (350,350,0007) |
+ (400,400,0008) | (400,400,0008)
+ (450,450,0009) |
+ | (75,75,0001)
+ | (225,225,0004)
+ | (325,325,0006)
+ | (475,475,0009)
+(14 rows)
+
+-- join with lateral reference
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t1.b
+ -> Append
+ -> Foreign Scan
+ Relations: (ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)
+ -> Foreign Scan
+ Relations: (ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)
+(7 rows)
+
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+-- with PHVs, partitionwise join selected but no join pushdown
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: fprt1.a, fprt2.b
+ -> Append
+ -> Hash Full Join
+ Hash Cond: (fprt1_1.a = fprt2_1.b)
+ -> Foreign Scan on ftprt1_p1 fprt1_1
+ -> Hash
+ -> Foreign Scan on ftprt2_p1 fprt2_1
+ -> Hash Full Join
+ Hash Cond: (fprt1_2.a = fprt2_2.b)
+ -> Foreign Scan on ftprt1_p2 fprt1_2
+ -> Hash
+ -> Foreign Scan on ftprt2_p2 fprt2_2
+(13 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | phv | b | phv
+-----+--------+-----+--------
+ 0 | t1_phv | 0 | t2_phv
+ 50 | t1_phv | |
+ 100 | t1_phv | |
+ 150 | t1_phv | 150 | t2_phv
+ 200 | t1_phv | |
+ 250 | t1_phv | 250 | t2_phv
+ 300 | t1_phv | |
+ 350 | t1_phv | |
+ 400 | t1_phv | 400 | t2_phv
+ 450 | t1_phv | |
+ | | 75 | t2_phv
+ | | 225 | t2_phv
+ | | 325 | t2_phv
+ | | 475 | t2_phv
+(14 rows)
+
+-- test FOR UPDATE; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ QUERY PLAN
+--------------------------------------------------------------
+ LockRows
+ -> Sort
+ Sort Key: t1.a
+ -> Hash Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+(12 rows)
+
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+RESET enable_partitionwise_join;
+-- ===================================================================
+-- test partitionwise aggregates
+-- ===================================================================
+CREATE TABLE pagg_tab (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE pagg_tab_p1 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p2 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p3 (LIKE pagg_tab);
+INSERT INTO pagg_tab_p1 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 10;
+INSERT INTO pagg_tab_p2 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 20 and (i % 30) >= 10;
+INSERT INTO pagg_tab_p3 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 30 and (i % 30) >= 20;
+-- Create foreign partitions
+CREATE FOREIGN TABLE fpagg_tab_p1 PARTITION OF pagg_tab FOR VALUES FROM (0) TO (10) SERVER loopback OPTIONS (table_name 'pagg_tab_p1');
+CREATE FOREIGN TABLE fpagg_tab_p2 PARTITION OF pagg_tab FOR VALUES FROM (10) TO (20) SERVER loopback OPTIONS (table_name 'pagg_tab_p2');
+CREATE FOREIGN TABLE fpagg_tab_p3 PARTITION OF pagg_tab FOR VALUES FROM (20) TO (30) SERVER loopback OPTIONS (table_name 'pagg_tab_p3');
+ANALYZE pagg_tab;
+ANALYZE fpagg_tab_p1;
+ANALYZE fpagg_tab_p2;
+ANALYZE fpagg_tab_p3;
+-- When GROUP BY clause matches with PARTITION KEY.
+-- Plan with partitionwise aggregates is disabled
+SET enable_partitionwise_aggregate TO false;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> HashAggregate
+ Group Key: pagg_tab.a
+ Filter: (avg(pagg_tab.b) < '22'::numeric)
+ -> Append
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab_1
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_2
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_3
+(9 rows)
+
+-- Plan with partitionwise aggregates is enabled
+SET enable_partitionwise_aggregate TO true;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> Append
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p1 pagg_tab)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p2 pagg_tab_1)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p3 pagg_tab_2)
+(9 rows)
+
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | sum | min | count
+----+------+-----+-------
+ 0 | 2000 | 0 | 100
+ 1 | 2100 | 1 | 100
+ 10 | 2000 | 0 | 100
+ 11 | 2100 | 1 | 100
+ 20 | 2000 | 0 | 100
+ 21 | 2100 | 1 | 100
+(6 rows)
+
+-- Check with whole-row reference
+-- Should have all the columns in the target list for the given relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, (count(((t1.*)::pagg_tab)))
+ Sort Key: t1.a
+ -> Append
+ -> HashAggregate
+ Output: t1.a, count(((t1.*)::pagg_tab))
+ Group Key: t1.a
+ Filter: (avg(t1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p1 t1
+ Output: t1.a, t1.*, t1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p1
+ -> HashAggregate
+ Output: t1_1.a, count(((t1_1.*)::pagg_tab))
+ Group Key: t1_1.a
+ Filter: (avg(t1_1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p2 t1_1
+ Output: t1_1.a, t1_1.*, t1_1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p2
+ -> HashAggregate
+ Output: t1_2.a, count(((t1_2.*)::pagg_tab))
+ Group Key: t1_2.a
+ Filter: (avg(t1_2.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p3 t1_2
+ Output: t1_2.a, t1_2.*, t1_2.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p3
+(25 rows)
+
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | count
+----+-------
+ 0 | 100
+ 1 | 100
+ 10 | 100
+ 11 | 100
+ 20 | 100
+ 21 | 100
+(6 rows)
+
+-- When GROUP BY clause does not match with PARTITION KEY.
+EXPLAIN (COSTS OFF)
+SELECT b, avg(a), max(a), count(*) FROM pagg_tab GROUP BY b HAVING sum(a) < 700 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.b
+ -> Finalize HashAggregate
+ Group Key: pagg_tab.b
+ Filter: (sum(pagg_tab.a) < 700)
+ -> Append
+ -> Partial HashAggregate
+ Group Key: pagg_tab.b
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab
+ -> Partial HashAggregate
+ Group Key: pagg_tab_1.b
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_1
+ -> Partial HashAggregate
+ Group Key: pagg_tab_2.b
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_2
+(15 rows)
+
+-- ===================================================================
+-- access rights and superuser
+-- ===================================================================
+-- Non-superuser cannot create a FDW without a password in the connstr
+CREATE ROLE regress_nosuper NOSUPERUSER;
+GRANT USAGE ON FOREIGN DATA WRAPPER postgres_fdw TO regress_nosuper;
+SET ROLE regress_nosuper;
+SHOW is_superuser;
+ is_superuser
+--------------
+ off
+(1 row)
+
+-- This will be OK, we can create the FDW
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback_nopw FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+-- But creation of user mappings for non-superusers should fail
+CREATE USER MAPPING FOR public SERVER loopback_nopw;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+CREATE FOREIGN TABLE pg_temp.ft1_nopw (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback_nopw OPTIONS (schema_name 'public', table_name 'ft1');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+-- If we add a password to the connstr it'll fail, because we don't allow passwords
+-- in connstrs only in user mappings.
+ALTER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+ERROR: invalid option "password"
+HINT: Perhaps you meant the option "passfile".
+-- If we add a password for our user mapping instead, we should get a different
+-- error because the password wasn't actually *used* when we run with trust auth.
+--
+-- This won't work with installcheck, but neither will most of the FDW checks.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+-- Unpriv user cannot make the mapping passwordless
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+ERROR: password_required=false is superuser-only
+HINT: User mappings with the password_required option set to false may only be created or modified by the superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+RESET ROLE;
+-- But the superuser can
+ALTER USER MAPPING FOR regress_nosuper SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+SET ROLE regress_nosuper;
+-- Should finally work now
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- unpriv user also cannot set sslcert / sslkey on the user mapping
+-- first set password_required so we see the right error messages
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (SET password_required 'true');
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslcert 'foo.crt');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslkey 'foo.key');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+-- We're done with the role named after a specific user and need to check the
+-- changes to the public mapping.
+DROP USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+-- This will fail again as it'll resolve the user mapping for public, which
+-- lacks password_required=false
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+RESET ROLE;
+-- The user mapping for public is passwordless and lacks the password_required=false
+-- mapping option, but will work because the current user is a superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- cleanup
+DROP USER MAPPING FOR public SERVER loopback_nopw;
+DROP OWNED BY regress_nosuper;
+DROP ROLE regress_nosuper;
+-- Clean-up
+RESET enable_partitionwise_aggregate;
+-- Two-phase transactions are not supported.
+BEGIN;
+SELECT count(*) FROM ft1;
+ count
+-------
+ 822
+(1 row)
+
+-- error here
+PREPARE TRANSACTION 'fdw_tpc';
+ERROR: cannot PREPARE a transaction that has operated on postgres_fdw foreign tables
+ROLLBACK;
+WARNING: there is no transaction in progress
+-- ===================================================================
+-- reestablish new connection
+-- ===================================================================
+-- Change application_name of remote connection to special one
+-- so that we can easily terminate the connection later.
+ALTER SERVER loopback OPTIONS (application_name 'fdw_retry_check');
+-- If debug_discard_caches is active, it results in
+-- dropping remote connections after every transaction, making it
+-- impossible to test termination meaningfully. So turn that off
+-- for this test.
+SET debug_discard_caches = 0;
+-- Make sure we have a remote connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- This query should detect the broken connection when starting new remote
+-- transaction, reestablish new connection, and then succeed.
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- If we detect the broken connection when starting a new remote
+-- subtransaction, we should fail instead of establishing a new connection.
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+SAVEPOINT s;
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT 1 FROM ft1 LIMIT 1; -- should fail
+ERROR: 08006
+\set VERBOSITY default
+COMMIT;
+RESET debug_discard_caches;
+-- =============================================================================
+-- test connection invalidation cases and postgres_fdw_get_connections function
+-- =============================================================================
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- This test case is for closing the connection in pgfdw_xact_callback
+BEGIN;
+-- Connection xact depth becomes 1 i.e. the connection is in midst of the xact.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT 1 FROM ft7 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback3 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback3
+(2 rows)
+
+-- Connections are not closed at the end of the alter and drop statements.
+-- That's because the connections are in midst of this xact,
+-- they are just marked as invalid in pgfdw_inval_callback.
+ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
+DROP SERVER loopback3 CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to user mapping for public on server loopback3
+drop cascades to foreign table ft7
+-- List all the existing cached connections. loopback and loopback3
+-- should be output as invalid connections. Also the server name for
+-- loopback3 should be NULL because the server was dropped.
+SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | valid
+-------------+-------
+ loopback | f
+ | f
+(2 rows)
+
+-- The invalid connections get closed in pgfdw_xact_callback during commit.
+COMMIT;
+-- All cached connections were closed while committing above xact, so no
+-- records should be output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+(0 rows)
+
+-- =======================================================================
+-- test postgres_fdw_disconnect and postgres_fdw_disconnect_all functions
+-- =======================================================================
+BEGIN;
+-- Ensure to cache loopback connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Ensure to cache loopback2 connection.
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Issue a warning and return false as loopback connection is still in use and
+-- can not be closed.
+SELECT postgres_fdw_disconnect('loopback');
+WARNING: cannot close connection for server "loopback" because it is still in use
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Return false as connections are still in use, warnings are issued.
+-- But disable warnings temporarily because the order of them is not stable.
+SET client_min_messages = 'ERROR';
+SELECT postgres_fdw_disconnect_all();
+ postgres_fdw_disconnect_all
+-----------------------------
+ f
+(1 row)
+
+RESET client_min_messages;
+COMMIT;
+-- Ensure that loopback2 connection is closed.
+SELECT 1 FROM postgres_fdw_disconnect('loopback2');
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT server_name FROM postgres_fdw_get_connections() WHERE server_name = 'loopback2';
+ server_name
+-------------
+(0 rows)
+
+-- Return false as loopback2 connection is closed already.
+SELECT postgres_fdw_disconnect('loopback2');
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- Return an error as there is no foreign server with given name.
+SELECT postgres_fdw_disconnect('unknownserver');
+ERROR: server "unknownserver" does not exist
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- =============================================================================
+-- test case for having multiple cached connections for a foreign server
+-- =============================================================================
+CREATE ROLE regress_multi_conn_user1 SUPERUSER;
+CREATE ROLE regress_multi_conn_user2 SUPERUSER;
+CREATE USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+CREATE USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+BEGIN;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user1
+SET ROLE regress_multi_conn_user1;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user2
+SET ROLE regress_multi_conn_user2;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Should output two connections for loopback server
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback
+(2 rows)
+
+COMMIT;
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- Clean up
+DROP USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+DROP USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+DROP ROLE regress_multi_conn_user1;
+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
+-- ===================================================================
+BEGIN;
+CREATE SERVER batch10 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( batch_size '10' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER batch10 OPTIONS( SET batch_size '20' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=20'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30 ( x int ) SERVER batch10 OPTIONS ( batch_size '30' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30 OPTIONS ( SET batch_size '40');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=40'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+CREATE TABLE batch_table ( x int );
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '10' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 10
+ -> Function Scan on pg_catalog.generate_series i
+ Output: i.i
+ Function Call: generate_series(1, 10)
+(6 rows)
+
+INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+INSERT INTO ftable SELECT * FROM generate_series(11, 31) i;
+INSERT INTO ftable VALUES (32);
+INSERT INTO ftable VALUES (33), (34);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 34
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- try if large batches exceed max number of bind parameters
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '100000' );
+INSERT INTO ftable SELECT * FROM generate_series(1, 70000) i;
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 70000
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- Disable batch insert
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '1' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (1), (2);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 2
+(1 row)
+
+-- Disable batch inserting into foreign tables with BEFORE ROW INSERT triggers
+-- even if the batch_size option is enabled.
+ALTER FOREIGN TABLE ftable OPTIONS ( SET batch_size '10' );
+CREATE TRIGGER trig_row_before BEFORE INSERT ON ftable
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (3), (4);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (3), (4);
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (3)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (4)
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 4
+(1 row)
+
+-- Clean up
+DROP TRIGGER trig_row_before ON ftable;
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+-- Use partitioning
+CREATE TABLE batch_table ( x int ) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0', batch_size '10');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1', batch_size '1');
+CREATE TABLE batch_table_p2
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 2);
+INSERT INTO batch_table SELECT * FROM generate_series(1, 66) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 66
+(1 row)
+
+-- Check that enabling batched inserts doesn't interfere with cross-partition
+-- updates
+CREATE TABLE batch_cp_upd_test (a int) PARTITION BY LIST (a);
+CREATE TABLE batch_cp_upd_test1 (LIKE batch_cp_upd_test);
+CREATE FOREIGN TABLE batch_cp_upd_test1_f
+ PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_cp_upd_test1', batch_size '10');
+CREATE TABLE batch_cp_up_test1 PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (2);
+INSERT INTO batch_cp_upd_test VALUES (1), (2);
+-- The following moves a row from the local partition to the foreign one
+UPDATE batch_cp_upd_test t SET a = 1 FROM (VALUES (1), (2)) s(a) WHERE t.a = s.a;
+ERROR: cannot route tuples into foreign table to be updated "batch_cp_upd_test1_f"
+SELECT tableoid::regclass, * FROM batch_cp_upd_test;
+ tableoid | a
+----------------------+---
+ batch_cp_upd_test1_f | 1
+ batch_cp_up_test1 | 2
+(2 rows)
+
+-- Clean up
+DROP TABLE batch_table, batch_cp_upd_test, batch_table_p0, batch_table_p1 CASCADE;
+-- Use partitioning
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+CREATE TABLE batch_table ( x int, field1 text, field2 text) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+ALTER TABLE batch_table_p0 ADD CONSTRAINT p0_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+ALTER TABLE batch_table_p1 ADD CONSTRAINT p1_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1');
+INSERT INTO batch_table SELECT i, 'test'||i, 'test'|| i FROM generate_series(1, 50) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 50
+(1 row)
+
+SELECT * FROM batch_table ORDER BY x;
+ x | field1 | field2
+----+--------+--------
+ 1 | test1 | test1
+ 2 | test2 | test2
+ 3 | test3 | test3
+ 4 | test4 | test4
+ 5 | test5 | test5
+ 6 | test6 | test6
+ 7 | test7 | test7
+ 8 | test8 | test8
+ 9 | test9 | test9
+ 10 | test10 | test10
+ 11 | test11 | test11
+ 12 | test12 | test12
+ 13 | test13 | test13
+ 14 | test14 | test14
+ 15 | test15 | test15
+ 16 | test16 | test16
+ 17 | test17 | test17
+ 18 | test18 | test18
+ 19 | test19 | test19
+ 20 | test20 | test20
+ 21 | test21 | test21
+ 22 | test22 | test22
+ 23 | test23 | test23
+ 24 | test24 | test24
+ 25 | test25 | test25
+ 26 | test26 | test26
+ 27 | test27 | test27
+ 28 | test28 | test28
+ 29 | test29 | test29
+ 30 | test30 | test30
+ 31 | test31 | test31
+ 32 | test32 | test32
+ 33 | test33 | test33
+ 34 | test34 | test34
+ 35 | test35 | test35
+ 36 | test36 | test36
+ 37 | test37 | test37
+ 38 | test38 | test38
+ 39 | test39 | test39
+ 40 | test40 | test40
+ 41 | test41 | test41
+ 42 | test42 | test42
+ 43 | test43 | test43
+ 44 | test44 | test44
+ 45 | test45 | test45
+ 46 | test46 | test46
+ 47 | test47 | test47
+ 48 | test48 | test48
+ 49 | test49 | test49
+ 50 | test50 | test50
+(50 rows)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+-- ===================================================================
+-- test asynchronous execution
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD async_capable 'true');
+ALTER SERVER loopback2 OPTIONS (ADD async_capable 'true');
+CREATE TABLE async_pt (a int, b int, c text) PARTITION BY RANGE (a);
+CREATE TABLE base_tbl1 (a int, b int, c text);
+CREATE TABLE base_tbl2 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p1 PARTITION OF async_pt FOR VALUES FROM (1000) TO (2000)
+ SERVER loopback OPTIONS (table_name 'base_tbl1');
+CREATE FOREIGN TABLE async_p2 PARTITION OF async_pt FOR VALUES FROM (2000) TO (3000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl2');
+INSERT INTO async_p1 SELECT 1000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+INSERT INTO async_p2 SELECT 2000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+-- simple queries
+CREATE TABLE result_tbl (a int, b int, c text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE (((b % 100) = 0))
+(8 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1000 | 0 | 0000
+ 1100 | 100 | 0100
+ 1200 | 200 | 0200
+ 1300 | 300 | 0300
+ 1400 | 400 | 0400
+ 1500 | 500 | 0500
+ 1600 | 600 | 0600
+ 1700 | 700 | 0700
+ 1800 | 800 | 0800
+ 1900 | 900 | 0900
+ 2000 | 0 | 0000
+ 2100 | 100 | 0100
+ 2200 | 200 | 0200
+ 2300 | 300 | 0300
+ 2400 | 400 | 0400
+ 2500 | 500 | 0500
+ 2600 | 600 | 0600
+ 2700 | 700 | 0700
+ 2800 | 800 | 0800
+ 2900 | 900 | 0900
+(20 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, ('AAA'::text || async_pt_1.c)
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, ('AAA'::text || async_pt_2.c)
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+---------
+ 1505 | 505 | AAA0505
+ 2505 | 505 | AAA0505
+(2 rows)
+
+DELETE FROM result_tbl;
+-- Check case where multiple partitions use the same connection
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl3');
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Async Foreign Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(14 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+DROP FOREIGN TABLE async_p3;
+DROP TABLE base_tbl3;
+-- Check case where the partitioned table has local/remote partitions
+CREATE TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000);
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+(13 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+-- partitionwise joins
+SET enable_partitionwise_join TO true;
+CREATE TABLE join_tbl (a1 int, b1 int, c1 text, a2 int, b2 int, c2 text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t2_1.b, t2_1.c
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t2_2.b, t2_2.c
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, t1_3.c, t2_3.a, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+ 2000 | 0 | 0000 | 2000 | 0 | 0000
+ 2100 | 100 | 0100 | 2100 | 100 | 0100
+ 2200 | 200 | 0200 | 2200 | 200 | 0200
+ 2300 | 300 | 0300 | 2300 | 300 | 0300
+ 2400 | 400 | 0400 | 2400 | 400 | 0400
+ 2500 | 500 | 0500 | 2500 | 500 | 0500
+ 2600 | 600 | 0600 | 2600 | 600 | 0600
+ 2700 | 700 | 0700 | 2700 | 700 | 0700
+ 2800 | 800 | 0800 | 2800 | 800 | 0800
+ 2900 | 900 | 0900 | 2900 | 900 | 0900
+ 3000 | 0 | 0000 | 3000 | 0 | 0000
+ 3100 | 100 | 0100 | 3100 | 100 | 0100
+ 3200 | 200 | 0200 | 3200 | 200 | 0200
+ 3300 | 300 | 0300 | 3300 | 300 | 0300
+ 3400 | 400 | 0400 | 3400 | 400 | 0400
+ 3500 | 500 | 0500 | 3500 | 500 | 0500
+ 3600 | 600 | 0600 | 3600 | 600 | 0600
+ 3700 | 700 | 0700 | 3700 | 700 | 0700
+ 3800 | 800 | 0800 | 3800 | 800 | 0800
+ 3900 | 900 | 0900 | 3900 | 900 | 0900
+(30 rows)
+
+DELETE FROM join_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, ('AAA'::text || t1_1.c), t2_1.a, t2_1.b, ('AAA'::text || t2_1.c)
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, ('AAA'::text || t1_2.c), t2_2.a, t2_2.b, ('AAA'::text || t2_2.c)
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, ('AAA'::text || t1_3.c), t2_3.a, t2_3.b, ('AAA'::text || t2_3.c)
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+---------+------+-----+---------
+ 1000 | 0 | AAA0000 | 1000 | 0 | AAA0000
+ 1100 | 100 | AAA0100 | 1100 | 100 | AAA0100
+ 1200 | 200 | AAA0200 | 1200 | 200 | AAA0200
+ 1300 | 300 | AAA0300 | 1300 | 300 | AAA0300
+ 1400 | 400 | AAA0400 | 1400 | 400 | AAA0400
+ 1500 | 500 | AAA0500 | 1500 | 500 | AAA0500
+ 1600 | 600 | AAA0600 | 1600 | 600 | AAA0600
+ 1700 | 700 | AAA0700 | 1700 | 700 | AAA0700
+ 1800 | 800 | AAA0800 | 1800 | 800 | AAA0800
+ 1900 | 900 | AAA0900 | 1900 | 900 | AAA0900
+ 2000 | 0 | AAA0000 | 2000 | 0 | AAA0000
+ 2100 | 100 | AAA0100 | 2100 | 100 | AAA0100
+ 2200 | 200 | AAA0200 | 2200 | 200 | AAA0200
+ 2300 | 300 | AAA0300 | 2300 | 300 | AAA0300
+ 2400 | 400 | AAA0400 | 2400 | 400 | AAA0400
+ 2500 | 500 | AAA0500 | 2500 | 500 | AAA0500
+ 2600 | 600 | AAA0600 | 2600 | 600 | AAA0600
+ 2700 | 700 | AAA0700 | 2700 | 700 | AAA0700
+ 2800 | 800 | AAA0800 | 2800 | 800 | AAA0800
+ 2900 | 900 | AAA0900 | 2900 | 900 | AAA0900
+ 3000 | 0 | AAA0000 | 3000 | 0 | AAA0000
+ 3100 | 100 | AAA0100 | 3100 | 100 | AAA0100
+ 3200 | 200 | AAA0200 | 3200 | 200 | AAA0200
+ 3300 | 300 | AAA0300 | 3300 | 300 | AAA0300
+ 3400 | 400 | AAA0400 | 3400 | 400 | AAA0400
+ 3500 | 500 | AAA0500 | 3500 | 500 | AAA0500
+ 3600 | 600 | AAA0600 | 3600 | 600 | AAA0600
+ 3700 | 700 | AAA0700 | 3700 | 700 | AAA0700
+ 3800 | 800 | AAA0800 | 3800 | 800 | AAA0800
+ 3900 | 900 | AAA0900 | 3900 | 900 | AAA0900
+(30 rows)
+
+DELETE FROM join_tbl;
+RESET enable_partitionwise_join;
+-- Test rescan of an async Append node with do_exec_prune=false
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: ((t1.a = t2.a) AND (t1.b = t2.b))
+ -> Foreign Scan on public.async_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t2_1
+ Output: t2_1.a, t2_1.b, t2_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t2_2
+ Output: t2_2.a, t2_2.b, t2_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+(16 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+(10 rows)
+
+DELETE FROM join_tbl;
+RESET enable_hashjoin;
+-- Test interaction of async execution with plan-time partition pruning
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 3000;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(7 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 2000;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Foreign Scan on public.async_p1 async_pt
+ Output: async_pt.a, async_pt.b, async_pt.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 2000))
+(3 rows)
+
+-- Test interaction of async execution with run-time partition pruning
+SET plan_cache_mode TO force_generic_plan;
+PREPARE async_pt_query (int, int) AS
+ INSERT INTO result_tbl SELECT * FROM async_pt WHERE a < $1 AND b === $2;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (3000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 1
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < $1::integer))
+(11 rows)
+
+EXECUTE async_pt_query (3000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (2000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 2
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+(7 rows)
+
+EXECUTE async_pt_query (2000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+(1 row)
+
+DELETE FROM result_tbl;
+RESET plan_cache_mode;
+CREATE TABLE local_tbl(a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo'), (2505, 505, 'bar');
+ANALYZE local_tbl;
+CREATE INDEX base_tbl1_idx ON base_tbl1 (a);
+CREATE INDEX base_tbl2_idx ON base_tbl2 (a);
+CREATE INDEX async_p3_idx ON async_p3 (a);
+ANALYZE base_tbl1;
+ANALYZE base_tbl2;
+ANALYZE async_p3;
+ALTER FOREIGN TABLE async_p1 OPTIONS (use_remote_estimate 'true');
+ALTER FOREIGN TABLE async_p2 OPTIONS (use_remote_estimate 'true');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: local_tbl.a, local_tbl.b, local_tbl.c, async_pt.a, async_pt.b, async_pt.c
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ Filter: (local_tbl.c = 'bar'::text)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (($1::integer = a))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE (($1::integer = a))
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (local_tbl.a = async_pt_3.a)
+(15 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Nested Loop (actual rows=1 loops=1)
+ -> Seq Scan on local_tbl (actual rows=1 loops=1)
+ Filter: (c = 'bar'::text)
+ Rows Removed by Filter: 1
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (never executed)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=1 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (never executed)
+ Filter: (local_tbl.a = a)
+(9 rows)
+
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ a | b | c | a | b | c
+------+-----+-----+------+-----+------
+ 2505 | 505 | bar | 2505 | 505 | 0505
+(1 row)
+
+ALTER FOREIGN TABLE async_p1 OPTIONS (DROP use_remote_estimate);
+ALTER FOREIGN TABLE async_p2 OPTIONS (DROP use_remote_estimate);
+DROP TABLE local_tbl;
+DROP INDEX base_tbl1_idx;
+DROP INDEX base_tbl2_idx;
+DROP INDEX async_p3_idx;
+-- UNION queries
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> HashAggregate
+ Output: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ Group Key: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(11 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(8 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+-- Disable async execution if we use gating Result nodes for pseudoconstant
+-- quals
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Result
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+(18 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+(SELECT * FROM async_p1 WHERE CURRENT_USER = SESSION_USER)
+UNION ALL
+(SELECT * FROM async_p2 WHERE CURRENT_USER = SESSION_USER);
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(13 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ((SELECT * FROM async_p1 WHERE b < 10) UNION ALL (SELECT * FROM async_p2 WHERE b < 10)) s WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((b < 10))
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(13 rows)
+
+-- Test that pending requests are processed properly
+SET enable_mergejoin TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: (t1.a = t2.a)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+ -> Materialize
+ Output: t2.a, t2.b, t2.c
+ -> Foreign Scan on public.async_p2 t2
+ Output: t2.a, t2.b, t2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(20 rows)
+
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ a | b | c | a | b | c
+------+-----+------+------+-----+------
+ 2505 | 505 | 0505 | 2505 | 505 | 0505
+(1 row)
+
+CREATE TABLE local_tbl (a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo');
+ANALYZE local_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, async_pt.a, async_pt.b, async_pt.c, ($0)
+ Join Filter: (t1.a = async_pt.a)
+ InitPlan 1 (returns $0)
+ -> Aggregate
+ Output: count(*)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_4
+ Remote SQL: SELECT NULL FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_5
+ Remote SQL: SELECT NULL FROM public.base_tbl2 WHERE ((a < 3000))
+ -> Seq Scan on public.local_tbl t1
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(20 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Nested Loop Left Join (actual rows=1 loops=1)
+ Join Filter: (t1.a = async_pt.a)
+ Rows Removed by Join Filter: 399
+ InitPlan 1 (returns $0)
+ -> Aggregate (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_4 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_5 (actual rows=200 loops=1)
+ -> Seq Scan on local_tbl t1 (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=200 loops=1)
+(12 rows)
+
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ a | b | c | a | b | c | count
+------+-----+-----+------+-----+------+-------
+ 1505 | 505 | foo | 1505 | 505 | 0505 | 400
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+----------------------------------------------------------------
+ Limit
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+(14 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit (actual rows=1 loops=1)
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 t1_1 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Async Foreign Scan on async_p2 t1_2 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Seq Scan on async_p3 t1_3 (actual rows=1 loops=1)
+ Filter: (b === 505)
+ Rows Removed by Filter: 101
+(9 rows)
+
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ a | b | c
+------+-----+------
+ 3505 | 505 | 0505
+(1 row)
+
+-- Check with foreign modify
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE remote_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl3');
+INSERT INTO remote_tbl VALUES (2505, 505, 'bar');
+CREATE TABLE base_tbl4 (a int, b int, c text);
+CREATE FOREIGN TABLE insert_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl4');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Insert on public.insert_tbl
+ Remote SQL: INSERT INTO public.base_tbl4(a, b, c) VALUES ($1, $2, $3)
+ Batch Size: 1
+ -> Append
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ -> Async Foreign Scan on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(9 rows)
+
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+SELECT * FROM insert_tbl ORDER BY a;
+ a | b | c
+------+-----+-----
+ 1505 | 505 | foo
+ 2505 | 505 | bar
+(2 rows)
+
+-- Check with direct modify
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ CTE t
+ -> Update on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ -> Foreign Update on public.remote_tbl
+ Remote SQL: UPDATE public.base_tbl3 SET c = (c || c) RETURNING a, b, c
+ -> Nested Loop Left Join
+ Output: async_pt.a, async_pt.b, async_pt.c, t.a, t.b, t.c
+ Join Filter: ((async_pt.a = t.a) AND (async_pt.b = t.b))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ -> CTE Scan on t
+ Output: t.a, t.b, t.c
+(23 rows)
+
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+--------
+ 1505 | 505 | 0505 | | |
+ 2505 | 505 | 0505 | 2505 | 505 | barbar
+ 3505 | 505 | 0505 | | |
+(3 rows)
+
+DELETE FROM join_tbl;
+DROP TABLE local_tbl;
+DROP FOREIGN TABLE remote_tbl;
+DROP FOREIGN TABLE insert_tbl;
+DROP TABLE base_tbl3;
+DROP TABLE base_tbl4;
+RESET enable_mergejoin;
+RESET enable_hashjoin;
+-- Test that UPDATE/DELETE with inherited target works with async_capable enabled
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Update on public.async_p1 async_pt_1
+ Foreign Update on public.async_p2 async_pt_2
+ Update on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Update on public.async_p1 async_pt_1
+ Remote SQL: UPDATE public.base_tbl1 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Update on public.async_p2 async_pt_2
+ Remote SQL: UPDATE public.base_tbl2 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: (async_pt_3.c || async_pt_3.c), async_pt_3.tableoid, async_pt_3.ctid, NULL::record
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Delete on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Delete on public.async_p1 async_pt_1
+ Foreign Delete on public.async_p2 async_pt_2
+ Delete on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Delete on public.async_p1 async_pt_1
+ Remote SQL: DELETE FROM public.base_tbl1 WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Delete on public.async_p2 async_pt_2
+ Remote SQL: DELETE FROM public.base_tbl2 WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.tableoid, async_pt_3.ctid
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+-- Check EXPLAIN ANALYZE for a query that scans empty partitions asynchronously
+DELETE FROM async_p1;
+DELETE FROM async_p2;
+DELETE FROM async_p3;
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Append (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=0 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (actual rows=0 loops=1)
+(4 rows)
+
+-- Clean up
+DROP TABLE async_pt;
+DROP TABLE base_tbl1;
+DROP TABLE base_tbl2;
+DROP TABLE result_tbl;
+DROP TABLE join_tbl;
+-- Test that an asynchronous fetch is processed before restarting the scan in
+-- ReScanForeignScan
+CREATE TABLE base_tbl (a int, b int);
+INSERT INTO base_tbl VALUES (1, 11), (2, 22), (3, 33);
+CREATE FOREIGN TABLE foreign_tbl (b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE FOREIGN TABLE foreign_tbl2 () INHERITS (foreign_tbl)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Seq Scan on public.base_tbl
+ Output: base_tbl.a
+ Filter: (SubPlan 1)
+ SubPlan 1
+ -> Result
+ Output: base_tbl.a
+ -> Append
+ -> Async Foreign Scan on public.foreign_tbl foreign_tbl_1
+ Remote SQL: SELECT NULL FROM public.base_tbl
+ -> Async Foreign Scan on public.foreign_tbl2 foreign_tbl_2
+ Remote SQL: SELECT NULL FROM public.base_tbl
+(11 rows)
+
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ a
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+-- Clean up
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to foreign table foreign_tbl2
+DROP TABLE base_tbl;
+ALTER SERVER loopback OPTIONS (DROP async_capable);
+ALTER SERVER loopback2 OPTIONS (DROP async_capable);
+-- ===================================================================
+-- test invalid server, foreign table and foreign data wrapper options
+-- ===================================================================
+-- Invalid fdw_startup_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_startup_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_startup_cost": 100$%$#$#
+-- Invalid fdw_tuple_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_tuple_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_tuple_cost": 100$%$#$#
+-- Invalid fetch_size option
+CREATE FOREIGN TABLE inv_fsz (c1 int )
+ SERVER loopback OPTIONS (fetch_size '100$%$#$#');
+ERROR: invalid value for integer option "fetch_size": 100$%$#$#
+-- Invalid batch_size option
+CREATE FOREIGN TABLE inv_bsz (c1 int )
+ SERVER loopback OPTIONS (batch_size '100$%$#$#');
+ERROR: invalid value for integer option "batch_size": 100$%$#$#
+-- No option is allowed to be specified at foreign data wrapper level
+ALTER FOREIGN DATA WRAPPER postgres_fdw OPTIONS (nonexistent 'fdw');
+ERROR: invalid option "nonexistent"
+HINT: There are no valid options in this context.
+-- ===================================================================
+-- test postgres_fdw.application_name GUC
+-- ===================================================================
+--- Turn debug_discard_caches off for this test to make sure that
+--- the remote connection is alive when checking its application_name.
+SET debug_discard_caches = 0;
+-- Specify escape sequences in application_name option of a server
+-- object so as to test that they are replaced with status information
+-- expectedly.
+--
+-- Since pg_stat_activity.application_name may be truncated to less than
+-- NAMEDATALEN characters, note that substring() needs to be used
+-- at the condition of test query to make sure that the string consisting
+-- of database name and process ID is also less than that.
+ALTER SERVER loopback2 OPTIONS (application_name 'fdw_%d%p');
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_database() || pg_backend_pid() for
+ current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- postgres_fdw.application_name overrides application_name option
+-- of a server object if both settings are present.
+SET postgres_fdw.application_name TO 'fdw_%a%u%%';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('application_name') ||
+ CURRENT_USER || '%' for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- Test %c (session ID) and %C (cluster name) escape sequences.
+SET postgres_fdw.application_name TO 'fdw_%C%c';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('cluster_name') ||
+ to_hex(trunc(EXTRACT(EPOCH FROM (SELECT backend_start FROM
+ pg_stat_get_activity(pg_backend_pid()))))::integer) || '.' ||
+ to_hex(pg_backend_pid())
+ for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+--Clean up
+RESET postgres_fdw.application_name;
+RESET debug_discard_caches;
+-- ===================================================================
+-- test parallel commit
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (ADD parallel_commit 'true');
+ALTER SERVER loopback2 OPTIONS (ADD parallel_commit 'true');
+CREATE TABLE ploc1 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem1 (f1 int, f2 text)
+ SERVER loopback OPTIONS (table_name 'ploc1');
+CREATE TABLE ploc2 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem2 (f1 int, f2 text)
+ SERVER loopback2 OPTIONS (table_name 'ploc2');
+BEGIN;
+INSERT INTO prem1 VALUES (101, 'foo');
+INSERT INTO prem2 VALUES (201, 'bar');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+-----
+ 101 | foo
+(1 row)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+-----
+ 201 | bar
+(1 row)
+
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (102, 'foofoo');
+INSERT INTO prem2 VALUES (202, 'barbar');
+RELEASE SAVEPOINT s;
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+(2 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+(2 rows)
+
+-- This tests executing DEALLOCATE ALL against foreign servers in parallel
+-- during pre-commit
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (103, 'baz');
+INSERT INTO prem2 VALUES (203, 'qux');
+ROLLBACK TO SAVEPOINT s;
+RELEASE SAVEPOINT s;
+INSERT INTO prem1 VALUES (104, 'bazbaz');
+INSERT INTO prem2 VALUES (204, 'quxqux');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+ 104 | bazbaz
+(3 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+ 204 | quxqux
+(3 rows)
+
+ALTER SERVER loopback OPTIONS (DROP parallel_commit);
+ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for health-check feature
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Set GUC for checking the health of remote servers
+SET postgres_fdw.health_check_interval TO '1s';
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+-- FIXME: this should be skipped in some platforms
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- While sleeping the process down will be detected.
+SELECT pg_sleep(3);
+WARNING: FATAL: terminating connection due to administrator command
+server closed the connection unexpectedly
+ This probably means the server terminated abnormally
+ before or while processing the request.
+ERROR: Foreign Server "loopback" might be down.
+COMMIT;
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/expected/postgres_fdw_2.out b/contrib/postgres_fdw/expected/postgres_fdw_2.out
new file mode 100644
index 0000000000..d1d8191143
--- /dev/null
+++ b/contrib/postgres_fdw/expected/postgres_fdw_2.out
@@ -0,0 +1,11623 @@
+-- ===================================================================
+-- create FDW objects
+-- ===================================================================
+CREATE EXTENSION postgres_fdw;
+CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw;
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback2 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback3 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+CREATE USER MAPPING FOR public SERVER testserver1
+ OPTIONS (user 'value', password 'value');
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback2;
+CREATE USER MAPPING FOR public SERVER loopback3;
+-- ===================================================================
+-- create objects used through FDW loopback server
+-- ===================================================================
+CREATE TYPE user_enum AS ENUM ('foo', 'bar', 'buz');
+CREATE SCHEMA "S 1";
+CREATE TABLE "S 1"."T 1" (
+ "C 1" int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10),
+ c8 user_enum,
+ CONSTRAINT t1_pkey PRIMARY KEY ("C 1")
+);
+CREATE TABLE "S 1"."T 2" (
+ c1 int NOT NULL,
+ c2 text,
+ CONSTRAINT t2_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 3" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t3_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 4" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t4_pkey PRIMARY KEY (c1)
+);
+-- Disable autovacuum for these tables to avoid unexpected effects of that
+ALTER TABLE "S 1"."T 1" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 2" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 3" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 4" SET (autovacuum_enabled = 'false');
+INSERT INTO "S 1"."T 1"
+ SELECT id,
+ id % 10,
+ to_char(id, 'FM00000'),
+ '1970-01-01'::timestamptz + ((id % 100) || ' days')::interval,
+ '1970-01-01'::timestamp + ((id % 100) || ' days')::interval,
+ id % 10,
+ id % 10,
+ 'foo'::user_enum
+ FROM generate_series(1, 1000) id;
+INSERT INTO "S 1"."T 2"
+ SELECT id,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+INSERT INTO "S 1"."T 3"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 3" WHERE c1 % 2 != 0; -- delete for outer join tests
+INSERT INTO "S 1"."T 4"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests
+ANALYZE "S 1"."T 1";
+ANALYZE "S 1"."T 2";
+ANALYZE "S 1"."T 3";
+ANALYZE "S 1"."T 4";
+-- ===================================================================
+-- create foreign tables
+-- ===================================================================
+CREATE FOREIGN TABLE ft1 (
+ c0 int,
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft1 DROP COLUMN c0;
+CREATE FOREIGN TABLE ft2 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ cx int,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft2',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft2 DROP COLUMN cx;
+CREATE FOREIGN TABLE ft4 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 3');
+CREATE FOREIGN TABLE ft5 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft6 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback2 OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft7 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback3 OPTIONS (schema_name 'S 1', table_name 'T 4');
+-- ===================================================================
+-- tests for validator
+-- ===================================================================
+-- requiressl and some other parameters are omitted because
+-- valid values for them depend on configure options
+ALTER SERVER testserver1 OPTIONS (
+ use_remote_estimate 'false',
+ updatable 'true',
+ fdw_startup_cost '123.456',
+ fdw_tuple_cost '0.123',
+ service 'value',
+ connect_timeout 'value',
+ dbname 'value',
+ host 'value',
+ hostaddr 'value',
+ port 'value',
+ --client_encoding 'value',
+ application_name 'value',
+ --fallback_application_name 'value',
+ keepalives 'value',
+ keepalives_idle 'value',
+ keepalives_interval 'value',
+ tcp_user_timeout 'value',
+ -- requiressl 'value',
+ sslcompression 'value',
+ sslmode 'value',
+ sslcert 'value',
+ sslkey 'value',
+ sslrootcert 'value',
+ sslcrl 'value',
+ --requirepeer 'value',
+ krbsrvname 'value',
+ gsslib 'value'
+ --replication 'value'
+);
+-- Error, invalid list syntax
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo; bar');
+ERROR: parameter "extensions" must be a list of extension names
+-- OK but gets a warning
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo, bar');
+WARNING: extension "foo" is not installed
+WARNING: extension "bar" is not installed
+ALTER SERVER testserver1 OPTIONS (DROP extensions);
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (DROP user, DROP password);
+-- Attempt to add a valid option that's not allowed in a user mapping
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslmode 'require');
+ERROR: invalid option "sslmode"
+-- But we can add valid ones fine
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslpassword 'dummy');
+-- Ensure valid options we haven't used in a user mapping yet are
+-- permitted to check validation.
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslkey 'value', ADD sslcert 'value');
+ALTER FOREIGN TABLE ft1 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft2 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+ALTER FOREIGN TABLE ft2 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+\det+
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------+-------+-----------+---------------------------------------+-------------
+ public | ft1 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft2 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft4 | loopback | (schema_name 'S 1', table_name 'T 3') |
+ public | ft5 | loopback | (schema_name 'S 1', table_name 'T 4') |
+ public | ft6 | loopback2 | (schema_name 'S 1', table_name 'T 4') |
+ public | ft7 | loopback3 | (schema_name 'S 1', table_name 'T 4') |
+(6 rows)
+
+-- Test that alteration of server options causes reconnection
+-- Remote's errors might be non-English, so hide them to ensure stable results
+\set VERBOSITY terse
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET dbname 'no such database');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+DO $d$
+ BEGIN
+ EXECUTE $$ALTER SERVER loopback
+ OPTIONS (SET dbname '$$||current_database()||$$')$$;
+ END;
+$d$;
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+-- Test that alteration of user mapping options causes reconnection
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (ADD user 'no such user');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (DROP user);
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+\set VERBOSITY default
+-- Now we should be able to run ANALYZE.
+-- To exercise multiple code paths, we use local stats on ft1
+-- and remote-estimate mode on ft2.
+ANALYZE ft1;
+ALTER FOREIGN TABLE ft2 OPTIONS (use_remote_estimate 'true');
+-- ===================================================================
+-- test error case for create publication on foreign table
+-- ===================================================================
+CREATE PUBLICATION testpub_ftbl FOR TABLE ft1; -- should fail
+ERROR: cannot add relation "ft1" to publication
+DETAIL: This operation is not supported for foreign tables.
+-- ===================================================================
+-- simple queries
+-- ===================================================================
+-- single table without alias
+EXPLAIN (COSTS OFF) SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------
+ Foreign Scan on ft1
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- single table with alias - also test that tableoid sort is not pushed to remote side
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ -> Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Sort Key: t1.c3, t1.c1, t1.tableoid
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(8 rows)
+
+SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF) SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: t1.*, c3, c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c3 ASC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(3 rows)
+
+SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ t1
+--------------------------------------------------------------------------------------------
+ (101,1,00101,"Fri Jan 02 00:00:00 1970 PST","Fri Jan 02 00:00:00 1970",1,"1 ",foo)
+ (102,2,00102,"Sat Jan 03 00:00:00 1970 PST","Sat Jan 03 00:00:00 1970",2,"2 ",foo)
+ (103,3,00103,"Sun Jan 04 00:00:00 1970 PST","Sun Jan 04 00:00:00 1970",3,"3 ",foo)
+ (104,4,00104,"Mon Jan 05 00:00:00 1970 PST","Mon Jan 05 00:00:00 1970",4,"4 ",foo)
+ (105,5,00105,"Tue Jan 06 00:00:00 1970 PST","Tue Jan 06 00:00:00 1970",5,"5 ",foo)
+ (106,6,00106,"Wed Jan 07 00:00:00 1970 PST","Wed Jan 07 00:00:00 1970",6,"6 ",foo)
+ (107,7,00107,"Thu Jan 08 00:00:00 1970 PST","Thu Jan 08 00:00:00 1970",7,"7 ",foo)
+ (108,8,00108,"Fri Jan 09 00:00:00 1970 PST","Fri Jan 09 00:00:00 1970",8,"8 ",foo)
+ (109,9,00109,"Sat Jan 10 00:00:00 1970 PST","Sat Jan 10 00:00:00 1970",9,"9 ",foo)
+ (110,0,00110,"Sun Jan 11 00:00:00 1970 PST","Sun Jan 11 00:00:00 1970",0,"0 ",foo)
+(10 rows)
+
+-- empty result
+SELECT * FROM ft1 WHERE false;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- with WHERE clause
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c7 >= '1')) AND (("C 1" = 101)) AND ((c6 = '1'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- with FOR UPDATE/SHARE
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 101)) FOR UPDATE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 102)) FOR SHARE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+-- aggregate
+SELECT COUNT(*) FROM ft1 t1;
+ count
+-------
+ 1000
+(1 row)
+
+-- subquery
+SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- subquery+MAX
+SELECT * FROM ft1 t1 WHERE t1.c3 = (SELECT MAX(c3) FROM ft2 t2) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+(1 row)
+
+-- used in CTE
+WITH t1 AS (SELECT * FROM ft1 WHERE c1 <= 10) SELECT t2.c1, t2.c2, t2.c3, t2.c4 FROM t1, ft2 t2 WHERE t1.c1 = t2.c1 ORDER BY t1.c1;
+ c1 | c2 | c3 | c4
+----+----+-------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+(10 rows)
+
+-- fixed values
+SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1;
+ ?column? | ?column?
+----------+----------
+ fixed |
+(1 row)
+
+-- Test forcing the remote server to produce sorted data for a merge join.
+SET enable_hashjoin TO false;
+SET enable_nestloop TO false;
+-- inner join; expressions in the clauses appear in the equivalence class list
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Left Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- A join between local table and foreign join. ORDER BY clause is added to the
+-- foreign join so that the local table can be joined using merge join strategy.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Merge Right Join
+ Output: t1."C 1"
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r3."C 1" FROM ("S 1"."T 1" r2 INNER JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r2."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- Test similar to above, except that the full join prevents any equivalence
+-- classes from being merged. This produces single relation equivalence classes
+-- included in join restrictions.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Right Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1, t2.c1
+ Relations: (public.ft2 t3) LEFT JOIN (public.ft1 t2)
+ Remote SQL: SELECT r3."C 1", r2."C 1" FROM ("S 1"."T 1" r3 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+-- Test similar to above with all full outer joins
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Full Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) FULL JOIN (public.ft2 t3)
+ Remote SQL: SELECT r2."C 1", r3."C 1" FROM ("S 1"."T 1" r2 FULL JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test executing assertion in estimate_path_cost_size() that makes sure that
+-- retrieved_rows for foreign rel re-used to cost pre-sorted foreign paths is
+-- a sensible value even when the rel has tuples=0
+CREATE TABLE loct_empty (c1 int NOT NULL, c2 text);
+CREATE FOREIGN TABLE ft_empty (c1 int NOT NULL, c2 text)
+ SERVER loopback OPTIONS (table_name 'loct_empty');
+INSERT INTO loct_empty
+ SELECT id, 'AAA' || to_char(id, 'FM000') FROM generate_series(1, 100) id;
+DELETE FROM loct_empty;
+ANALYZE ft_empty;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Foreign Scan on public.ft_empty
+ Output: c1, c2
+ Remote SQL: SELECT c1, c2 FROM public.loct_empty ORDER BY c1 ASC NULLS LAST
+(3 rows)
+
+-- ===================================================================
+-- WHERE with remotely-executable conditions
+-- ===================================================================
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1; -- Var, OpExpr(b), Const
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL; -- NullTest
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL; -- NullTest
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((round(abs("C 1"), 0) = 1::numeric))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1; -- OpExpr(l)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = (- "C 1")))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" IS NOT NULL) IS DISTINCT FROM ("C 1" IS NOT NULL)))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]); -- ScalarArrayOpExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ANY (ARRAY[c2, 1, ("C 1" + 0)])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1]; -- SubscriptingRef
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ((ARRAY["C 1", c2, 3])[1])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar'; -- check special chars
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c6 = E'foo''s\\bar'))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c8 = 'foo'; -- can't be sent to remote
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- parameterized remote path for foreign table
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM "S 1"."T 1" a, ft2 b WHERE a."C 1" = 47 AND b.c1 = a.c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Index Scan using t1_pkey on "S 1"."T 1" a
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Index Cond: (a."C 1" = 47)
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(8 rows)
+
+SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 47 | 7 | 00047 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo | 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+(1 row)
+
+-- check both safe and unsafe join conditions
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 a, ft2 b
+ WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Foreign Scan on public.ft2 a
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Filter: (a.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c2 = 6))
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Filter: (upper((a.c7)::text) = (b.c7)::text)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(10 rows)
+
+SELECT * FROM ft2 a, ft2 b
+WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+(100 rows)
+
+-- bug before 9.3.5 due to sloppy handling of remote-estimate parameters
+SELECT * FROM ft1 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft2 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+SELECT * FROM ft2 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft1 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+-- we should not push order by clause with volatile expressions or unsafe
+-- collations
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, random();
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, (random())
+ Sort Key: ft2.c1, (random())
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, random()
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, ft2.c3 collate "C";
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, ((c3)::text)
+ Sort Key: ft2.c1, ft2.c3 COLLATE "C"
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- user-defined operator/function
+CREATE FUNCTION postgres_fdw_abs(int) RETURNS int AS $$
+BEGIN
+RETURN abs($1);
+END
+$$ LANGUAGE plpgsql IMMUTABLE;
+CREATE OPERATOR === (
+ LEFTARG = int,
+ RIGHTARG = int,
+ PROCEDURE = int4eq,
+ COMMUTATOR = ===
+);
+-- built-in operators and functions can be shipped for remote execution
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ QUERY PLAN
+----------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- by default, user-defined ones cannot
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 = postgres_fdw_abs(t1.c2))
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- ORDER BY can be shipped, though
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- but let's put them in an extension ...
+ALTER EXTENSION postgres_fdw ADD FUNCTION postgres_fdw_abs(int);
+ALTER EXTENSION postgres_fdw ADD OPERATOR === (int, int);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- ... now they can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- and both ORDER BY and LIMIT can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2)) ORDER BY c2 ASC NULLS LAST LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- Test CASE pushdown
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE WHEN ("C 1" > 990) THEN "C 1" ELSE NULL::integer END) < 1000)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ c1 | c2 | c3
+-----+----+-------
+ 991 | 1 | 00991
+ 992 | 2 | 00992
+ 993 | 3 | 00993
+ 994 | 4 | 00994
+ 995 | 5 | 00995
+ 996 | 6 | 00996
+ 997 | 7 | 00997
+ 998 | 8 | 00998
+ 999 | 9 | 00999
+(9 rows)
+
+-- Nested CASE
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE (CASE WHEN (c2 > 0) THEN c2 ELSE NULL::integer END) WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END) > 600)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ c1 | c2 | c3
+----+----+----
+(0 rows)
+
+-- CASE arg WHEN
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE mod(c1, 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" > (CASE mod("C 1", 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)))
+(3 rows)
+
+-- CASE cannot be pushed down because of unshippable arg clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE random()::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (ft1.c1 > CASE (random())::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- these are shippable
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c6 WHEN 'foo' THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c6 WHEN 'foo'::text THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c3 WHEN c6 THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+-- but this is not because of collation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 COLLATE "C" WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: CASE (ft1.c3)::text WHEN ft1.c6 THEN true ELSE (ft1.c3 < 'bar'::text) END
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- a regconfig constant referring to this text search configuration
+-- is initially unshippable
+CREATE TEXT SEARCH CONFIGURATION public.custom_search
+ (COPY = pg_catalog.english);
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Filter: (length(to_tsvector('custom_search'::regconfig, ft1.c3)) > 0)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642))
+(4 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- but if it's in a shippable extension, it can be shipped
+ALTER EXTENSION postgres_fdw ADD TEXT SEARCH CONFIGURATION public.custom_search;
+-- however, that doesn't flush the shippability cache, so do a quick reconnect
+\c -
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642)) AND ((length(to_tsvector('public.custom_search'::regconfig, c3)) > 0))
+(3 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- ===================================================================
+-- JOIN queries
+-- ===================================================================
+-- Analyze ft4 and ft5 so that we have better statistics. These tables do not
+-- have use_remote_estimate set.
+ANALYZE ft4;
+ANALYZE ft5;
+-- join two tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3, t1.c3
+ Relations: ((public.ft1 t1) INNER JOIN (public.ft2 t2)) INNER JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3, r1.c3 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) INNER JOIN "S 1"."T 3" r4 ON (((r1."C 1" = r4.c1)))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 22 |
+ 24 | 24
+ 26 |
+ 28 |
+ 30 | 30
+ 32 |
+ 34 |
+ 36 | 36
+ 38 |
+ 40 |
+(10 rows)
+
+-- left outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + placement of clauses.
+-- clauses within the nullable side are not pulled up, but top level clause on
+-- non-nullable side is pushed into non-nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- clauses within the nullable side are not pulled up, but the top level clause
+-- on nullable side is not pushed down into nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE (((r4.c1 < 10) OR (r4.c1 IS NULL))) AND ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t2) LEFT JOIN (public.ft5 t1)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r1 ON (((r1.c1 = r2.c1)))) ORDER BY r2.c1 ASC NULLS LAST, r1.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ | 22
+ 24 | 24
+ | 26
+ | 28
+ 30 | 30
+ | 32
+ | 34
+ 36 | 36
+ | 38
+ | 40
+(10 rows)
+
+-- right outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 45::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ c1 | c1
+-----+----
+ 92 |
+ 94 |
+ 96 | 96
+ 98 |
+ 100 |
+ | 3
+ | 9
+ | 15
+ | 21
+ | 27
+(10 rows)
+
+-- full outer join with restrictions on the joining relations
+-- a. the joining relations are both base relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s4.c1, s5.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s5.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ c1 | c1
+----+----
+ 50 |
+ 52 |
+ 54 | 54
+ 56 |
+ 58 |
+ 60 | 60
+ | 51
+ | 57
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: 1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT NULL FROM ((SELECT NULL FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4 FULL JOIN (SELECT NULL FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5 ON (TRUE)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ ?column?
+----------
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- b. one of the joining relations is a base relation and the other is a join
+-- relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c1, t3.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 t2) LEFT JOIN (public.ft5 t3))
+ Remote SQL: SELECT s4.c1, s8.c1, s8.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT r5.c1, r6.c1 FROM ("S 1"."T 3" r5 LEFT JOIN "S 1"."T 4" r6 ON (((r5.c1 = r6.c1)))) WHERE ((r5.c1 >= 50)) AND ((r5.c1 <= 60))) s8(c1, c2) ON (((s4.c1 = s8.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s8.c1 ASC NULLS LAST, s8.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+(6 rows)
+
+-- c. test deparsing the remote query as nested subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft4_1.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 ft4_1) FULL JOIN (public.ft5))
+ Remote SQL: SELECT s4.c1, s10.c1, s10.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT s8.c1, s9.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL)))) s10(c1, c2) ON (((s4.c1 = s10.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s10.c1 ASC NULLS LAST, s10.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+ | | 51
+ | | 57
+(8 rows)
+
+-- d. test deparsing rowmarked relations as subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Nested Loop
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Foreign Scan
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s8.c1, s8.c2, s9.c1, s9.c2 FROM ((SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1, c2) FULL JOIN (SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1, c2) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL))) ORDER BY s8.c1 ASC NULLS LAST, s9.c1 ASC NULLS LAST
+ -> Sort
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Full Join
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Hash Cond: (ft4.c1 = ft5.c1)
+ Filter: ((ft4.c1 IS NULL) OR (ft4.c1 IS NOT NULL))
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Hash
+ Output: ft5.c1, ft5.*
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Materialize
+ Output: "T 3".c1, "T 3".ctid
+ -> Seq Scan on "S 1"."T 3"
+ Output: "T 3".c1, "T 3".ctid
+ Filter: ("T 3".c1 = 50)
+(28 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 50 | 52 |
+ 50 | 54 | 54
+ 50 | 56 |
+ 50 | 58 |
+ 50 | 60 | 60
+ 50 | | 51
+ 50 | | 57
+(8 rows)
+
+-- full outer join + inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t3.c1
+ Relations: ((public.ft4 t1) INNER JOIN (public.ft5 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1.c1, r2.c1, r4.c1 FROM (("S 1"."T 3" r1 INNER JOIN "S 1"."T 4" r2 ON (((r1.c1 = (r2.c1 + 1))) AND ((r1.c1 >= 50)) AND ((r1.c1 <= 60)))) FULL JOIN "S 1"."T 3" r4 ON (((r2.c1 = r4.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST, r4.c1 ASC NULLS LAST LIMIT 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ c1 | c1 | c1
+----+----+----
+ 52 | 51 |
+ 58 | 57 |
+ | | 2
+ | | 4
+ | | 6
+ | | 8
+ | | 10
+ | | 12
+ | | 14
+ | | 16
+(10 rows)
+
+-- full outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- right outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+SET enable_memoize TO off;
+-- right outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+RESET enable_memoize;
+-- left outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: (public.ft4 t3) LEFT JOIN ((public.ft2 t1) INNER JOIN (public.ft2 t2))
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM ("S 1"."T 3" r4 LEFT JOIN ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join + WHERE clause, only matched rows
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 = r2.c1) OR (r1.c1 IS NULL)))
+(9 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 66 | 66
+ 72 | 72
+ 78 | 78
+ 84 | 84
+ 90 | 90
+ 96 | 96
+ | 3
+ | 9
+ | 15
+ | 21
+(10 rows)
+
+-- full outer join + WHERE clause with shippable extensions set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) WHERE ((public.postgres_fdw_abs(r1."C 1") > 0)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+-- full outer join + WHERE clause with shippable extensions not set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c2, t1.c3
+ -> Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Filter: (postgres_fdw_abs(t1.c1) > 0)
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- join two tables with FOR UPDATE clause
+-- tests whole-row reference for row marks
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1 FOR UPDATE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join two tables with FOR SHARE clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1 FOR SHARE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join in CTE
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t.c1_1, t.c2_1, t.c1_3
+ CTE t
+ -> Foreign Scan
+ Output: t1.c1, t1.c3, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r1.c3, r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+ -> Sort
+ Output: t.c1_1, t.c2_1, t.c1_3
+ Sort Key: t.c1_3, t.c1_1
+ -> CTE Scan on t
+ Output: t.c1_1, t.c2_1, t.c1_3
+(12 rows)
+
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ c1_1 | c2_1
+------+------
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- ctid with whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.ctid, t1.*, t2.*, t1.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r1."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+-- SEMI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Semi Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c1)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- ANTI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Anti Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c2)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 110
+ 111
+ 112
+ 113
+ 114
+ 115
+ 116
+ 117
+ 118
+ 119
+(10 rows)
+
+-- CROSS JOIN can be pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (TRUE)) ORDER BY r1."C 1" ASC NULLS LAST, r2."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- different server, not pushed down. No result expected.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Merge Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft6 t2
+ Output: t2.c1, t2.c2, t2.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+ -> Materialize
+ Output: t1.c1, t1.c2, t1.c3
+ -> Foreign Scan on public.ft5 t1
+ Output: t1.c1, t1.c2, t1.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+(13 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+----
+(0 rows)
+
+-- unsafe join conditions (c8 has a UDT), not pushed down. Practically a CROSS
+-- JOIN since c8 in both tables has same value.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Merge Left Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t1.c8 = t2.c8)
+ -> Sort
+ Output: t1.c1, t1.c8
+ Sort Key: t1.c8
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+ -> Sort
+ Output: t2.c1, t2.c8
+ Sort Key: t2.c8
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1, t2.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+(20 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- unsafe conditions on one side (c8 has a UDT), not pushed down.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Hash Right Join
+ Output: t1.c1, t2.c1, t1.c3
+ Hash Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+ -> Hash
+ Output: t1.c1, t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c3
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c3, c8 FROM "S 1"."T 1"
+(17 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join where unsafe to pushdown condition in WHERE clause has a column not
+-- in the SELECT clause. In this test unsafe clause needs to have column
+-- references from both joining sides so that the clause is not pushed down
+-- into one of the joining sides.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Filter: (t1.c8 = t2.c8)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, r1.c8, r2.c8 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(10 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- Aggregate after UNION, for testing setrefs
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ -> Sort
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ Sort Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, avg((t1.c1 + t2.c1))
+ Group Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, t2.c1
+ Group Key: t1.c1, t2.c1
+ -> Append
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+ -> Foreign Scan
+ Output: t1_1.c1, t2_1.c1
+ Relations: (public.ft1 t1_1) INNER JOIN (public.ft2 t2_1)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(20 rows)
+
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ t1c1 | avg
+------+----------------------
+ 101 | 202.0000000000000000
+ 102 | 204.0000000000000000
+ 103 | 206.0000000000000000
+ 104 | 208.0000000000000000
+ 105 | 210.0000000000000000
+ 106 | 212.0000000000000000
+ 107 | 214.0000000000000000
+ 108 | 216.0000000000000000
+ 109 | 218.0000000000000000
+ 110 | 220.0000000000000000
+(10 rows)
+
+-- join with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Nested Loop
+ Output: t1."C 1"
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ -> Memoize
+ Cache Key: t1.c2
+ Cache Mode: binary
+ -> Subquery Scan on q
+ -> HashAggregate
+ Output: t2.c1, t3.c1
+ Group Key: t2.c1, t3.c1
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r1.c2 = $1::integer))))
+(17 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ C 1
+-----
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- non-Var items in targetlist of the nullable rel of a join preventing
+-- push-down in some cases
+-- unable to push {ft1, ft2}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: (13), ft2.c1
+ Join Filter: (13 = ft2.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" WHERE (("C 1" >= 10)) AND (("C 1" <= 15)) ORDER BY "C 1" ASC NULLS LAST
+ -> Materialize
+ Output: (13)
+ -> Foreign Scan on public.ft1
+ Output: 13
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 13))
+(11 rows)
+
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ a | c1
+----+----
+ | 10
+ | 11
+ | 12
+ 13 | 13
+ | 14
+ | 15
+(6 rows)
+
+-- ok to push {ft1, ft2} but not {ft1, ft2, ft4}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: ft4.c1, (13), ft1.c1, ft2.c1
+ Join Filter: (ft4.c1 = ft1.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
+ -> Materialize
+ Output: ft1.c1, ft2.c1, (13)
+ -> Foreign Scan
+ Output: ft1.c1, ft2.c1, 13
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r5."C 1" FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = 12)) AND ((r4."C 1" = 12)))) ORDER BY r4."C 1" ASC NULLS LAST
+(12 rows)
+
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ c1 | a | b | c
+----+----+----+----
+ 10 | | |
+ 12 | 13 | 12 | 12
+ 14 | | |
+(3 rows)
+
+-- join with nullable side with some columns with null values
+UPDATE ft5 SET c3 = null where c1 % 9 = 0;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2
+ Relations: (public.ft5) INNER JOIN (public.ft4)
+ Remote SQL: SELECT CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1.c1, r1.c2, r1.c3) END, r1.c1, r1.c2, r1.c3, r2.c1, r2.c2 FROM ("S 1"."T 4" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c1 = r2.c1)) AND ((r2.c1 >= 10)) AND ((r2.c1 <= 30)))) ORDER BY r1.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ ft5 | c1 | c2 | c3 | c1 | c2
+----------------+----+----+--------+----+----
+ (12,13,AAA012) | 12 | 13 | AAA012 | 12 | 13
+ (18,19,) | 18 | 19 | | 18 | 19
+ (24,25,AAA024) | 24 | 25 | AAA024 | 24 | 25
+ (30,31,AAA030) | 30 | 31 | AAA030 | 30 | 31
+(4 rows)
+
+-- multi-way join involving multiple merge joins
+-- (this case used to have EPQ-related planning problems)
+CREATE TABLE local_tbl (c1 int NOT NULL, c2 int NOT NULL, c3 text, CONSTRAINT local_tbl_pkey PRIMARY KEY (c1));
+INSERT INTO local_tbl SELECT id, id % 10, to_char(id, 'FM0000') FROM generate_series(1, 1000) id;
+ANALYZE local_tbl;
+SET enable_nestloop TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ Inner Unique: true
+ Merge Cond: (ft1.c2 = local_tbl.c1)
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Relations: (((public.ft1) INNER JOIN (public.ft2)) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r3.c1, r3.c2, r3.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r4.c1, r4.c2, r4.c3, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4.c1, r4.c2, r4.c3) END FROM ((("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r2."C 1" < 100)) AND ((r1."C 1" < 100)))) INNER JOIN "S 1"."T 3" r3 ON (((r1.c2 = r3.c1)))) INNER JOIN "S 1"."T 4" r4 ON (((r1.c2 = r4.c1)))) ORDER BY r1.c2 ASC NULLS LAST FOR UPDATE OF r1 FOR UPDATE OF r2 FOR UPDATE OF r3 FOR UPDATE OF r4
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Merge Cond: (ft1.c2 = ft5.c1)
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Merge Cond: (ft1.c2 = ft4.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Sort Key: ft1.c2
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Merge Cond: (ft1.c1 = ft2.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) FOR UPDATE
+ -> Materialize
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Sort
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Sort Key: ft4.c1
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" FOR UPDATE
+ -> Sort
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Sort Key: ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" FOR UPDATE
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+(47 rows)
+
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3 | c1 | c2 | c3
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+--------+----+----+--------+----+----+------
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+(10 rows)
+
+RESET enable_nestloop;
+RESET enable_hashjoin;
+-- test that add_paths_with_pathkeys_for_rel() arranges for the epq_path to
+-- return columns needed by the parent ForeignScan node
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.*, COALESCE(ft1.c3 || ft2.c3, 'foobar') FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100)) ss ON (local_tbl.c1 = ss.c1) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ -> Merge Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ Merge Cond: (local_tbl.c1 = ft1.c1)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text))
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c3 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r4."C 1" = r5."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4."C 1" ASC NULLS LAST
+ -> Result
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c3
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), ft2.c3
+ Sort Key: ft1.c1
+ -> Hash Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text), ft2.c3
+ Hash Cond: (ft1.c1 = ft2.c1)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Hash
+ Output: ft2.*, ft2.c1, ft2.c3
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(29 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD fdw_startup_cost '10000.0');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.* FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100 AND ft1.c1 = postgres_fdw_abs(ft2.c2))) ss ON (local_tbl.c3 = ss.c3) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ -> Nested Loop Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ Join Filter: (local_tbl.c3 = ft1.c3)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ Filter: (ft1.c1 = postgres_fdw_abs(ft2.c2))
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c2 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r4."C 1" = r5."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4.c3 ASC NULLS LAST
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Sort Key: ft1.c3
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Merge Cond: ((ft1.c1 = (postgres_fdw_abs(ft2.c2))) AND (ft1.c1 = ft2.c1))
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Sort
+ Output: ft2.*, ft2.c1, ft2.c2, (postgres_fdw_abs(ft2.c2))
+ Sort Key: (postgres_fdw_abs(ft2.c2)), ft2.c1
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, postgres_fdw_abs(ft2.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(32 rows)
+
+ALTER SERVER loopback OPTIONS (DROP fdw_startup_cost);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+DROP TABLE local_tbl;
+-- check join pushdown in situations where multiple userids are involved
+CREATE ROLE regress_view_owner SUPERUSER;
+CREATE USER MAPPING FOR regress_view_owner SERVER loopback;
+GRANT SELECT ON ft4 TO regress_view_owner;
+GRANT SELECT ON ft5 TO regress_view_owner;
+CREATE VIEW v4 AS SELECT * FROM ft4;
+CREATE VIEW v5 AS SELECT * FROM ft5;
+ALTER VIEW v5 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, different view owners
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, ft5.c2, ft5.c1
+ -> Sort
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Left Join
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.c2, ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c2, ft5.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r6.c1, r9.c2, r9.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r9 ON (((r6.c1 = r9.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r9.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, view owner not current user
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, t2.c2, t2.c1
+ -> Sort
+ Output: ft4.c1, t2.c2, t2.c1
+ Sort Key: ft4.c1, t2.c1
+ -> Hash Left Join
+ Output: ft4.c1, t2.c2, t2.c1
+ Hash Cond: (ft4.c1 = t2.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: t2.c2, t2.c1
+ -> Foreign Scan on public.ft5 t2
+ Output: t2.c2, t2.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO CURRENT_USER;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c2, t2.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r6.c1, r2.c2, r2.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r2 ON (((r6.c1 = r2.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+-- cleanup
+DROP OWNED BY regress_view_owner;
+DROP ROLE regress_view_owner;
+-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+------+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+ 100 | 49700 | 497.0000000000000000 | 2 | 992 | 0 | 49700
+ 100 | 49800 | 498.0000000000000000 | 3 | 993 | 0 | 49800
+ 100 | 49900 | 499.0000000000000000 | 4 | 994 | 0 | 49900
+ 100 | 50500 | 505.0000000000000000 | 0 | 1000 | 0 | 50500
+(5 rows)
+
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST LIMIT 1::bigint
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+-----+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+(1 row)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * (random() <= 1)::int) as sum, avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Aggregate
+ Output: sum((c1 * ((random() <= '1'::double precision))::integer)), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT count(*), sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ count | sum | avg
+-------+---------+----------------------
+ 10000 | 5010000 | 501.0000000000000000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where ((t1.c1 * t2.c1)/(t1.c1 * t2.c1)) * random() <= 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(t1.c1), count(t2.c1)
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Filter: (((((t1.c1 * t2.c1) / (t1.c1 * t2.c1)))::double precision * random()) <= '1'::double precision)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY 1 ORDER BY (c2 / 2) ASC NULLS LAST
+(4 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 500
+ 2 | 1800
+ 3 | 3900
+ 4 | 6800
+(5 rows)
+
+-- Aggregates in subquery are pushed down.
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 ORDER BY c2 ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(6 rows)
+
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+------
+ 1000 | 4500
+(1 row)
+
+-- Aggregate is still pushed down by taking unshippable expression out
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer)), ((sum(c1) * c2)), c2
+ Sort Key: ((ft1.c2 * ((random() <= '1'::double precision))::integer)), ((sum(ft1.c1) * ft1.c2))
+ -> Foreign Scan
+ Output: (c2 * ((random() <= '1'::double precision))::integer), ((sum(c1) * c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum("C 1") * c2), c2 FROM "S 1"."T 1" GROUP BY 2
+(7 rows)
+
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ sum1 | sum2
+------+--------
+ 0 | 0
+ 1 | 49600
+ 2 | 99400
+ 3 | 149400
+ 4 | 199600
+ 5 | 250000
+ 6 | 300600
+ 7 | 351400
+ 8 | 402400
+ 9 | 453600
+(10 rows)
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::int order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Sort Key: ((ft2.c2 * ((random() <= '1'::double precision))::integer))
+ -> HashAggregate
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Group Key: (ft2.c2 * ((random() <= '1'::double precision))::integer)
+ -> Foreign Scan on public.ft2
+ Output: (c2 * ((random() <= '1'::double precision))::integer)
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- GROUP BY clause in various forms, cardinal, alias and constant expression
+explain (verbose, costs off)
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), c2, 5, 7.0, 9 FROM "S 1"."T 1" GROUP BY 2, 3, 5
+(7 rows)
+
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ w | x | y | z
+-----+---+---+-----
+ 100 | 0 | 5 | 7.0
+ 100 | 1 | 5 | 7.0
+ 100 | 2 | 5 | 7.0
+ 100 | 3 | 5 | 7.0
+ 100 | 4 | 5 | 7.0
+ 100 | 5 | 5 | 7.0
+ 100 | 6 | 5 | 7.0
+ 100 | 7 | 5 | 7.0
+ 100 | 8 | 5 | 7.0
+ 100 | 9 | 5 | 7.0
+(10 rows)
+
+-- GROUP BY clause referring to same column multiple times
+-- Also, ORDER BY contains an aggregate function
+explain (verbose, costs off)
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, c2, (sum(c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, c2, sum("C 1") FROM "S 1"."T 1" WHERE ((c2 > 6)) GROUP BY 1, 2 ORDER BY sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ c2 | c2
+----+----
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(3 rows)
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 49800)) ORDER BY c2 ASC NULLS LAST
+(4 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ c2 | sum
+----+-------
+ 1 | 49600
+ 2 | 49700
+(2 rows)
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, NULL::bigint, (sqrt((ft1.c2)::double precision))
+ Filter: (((((avg(ft1.c1)) / (avg(ft1.c1))))::double precision * random()) <= '1'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ count
+-------
+ 49
+(1 row)
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * (random() <= 1)::int) > 100 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1)), c2
+ Sort Key: (sum(ft1.c1))
+ -> HashAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Filter: (avg((ft1.c1 * ((random() <= '1'::double precision))::integer)) > '100'::numeric)
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(10 rows)
+
+-- Remote aggregate in combination with a local Param (for the output
+-- of an initplan) can be trouble, per bug #15781
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ QUERY PLAN
+--------------------------------------------------
+ Foreign Scan
+ Output: $0, (sum(ft1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1"
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+(6 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ QUERY PLAN
+---------------------------------------------------
+ GroupAggregate
+ Output: ($0), sum(ft1.c1)
+ Group Key: $0
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+ -> Foreign Scan on public.ft1
+ Output: $0, ft1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(8 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY 2 ORDER BY array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1,11,21,31,41,51,61,71,81,91}
+ {2,12,22,32,42,52,62,72,82,92}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {5,15,25,35,45,55,65,75,85,95}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+(10 rows)
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5)) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY 2 ORDER BY sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))) ASC NULLS LAST
+(4 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+(10 rows)
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3) ORDER BY (("C 1" % 3)) ASC NULLS LAST) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY 3
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft2 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where (c1 / c1) * random() <= 1) from ft1 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((((ft1.c1 / ft1.c1))::double precision * random()) <= '1'::double precision)))
+ -> HashAggregate
+ Output: sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST), percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
+(7 rows)
+
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | rank | percentile_cont
+----+------+-----------------
+ 0 | 101 | 10
+ 1 | 101 | 100
+ 2 | 1 | 200
+ 3 | 1 | 300
+ 4 | 1 | 400
+(5 rows)
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY 1, 3
+(4 rows)
+
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ c1 | rank
+----+------
+ 6 | 1
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Disable hash aggregation for plan stability.
+set enable_hashagg to false;
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY 1
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 0 | 10
+ 1 | 1
+ 2 | 2
+ 3 | 3
+ 4 | 4
+ 5 | 5
+ 6 | 6
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(10 rows)
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Cleanup
+reset enable_hashagg;
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+create operator family my_op_family using btree;
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- This should not be pushed either.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- Update local stats on ft2
+ANALYZE ft2;
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now this will be pushed as sort operator is part of the extension.
+alter server loopback options (add fdw_tuple_cost '0.5');
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY 2
+(4 rows)
+
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+alter server loopback options (drop fdw_tuple_cost);
+-- This should be pushed too.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST
+(3 rows)
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft2 t1 left join ft2 t2 on (t1.c1 = random() * t2.c2);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop Left Join
+ Output: t1.c3
+ Join Filter: ((t1.c1)::double precision = (random() * (t2.c2)::double precision))
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c3, t1.c1
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1"
+ -> Materialize
+ Output: t2.c2
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(13 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Inner Unique: true
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1 ft1_1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1
+(21 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 100 | 49600
+ 100 | 49700
+ 100 | 49800
+ 100 | 49900
+ 100 | 50000
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(10 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY 3 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL))) ORDER BY avg(r1.c1) ASC NULLS LAST, sum(r2.c1) ASC NULLS LAST
+(4 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- Aggregate over FULL join needing to deparse the joining relations as
+-- subqueries.
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(ft4.c1)), (avg(ft5.c1))
+ Relations: Aggregate on ((public.ft4) FULL JOIN (public.ft5))
+ Remote SQL: SELECT count(*), sum(s4.c1), avg(s5.c1) FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ count | sum | avg
+-------+-----+---------------------
+ 8 | 330 | 55.5000000000000000
+(1 row)
+
+-- ORDER BY expression is part of the target list but not pushed down to
+-- foreign server.
+explain (verbose, costs off)
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: (((sum(c2)) * ((random() <= '1'::double precision))::integer))
+ Sort Key: (((sum(ft1.c2)) * ((random() <= '1'::double precision))::integer))
+ -> Foreign Scan
+ Output: ((sum(c2)) * ((random() <= '1'::double precision))::integer)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
+(7 rows)
+
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ sum
+------
+ 4500
+(1 row)
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c2, qry.sum
+ Sort Key: t1.c2
+ -> Nested Loop
+ Output: t1.c2, qry.sum
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Index Cond: (t1."C 1" < 100)
+ Filter: (t1.c2 < 3)
+ -> Subquery Scan on qry
+ Output: qry.sum, t2.c1
+ Filter: ((t1.c2 * 2) = qry.sum)
+ -> Foreign Scan
+ Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY 2
+(16 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ c2 | sum
+----+-----
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+reset enable_hashagg;
+-- bug #15613: bad plan for foreign table scan with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: ref_0.c2, ref_0."C 1", (ref_0.c2), ref_1.c3, ref_0."C 1"
+ -> Nested Loop
+ Output: ref_0.c2, ref_0."C 1", ref_1.c3, (ref_0.c2)
+ -> Index Scan using t1_pkey on "S 1"."T 1" ref_0
+ Output: ref_0."C 1", ref_0.c2, ref_0.c3, ref_0.c4, ref_0.c5, ref_0.c6, ref_0.c7, ref_0.c8
+ Index Cond: (ref_0."C 1" < 10)
+ -> Foreign Scan on public.ft1 ref_1
+ Output: ref_1.c3, ref_0.c2
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+ -> Materialize
+ Output: ref_3.c3
+ -> Foreign Scan on public.ft2 ref_3
+ Output: ref_3.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+(15 rows)
+
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ c2 | c1 | c2 | c3
+----+----+----+-------
+ 1 | 1 | 1 | 00001
+ 2 | 2 | 2 | 00001
+ 3 | 3 | 3 | 00001
+ 4 | 4 | 4 | 00001
+ 5 | 5 | 5 | 00001
+ 6 | 6 | 6 | 00001
+ 7 | 7 | 7 | 00001
+ 8 | 8 | 8 | 00001
+ 9 | 9 | 9 | 00001
+(9 rows)
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(q.a), count(q.b)
+ -> Nested Loop Left Join
+ Output: q.a, q.b
+ Inner Unique: true
+ Join Filter: ((ft4.c1)::numeric <= q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Materialize
+ Output: q.a, q.b
+ -> Subquery Scan on q
+ Output: q.a, q.b
+ -> Foreign Scan
+ Output: 13, (avg(ft1.c1)), NULL::bigint
+ Relations: Aggregate on ((public.ft2) LEFT JOIN (public.ft1))
+ Remote SQL: SELECT 13, avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1"))))
+(17 rows)
+
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ sum | count
+-----+-------
+ 650 | 50
+(1 row)
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: c2, c6, (sum(c1))
+ Sort Key: ft1.c2, ft1.c6
+ -> HashAggregate
+ Output: c2, c6, sum(c1)
+ Hash Key: ft1.c2
+ Hash Key: ft1.c6
+ -> Foreign Scan on public.ft1
+ Output: c2, c6, c1
+ Remote SQL: SELECT "C 1", c2, c6 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 0 | | 50500
+ 1 | | 49600
+ 2 | | 49700
+ | 0 | 50500
+ | 1 | 49600
+ | 2 | 49700
+(6 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1)), (GROUPING(c2))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, sum(c1), GROUPING(c2)
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(9 rows)
+
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 0 | 50500 | 0
+ 1 | 49600 | 0
+ 2 | 49700 | 0
+(3 rows)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((sum(c1) / 1000)), c2
+ -> Sort
+ Output: ((sum(c1) / 1000)), c2
+ Sort Key: ((sum(ft2.c1) / 1000))
+ -> Foreign Scan
+ Output: ((sum(c1) / 1000)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT (sum("C 1") / 1000), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY 2
+(9 rows)
+
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ s
+----
+ 49
+ 50
+(2 rows)
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2)), (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, (sum(c2)), count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ c2 | sum | count
+----+-----+-------
+ 0 | 0 | 5
+ 1 | 100 | 5
+ 2 | 200 | 5
+ 3 | 300 | 5
+ 4 | 400 | 5
+ 5 | 500 | 5
+ 6 | 600 | 5
+ 7 | 700 | 5
+ 8 | 800 | 5
+ 9 | 900 | 5
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2 DESC
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {8,6,4,2,0}
+ 1 | {9,7,5,3,1}
+ 2 | {8,6,4,2}
+ 3 | {9,7,5,3}
+ 4 | {8,6,4}
+ 5 | {9,7,5}
+ 6 | {8,6}
+ 7 | {9,7}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {0,2,4,6,8}
+ 1 | {1,3,5,7,9}
+ 2 | {2,4,6,8}
+ 3 | {3,5,7,9}
+ 4 | {4,6,8}
+ 5 | {5,7,9}
+ 6 | {6,8}
+ 7 | {7,9}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+-- ===================================================================
+-- parameterized queries
+-- ===================================================================
+-- simple join
+PREPARE st1(int, int) AS SELECT t1.c3, t2.c3 FROM ft1 t1, ft2 t2 WHERE t1.c1 = $1 AND t2.c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st1(1, 2);
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c3, t2.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.c3, r2.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 2)) AND ((r1."C 1" = 1))))
+(4 rows)
+
+EXECUTE st1(1, 1);
+ c3 | c3
+-------+-------
+ 00001 | 00001
+(1 row)
+
+EXECUTE st1(101, 101);
+ c3 | c3
+-------+-------
+ 00101 | 00101
+(1 row)
+
+-- subquery using stable function (can't be sent to remote)
+PREPARE st2(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c4) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st2(10, 20);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t1.c3 = t2.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Filter: (date(t2.c4) = '01-17-1970'::date)
+ Remote SQL: SELECT c3, c4 FROM "S 1"."T 1" WHERE (("C 1" > 10))
+(15 rows)
+
+EXECUTE st2(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st2(101, 121);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+-- subquery using immutable function (can be sent to remote)
+PREPARE st3(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c5) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st3(10, 20);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t1.c3 = t2.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" > 10)) AND ((date(c5) = '1970-01-17'::date))
+(14 rows)
+
+EXECUTE st3(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st3(20, 30);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- custom plan should be chosen initially
+PREPARE st4(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 = $1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+-- once we try it enough times, should switch to generic plan
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(3 rows)
+
+-- value of $1 should not be sent to remote
+PREPARE st5(user_enum,int) AS SELECT * FROM ft1 t1 WHERE c8 = $1 and c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = $1)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(4 rows)
+
+EXECUTE st5('foo', 1);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- altering FDW options requires replanning
+PREPARE st6 AS SELECT * FROM ft1 t1 WHERE t1.c1 = t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(3 rows)
+
+PREPARE st7 AS INSERT INTO ft1 (c1,c2,c3) VALUES (1001,101,'foo');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 1" RENAME TO "T 0";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 0');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 0" WHERE (("C 1" = c2))
+(3 rows)
+
+EXECUTE st6;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 0"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 0" RENAME TO "T 1";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 1');
+PREPARE st8 AS SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+EXECUTE st8;
+ count
+-------
+ 9
+(1 row)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- cleanup
+DEALLOCATE st1;
+DEALLOCATE st2;
+DEALLOCATE st3;
+DEALLOCATE st4;
+DEALLOCATE st5;
+DEALLOCATE st6;
+DEALLOCATE st7;
+DEALLOCATE st8;
+-- System columns, except ctid and oid, should not be sent to remote
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'pg_class'::regclass LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.tableoid = '1259'::oid)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'ft1'::regclass LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: (tableoid)::regclass, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ tableoid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ ft1 | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((ctid = '(0,2)'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: ctid, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ ctid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ (0,1) | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- ===================================================================
+-- used in PL/pgSQL function
+-- ===================================================================
+CREATE OR REPLACE FUNCTION f_test(p_c1 int) RETURNS int AS $$
+DECLARE
+ v_c1 int;
+BEGIN
+ SELECT c1 INTO v_c1 FROM ft1 WHERE c1 = p_c1 LIMIT 1;
+ PERFORM c1 FROM ft1 WHERE c1 = p_c1 AND p_c1 = v_c1 LIMIT 1;
+ RETURN v_c1;
+END;
+$$ LANGUAGE plpgsql;
+SELECT f_test(100);
+ f_test
+--------
+ 100
+(1 row)
+
+DROP FUNCTION f_test(int);
+-- ===================================================================
+-- REINDEX
+-- ===================================================================
+-- remote table is not created here
+CREATE FOREIGN TABLE reindex_foreign (c1 int, c2 int)
+ SERVER loopback2 OPTIONS (table_name 'reindex_local');
+REINDEX TABLE reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+REINDEX TABLE CONCURRENTLY reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+DROP FOREIGN TABLE reindex_foreign;
+-- partitions and foreign tables
+CREATE TABLE reind_fdw_parent (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE reind_fdw_0_10 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (0) TO (10);
+CREATE FOREIGN TABLE reind_fdw_10_20 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (10) TO (20)
+ SERVER loopback OPTIONS (table_name 'reind_local_10_20');
+REINDEX TABLE reind_fdw_parent; -- ok
+REINDEX TABLE CONCURRENTLY reind_fdw_parent; -- ok
+DROP TABLE reind_fdw_parent;
+-- ===================================================================
+-- conversion error
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int;
+SELECT * FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8) WHERE x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx.x8 FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: whole-row reference to foreign table "ftx"
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: processing expression at position 2 in select list
+ANALYZE ft1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "c8" of foreign table "ft1"
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- local type can be different from remote type in some cases,
+-- in particular if similarly-named operators do equivalent things
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE text;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 = 'foo')) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (('foo' = c8)) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- we declared c8 to be text locally, but it's still the same type on
+-- the remote which will balk if we try to do anything incompatible
+-- with that remote type
+SELECT * FROM ft1 WHERE c8 LIKE 'foo' LIMIT 1; -- ERROR
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+SELECT * FROM ft1 WHERE c8::text LIKE 'foo' LIMIT 1; -- ERROR; cast not pushed down
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- subtransaction
+-- + local/remote error doesn't break cursor
+-- ===================================================================
+BEGIN;
+DECLARE c CURSOR FOR SELECT * FROM ft1 ORDER BY c1;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+SAVEPOINT s;
+ERROR OUT; -- ERROR
+ERROR: syntax error at or near "ERROR"
+LINE 1: ERROR OUT;
+ ^
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+SAVEPOINT s;
+SELECT * FROM ft1 WHERE 1 / (c1 - 1) > 0; -- ERROR
+ERROR: division by zero
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (((1 / ("C 1" - 1)) > 0))
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c1 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+COMMIT;
+-- ===================================================================
+-- test handling of collations
+-- ===================================================================
+create table loct3 (f1 text collate "C" unique, f2 text, f3 varchar(10) unique);
+create foreign table ft3 (f1 text collate "C", f2 text, f3 varchar(10))
+ server loopback options (table_name 'loct3', use_remote_estimate 'true');
+-- can be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "C" = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f2 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f3 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 and l.f1 = 'foo';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE (($1::character varying(10) = f3))
+(8 rows)
+
+-- can't be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "POSIX" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f1)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f1 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 COLLATE "C" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f2)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f2 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 COLLATE "POSIX" and l.f1 = 'foo';
+ QUERY PLAN
+-------------------------------------------------------------
+ Hash Join
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ Inner Unique: true
+ Hash Cond: ((f.f3)::text = (l.f3)::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+ -> Hash
+ Output: l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+(12 rows)
+
+-- ===================================================================
+-- test writable foreign table stuff
+-- ===================================================================
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Subquery Scan on "*SELECT*"
+ Output: "*SELECT*"."?column?", "*SELECT*"."?column?_1", NULL::integer, "*SELECT*"."?column?_2", NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+ -> Foreign Scan on public.ft2 ft2_1
+ Output: (ft2_1.c1 + 1000), (ft2_1.c2 + 100), (ft2_1.c3 || ft2_1.c3)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" LIMIT 20::bigint
+(8 rows)
+
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+INSERT INTO ft2 (c1,c2,c3)
+ VALUES (1101,201,'aaa'), (1102,202,'bbb'), (1103,203,'ccc') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----+----+----+----+------------+----
+ 1101 | 201 | aaa | | | | ft2 |
+ 1102 | 202 | bbb | | | | ft2 |
+ 1103 | 203 | ccc | | | | ft2 |
+(3 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1104,204,'ddd'), (1105,205,'eee');
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 300), c3 = (c3 || '_update3') WHERE ((("C 1" % 10) = 3))
+(3 rows)
+
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 400), c3 = (c3 || '_update7') WHERE ((("C 1" % 10) = 7)) RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+(4 rows)
+
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+----+------------+-----
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 1007 | 507 | 0000700007_update7 | | | | ft2 |
+ 1017 | 507 | 0001700017_update7 | | | | ft2 |
+(102 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9; -- can be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c2 = (r1.c2 + 500), c3 = (r1.c3 || '_update9'), c7 = 'ft2 '::character(10) FROM "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 9))
+(3 rows)
+
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9;
+EXPLAIN (verbose, costs off)
+ DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: c1, c4
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 5)) RETURNING "C 1", c4
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4;
+ c1 | c4
+------+------------------------------
+ 5 | Tue Jan 06 00:00:00 1970 PST
+ 15 | Fri Jan 16 00:00:00 1970 PST
+ 25 | Mon Jan 26 00:00:00 1970 PST
+ 35 | Thu Feb 05 00:00:00 1970 PST
+ 45 | Sun Feb 15 00:00:00 1970 PST
+ 55 | Wed Feb 25 00:00:00 1970 PST
+ 65 | Sat Mar 07 00:00:00 1970 PST
+ 75 | Tue Mar 17 00:00:00 1970 PST
+ 85 | Fri Mar 27 00:00:00 1970 PST
+ 95 | Mon Apr 06 00:00:00 1970 PST
+ 105 | Tue Jan 06 00:00:00 1970 PST
+ 115 | Fri Jan 16 00:00:00 1970 PST
+ 125 | Mon Jan 26 00:00:00 1970 PST
+ 135 | Thu Feb 05 00:00:00 1970 PST
+ 145 | Sun Feb 15 00:00:00 1970 PST
+ 155 | Wed Feb 25 00:00:00 1970 PST
+ 165 | Sat Mar 07 00:00:00 1970 PST
+ 175 | Tue Mar 17 00:00:00 1970 PST
+ 185 | Fri Mar 27 00:00:00 1970 PST
+ 195 | Mon Apr 06 00:00:00 1970 PST
+ 205 | Tue Jan 06 00:00:00 1970 PST
+ 215 | Fri Jan 16 00:00:00 1970 PST
+ 225 | Mon Jan 26 00:00:00 1970 PST
+ 235 | Thu Feb 05 00:00:00 1970 PST
+ 245 | Sun Feb 15 00:00:00 1970 PST
+ 255 | Wed Feb 25 00:00:00 1970 PST
+ 265 | Sat Mar 07 00:00:00 1970 PST
+ 275 | Tue Mar 17 00:00:00 1970 PST
+ 285 | Fri Mar 27 00:00:00 1970 PST
+ 295 | Mon Apr 06 00:00:00 1970 PST
+ 305 | Tue Jan 06 00:00:00 1970 PST
+ 315 | Fri Jan 16 00:00:00 1970 PST
+ 325 | Mon Jan 26 00:00:00 1970 PST
+ 335 | Thu Feb 05 00:00:00 1970 PST
+ 345 | Sun Feb 15 00:00:00 1970 PST
+ 355 | Wed Feb 25 00:00:00 1970 PST
+ 365 | Sat Mar 07 00:00:00 1970 PST
+ 375 | Tue Mar 17 00:00:00 1970 PST
+ 385 | Fri Mar 27 00:00:00 1970 PST
+ 395 | Mon Apr 06 00:00:00 1970 PST
+ 405 | Tue Jan 06 00:00:00 1970 PST
+ 415 | Fri Jan 16 00:00:00 1970 PST
+ 425 | Mon Jan 26 00:00:00 1970 PST
+ 435 | Thu Feb 05 00:00:00 1970 PST
+ 445 | Sun Feb 15 00:00:00 1970 PST
+ 455 | Wed Feb 25 00:00:00 1970 PST
+ 465 | Sat Mar 07 00:00:00 1970 PST
+ 475 | Tue Mar 17 00:00:00 1970 PST
+ 485 | Fri Mar 27 00:00:00 1970 PST
+ 495 | Mon Apr 06 00:00:00 1970 PST
+ 505 | Tue Jan 06 00:00:00 1970 PST
+ 515 | Fri Jan 16 00:00:00 1970 PST
+ 525 | Mon Jan 26 00:00:00 1970 PST
+ 535 | Thu Feb 05 00:00:00 1970 PST
+ 545 | Sun Feb 15 00:00:00 1970 PST
+ 555 | Wed Feb 25 00:00:00 1970 PST
+ 565 | Sat Mar 07 00:00:00 1970 PST
+ 575 | Tue Mar 17 00:00:00 1970 PST
+ 585 | Fri Mar 27 00:00:00 1970 PST
+ 595 | Mon Apr 06 00:00:00 1970 PST
+ 605 | Tue Jan 06 00:00:00 1970 PST
+ 615 | Fri Jan 16 00:00:00 1970 PST
+ 625 | Mon Jan 26 00:00:00 1970 PST
+ 635 | Thu Feb 05 00:00:00 1970 PST
+ 645 | Sun Feb 15 00:00:00 1970 PST
+ 655 | Wed Feb 25 00:00:00 1970 PST
+ 665 | Sat Mar 07 00:00:00 1970 PST
+ 675 | Tue Mar 17 00:00:00 1970 PST
+ 685 | Fri Mar 27 00:00:00 1970 PST
+ 695 | Mon Apr 06 00:00:00 1970 PST
+ 705 | Tue Jan 06 00:00:00 1970 PST
+ 715 | Fri Jan 16 00:00:00 1970 PST
+ 725 | Mon Jan 26 00:00:00 1970 PST
+ 735 | Thu Feb 05 00:00:00 1970 PST
+ 745 | Sun Feb 15 00:00:00 1970 PST
+ 755 | Wed Feb 25 00:00:00 1970 PST
+ 765 | Sat Mar 07 00:00:00 1970 PST
+ 775 | Tue Mar 17 00:00:00 1970 PST
+ 785 | Fri Mar 27 00:00:00 1970 PST
+ 795 | Mon Apr 06 00:00:00 1970 PST
+ 805 | Tue Jan 06 00:00:00 1970 PST
+ 815 | Fri Jan 16 00:00:00 1970 PST
+ 825 | Mon Jan 26 00:00:00 1970 PST
+ 835 | Thu Feb 05 00:00:00 1970 PST
+ 845 | Sun Feb 15 00:00:00 1970 PST
+ 855 | Wed Feb 25 00:00:00 1970 PST
+ 865 | Sat Mar 07 00:00:00 1970 PST
+ 875 | Tue Mar 17 00:00:00 1970 PST
+ 885 | Fri Mar 27 00:00:00 1970 PST
+ 895 | Mon Apr 06 00:00:00 1970 PST
+ 905 | Tue Jan 06 00:00:00 1970 PST
+ 915 | Fri Jan 16 00:00:00 1970 PST
+ 925 | Mon Jan 26 00:00:00 1970 PST
+ 935 | Thu Feb 05 00:00:00 1970 PST
+ 945 | Sun Feb 15 00:00:00 1970 PST
+ 955 | Wed Feb 25 00:00:00 1970 PST
+ 965 | Sat Mar 07 00:00:00 1970 PST
+ 975 | Tue Mar 17 00:00:00 1970 PST
+ 985 | Fri Mar 27 00:00:00 1970 PST
+ 995 | Mon Apr 06 00:00:00 1970 PST
+ 1005 |
+ 1015 |
+ 1105 |
+(103 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 2))
+(3 rows)
+
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2;
+SELECT c1,c2,c3,c4 FROM ft2 ORDER BY c1;
+ c1 | c2 | c3 | c4
+------+-----+--------------------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 3 | 303 | 00003_update3 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+ 11 | 1 | 00011 | Mon Jan 12 00:00:00 1970 PST
+ 13 | 303 | 00013_update3 | Wed Jan 14 00:00:00 1970 PST
+ 14 | 4 | 00014 | Thu Jan 15 00:00:00 1970 PST
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST
+ 18 | 8 | 00018 | Mon Jan 19 00:00:00 1970 PST
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST
+ 20 | 0 | 00020 | Wed Jan 21 00:00:00 1970 PST
+ 21 | 1 | 00021 | Thu Jan 22 00:00:00 1970 PST
+ 23 | 303 | 00023_update3 | Sat Jan 24 00:00:00 1970 PST
+ 24 | 4 | 00024 | Sun Jan 25 00:00:00 1970 PST
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST
+ 28 | 8 | 00028 | Thu Jan 29 00:00:00 1970 PST
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST
+ 30 | 0 | 00030 | Sat Jan 31 00:00:00 1970 PST
+ 31 | 1 | 00031 | Sun Feb 01 00:00:00 1970 PST
+ 33 | 303 | 00033_update3 | Tue Feb 03 00:00:00 1970 PST
+ 34 | 4 | 00034 | Wed Feb 04 00:00:00 1970 PST
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST
+ 38 | 8 | 00038 | Sun Feb 08 00:00:00 1970 PST
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST
+ 40 | 0 | 00040 | Tue Feb 10 00:00:00 1970 PST
+ 41 | 1 | 00041 | Wed Feb 11 00:00:00 1970 PST
+ 43 | 303 | 00043_update3 | Fri Feb 13 00:00:00 1970 PST
+ 44 | 4 | 00044 | Sat Feb 14 00:00:00 1970 PST
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST
+ 48 | 8 | 00048 | Wed Feb 18 00:00:00 1970 PST
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST
+ 50 | 0 | 00050 | Fri Feb 20 00:00:00 1970 PST
+ 51 | 1 | 00051 | Sat Feb 21 00:00:00 1970 PST
+ 53 | 303 | 00053_update3 | Mon Feb 23 00:00:00 1970 PST
+ 54 | 4 | 00054 | Tue Feb 24 00:00:00 1970 PST
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST
+ 58 | 8 | 00058 | Sat Feb 28 00:00:00 1970 PST
+ 59 | 509 | 00059_update9 | Sun Mar 01 00:00:00 1970 PST
+ 60 | 0 | 00060 | Mon Mar 02 00:00:00 1970 PST
+ 61 | 1 | 00061 | Tue Mar 03 00:00:00 1970 PST
+ 63 | 303 | 00063_update3 | Thu Mar 05 00:00:00 1970 PST
+ 64 | 4 | 00064 | Fri Mar 06 00:00:00 1970 PST
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST
+ 68 | 8 | 00068 | Tue Mar 10 00:00:00 1970 PST
+ 69 | 509 | 00069_update9 | Wed Mar 11 00:00:00 1970 PST
+ 70 | 0 | 00070 | Thu Mar 12 00:00:00 1970 PST
+ 71 | 1 | 00071 | Fri Mar 13 00:00:00 1970 PST
+ 73 | 303 | 00073_update3 | Sun Mar 15 00:00:00 1970 PST
+ 74 | 4 | 00074 | Mon Mar 16 00:00:00 1970 PST
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST
+ 78 | 8 | 00078 | Fri Mar 20 00:00:00 1970 PST
+ 79 | 509 | 00079_update9 | Sat Mar 21 00:00:00 1970 PST
+ 80 | 0 | 00080 | Sun Mar 22 00:00:00 1970 PST
+ 81 | 1 | 00081 | Mon Mar 23 00:00:00 1970 PST
+ 83 | 303 | 00083_update3 | Wed Mar 25 00:00:00 1970 PST
+ 84 | 4 | 00084 | Thu Mar 26 00:00:00 1970 PST
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST
+ 88 | 8 | 00088 | Mon Mar 30 00:00:00 1970 PST
+ 89 | 509 | 00089_update9 | Tue Mar 31 00:00:00 1970 PST
+ 90 | 0 | 00090 | Wed Apr 01 00:00:00 1970 PST
+ 91 | 1 | 00091 | Thu Apr 02 00:00:00 1970 PST
+ 93 | 303 | 00093_update3 | Sat Apr 04 00:00:00 1970 PST
+ 94 | 4 | 00094 | Sun Apr 05 00:00:00 1970 PST
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST
+ 98 | 8 | 00098 | Thu Apr 09 00:00:00 1970 PST
+ 99 | 509 | 00099_update9 | Fri Apr 10 00:00:00 1970 PST
+ 100 | 0 | 00100 | Thu Jan 01 00:00:00 1970 PST
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST
+ 103 | 303 | 00103_update3 | Sun Jan 04 00:00:00 1970 PST
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST
+ 109 | 509 | 00109_update9 | Sat Jan 10 00:00:00 1970 PST
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST
+ 111 | 1 | 00111 | Mon Jan 12 00:00:00 1970 PST
+ 113 | 303 | 00113_update3 | Wed Jan 14 00:00:00 1970 PST
+ 114 | 4 | 00114 | Thu Jan 15 00:00:00 1970 PST
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST
+ 118 | 8 | 00118 | Mon Jan 19 00:00:00 1970 PST
+ 119 | 509 | 00119_update9 | Tue Jan 20 00:00:00 1970 PST
+ 120 | 0 | 00120 | Wed Jan 21 00:00:00 1970 PST
+ 121 | 1 | 00121 | Thu Jan 22 00:00:00 1970 PST
+ 123 | 303 | 00123_update3 | Sat Jan 24 00:00:00 1970 PST
+ 124 | 4 | 00124 | Sun Jan 25 00:00:00 1970 PST
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST
+ 128 | 8 | 00128 | Thu Jan 29 00:00:00 1970 PST
+ 129 | 509 | 00129_update9 | Fri Jan 30 00:00:00 1970 PST
+ 130 | 0 | 00130 | Sat Jan 31 00:00:00 1970 PST
+ 131 | 1 | 00131 | Sun Feb 01 00:00:00 1970 PST
+ 133 | 303 | 00133_update3 | Tue Feb 03 00:00:00 1970 PST
+ 134 | 4 | 00134 | Wed Feb 04 00:00:00 1970 PST
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST
+ 138 | 8 | 00138 | Sun Feb 08 00:00:00 1970 PST
+ 139 | 509 | 00139_update9 | Mon Feb 09 00:00:00 1970 PST
+ 140 | 0 | 00140 | Tue Feb 10 00:00:00 1970 PST
+ 141 | 1 | 00141 | Wed Feb 11 00:00:00 1970 PST
+ 143 | 303 | 00143_update3 | Fri Feb 13 00:00:00 1970 PST
+ 144 | 4 | 00144 | Sat Feb 14 00:00:00 1970 PST
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST
+ 148 | 8 | 00148 | Wed Feb 18 00:00:00 1970 PST
+ 149 | 509 | 00149_update9 | Thu Feb 19 00:00:00 1970 PST
+ 150 | 0 | 00150 | Fri Feb 20 00:00:00 1970 PST
+ 151 | 1 | 00151 | Sat Feb 21 00:00:00 1970 PST
+ 153 | 303 | 00153_update3 | Mon Feb 23 00:00:00 1970 PST
+ 154 | 4 | 00154 | Tue Feb 24 00:00:00 1970 PST
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST
+ 158 | 8 | 00158 | Sat Feb 28 00:00:00 1970 PST
+ 159 | 509 | 00159_update9 | Sun Mar 01 00:00:00 1970 PST
+ 160 | 0 | 00160 | Mon Mar 02 00:00:00 1970 PST
+ 161 | 1 | 00161 | Tue Mar 03 00:00:00 1970 PST
+ 163 | 303 | 00163_update3 | Thu Mar 05 00:00:00 1970 PST
+ 164 | 4 | 00164 | Fri Mar 06 00:00:00 1970 PST
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST
+ 168 | 8 | 00168 | Tue Mar 10 00:00:00 1970 PST
+ 169 | 509 | 00169_update9 | Wed Mar 11 00:00:00 1970 PST
+ 170 | 0 | 00170 | Thu Mar 12 00:00:00 1970 PST
+ 171 | 1 | 00171 | Fri Mar 13 00:00:00 1970 PST
+ 173 | 303 | 00173_update3 | Sun Mar 15 00:00:00 1970 PST
+ 174 | 4 | 00174 | Mon Mar 16 00:00:00 1970 PST
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST
+ 178 | 8 | 00178 | Fri Mar 20 00:00:00 1970 PST
+ 179 | 509 | 00179_update9 | Sat Mar 21 00:00:00 1970 PST
+ 180 | 0 | 00180 | Sun Mar 22 00:00:00 1970 PST
+ 181 | 1 | 00181 | Mon Mar 23 00:00:00 1970 PST
+ 183 | 303 | 00183_update3 | Wed Mar 25 00:00:00 1970 PST
+ 184 | 4 | 00184 | Thu Mar 26 00:00:00 1970 PST
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST
+ 188 | 8 | 00188 | Mon Mar 30 00:00:00 1970 PST
+ 189 | 509 | 00189_update9 | Tue Mar 31 00:00:00 1970 PST
+ 190 | 0 | 00190 | Wed Apr 01 00:00:00 1970 PST
+ 191 | 1 | 00191 | Thu Apr 02 00:00:00 1970 PST
+ 193 | 303 | 00193_update3 | Sat Apr 04 00:00:00 1970 PST
+ 194 | 4 | 00194 | Sun Apr 05 00:00:00 1970 PST
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST
+ 198 | 8 | 00198 | Thu Apr 09 00:00:00 1970 PST
+ 199 | 509 | 00199_update9 | Fri Apr 10 00:00:00 1970 PST
+ 200 | 0 | 00200 | Thu Jan 01 00:00:00 1970 PST
+ 201 | 1 | 00201 | Fri Jan 02 00:00:00 1970 PST
+ 203 | 303 | 00203_update3 | Sun Jan 04 00:00:00 1970 PST
+ 204 | 4 | 00204 | Mon Jan 05 00:00:00 1970 PST
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST
+ 208 | 8 | 00208 | Fri Jan 09 00:00:00 1970 PST
+ 209 | 509 | 00209_update9 | Sat Jan 10 00:00:00 1970 PST
+ 210 | 0 | 00210 | Sun Jan 11 00:00:00 1970 PST
+ 211 | 1 | 00211 | Mon Jan 12 00:00:00 1970 PST
+ 213 | 303 | 00213_update3 | Wed Jan 14 00:00:00 1970 PST
+ 214 | 4 | 00214 | Thu Jan 15 00:00:00 1970 PST
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST
+ 218 | 8 | 00218 | Mon Jan 19 00:00:00 1970 PST
+ 219 | 509 | 00219_update9 | Tue Jan 20 00:00:00 1970 PST
+ 220 | 0 | 00220 | Wed Jan 21 00:00:00 1970 PST
+ 221 | 1 | 00221 | Thu Jan 22 00:00:00 1970 PST
+ 223 | 303 | 00223_update3 | Sat Jan 24 00:00:00 1970 PST
+ 224 | 4 | 00224 | Sun Jan 25 00:00:00 1970 PST
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST
+ 228 | 8 | 00228 | Thu Jan 29 00:00:00 1970 PST
+ 229 | 509 | 00229_update9 | Fri Jan 30 00:00:00 1970 PST
+ 230 | 0 | 00230 | Sat Jan 31 00:00:00 1970 PST
+ 231 | 1 | 00231 | Sun Feb 01 00:00:00 1970 PST
+ 233 | 303 | 00233_update3 | Tue Feb 03 00:00:00 1970 PST
+ 234 | 4 | 00234 | Wed Feb 04 00:00:00 1970 PST
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST
+ 238 | 8 | 00238 | Sun Feb 08 00:00:00 1970 PST
+ 239 | 509 | 00239_update9 | Mon Feb 09 00:00:00 1970 PST
+ 240 | 0 | 00240 | Tue Feb 10 00:00:00 1970 PST
+ 241 | 1 | 00241 | Wed Feb 11 00:00:00 1970 PST
+ 243 | 303 | 00243_update3 | Fri Feb 13 00:00:00 1970 PST
+ 244 | 4 | 00244 | Sat Feb 14 00:00:00 1970 PST
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST
+ 248 | 8 | 00248 | Wed Feb 18 00:00:00 1970 PST
+ 249 | 509 | 00249_update9 | Thu Feb 19 00:00:00 1970 PST
+ 250 | 0 | 00250 | Fri Feb 20 00:00:00 1970 PST
+ 251 | 1 | 00251 | Sat Feb 21 00:00:00 1970 PST
+ 253 | 303 | 00253_update3 | Mon Feb 23 00:00:00 1970 PST
+ 254 | 4 | 00254 | Tue Feb 24 00:00:00 1970 PST
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST
+ 258 | 8 | 00258 | Sat Feb 28 00:00:00 1970 PST
+ 259 | 509 | 00259_update9 | Sun Mar 01 00:00:00 1970 PST
+ 260 | 0 | 00260 | Mon Mar 02 00:00:00 1970 PST
+ 261 | 1 | 00261 | Tue Mar 03 00:00:00 1970 PST
+ 263 | 303 | 00263_update3 | Thu Mar 05 00:00:00 1970 PST
+ 264 | 4 | 00264 | Fri Mar 06 00:00:00 1970 PST
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST
+ 268 | 8 | 00268 | Tue Mar 10 00:00:00 1970 PST
+ 269 | 509 | 00269_update9 | Wed Mar 11 00:00:00 1970 PST
+ 270 | 0 | 00270 | Thu Mar 12 00:00:00 1970 PST
+ 271 | 1 | 00271 | Fri Mar 13 00:00:00 1970 PST
+ 273 | 303 | 00273_update3 | Sun Mar 15 00:00:00 1970 PST
+ 274 | 4 | 00274 | Mon Mar 16 00:00:00 1970 PST
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST
+ 278 | 8 | 00278 | Fri Mar 20 00:00:00 1970 PST
+ 279 | 509 | 00279_update9 | Sat Mar 21 00:00:00 1970 PST
+ 280 | 0 | 00280 | Sun Mar 22 00:00:00 1970 PST
+ 281 | 1 | 00281 | Mon Mar 23 00:00:00 1970 PST
+ 283 | 303 | 00283_update3 | Wed Mar 25 00:00:00 1970 PST
+ 284 | 4 | 00284 | Thu Mar 26 00:00:00 1970 PST
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST
+ 288 | 8 | 00288 | Mon Mar 30 00:00:00 1970 PST
+ 289 | 509 | 00289_update9 | Tue Mar 31 00:00:00 1970 PST
+ 290 | 0 | 00290 | Wed Apr 01 00:00:00 1970 PST
+ 291 | 1 | 00291 | Thu Apr 02 00:00:00 1970 PST
+ 293 | 303 | 00293_update3 | Sat Apr 04 00:00:00 1970 PST
+ 294 | 4 | 00294 | Sun Apr 05 00:00:00 1970 PST
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST
+ 298 | 8 | 00298 | Thu Apr 09 00:00:00 1970 PST
+ 299 | 509 | 00299_update9 | Fri Apr 10 00:00:00 1970 PST
+ 300 | 0 | 00300 | Thu Jan 01 00:00:00 1970 PST
+ 301 | 1 | 00301 | Fri Jan 02 00:00:00 1970 PST
+ 303 | 303 | 00303_update3 | Sun Jan 04 00:00:00 1970 PST
+ 304 | 4 | 00304 | Mon Jan 05 00:00:00 1970 PST
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST
+ 308 | 8 | 00308 | Fri Jan 09 00:00:00 1970 PST
+ 309 | 509 | 00309_update9 | Sat Jan 10 00:00:00 1970 PST
+ 310 | 0 | 00310 | Sun Jan 11 00:00:00 1970 PST
+ 311 | 1 | 00311 | Mon Jan 12 00:00:00 1970 PST
+ 313 | 303 | 00313_update3 | Wed Jan 14 00:00:00 1970 PST
+ 314 | 4 | 00314 | Thu Jan 15 00:00:00 1970 PST
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST
+ 318 | 8 | 00318 | Mon Jan 19 00:00:00 1970 PST
+ 319 | 509 | 00319_update9 | Tue Jan 20 00:00:00 1970 PST
+ 320 | 0 | 00320 | Wed Jan 21 00:00:00 1970 PST
+ 321 | 1 | 00321 | Thu Jan 22 00:00:00 1970 PST
+ 323 | 303 | 00323_update3 | Sat Jan 24 00:00:00 1970 PST
+ 324 | 4 | 00324 | Sun Jan 25 00:00:00 1970 PST
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST
+ 328 | 8 | 00328 | Thu Jan 29 00:00:00 1970 PST
+ 329 | 509 | 00329_update9 | Fri Jan 30 00:00:00 1970 PST
+ 330 | 0 | 00330 | Sat Jan 31 00:00:00 1970 PST
+ 331 | 1 | 00331 | Sun Feb 01 00:00:00 1970 PST
+ 333 | 303 | 00333_update3 | Tue Feb 03 00:00:00 1970 PST
+ 334 | 4 | 00334 | Wed Feb 04 00:00:00 1970 PST
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST
+ 338 | 8 | 00338 | Sun Feb 08 00:00:00 1970 PST
+ 339 | 509 | 00339_update9 | Mon Feb 09 00:00:00 1970 PST
+ 340 | 0 | 00340 | Tue Feb 10 00:00:00 1970 PST
+ 341 | 1 | 00341 | Wed Feb 11 00:00:00 1970 PST
+ 343 | 303 | 00343_update3 | Fri Feb 13 00:00:00 1970 PST
+ 344 | 4 | 00344 | Sat Feb 14 00:00:00 1970 PST
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST
+ 348 | 8 | 00348 | Wed Feb 18 00:00:00 1970 PST
+ 349 | 509 | 00349_update9 | Thu Feb 19 00:00:00 1970 PST
+ 350 | 0 | 00350 | Fri Feb 20 00:00:00 1970 PST
+ 351 | 1 | 00351 | Sat Feb 21 00:00:00 1970 PST
+ 353 | 303 | 00353_update3 | Mon Feb 23 00:00:00 1970 PST
+ 354 | 4 | 00354 | Tue Feb 24 00:00:00 1970 PST
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST
+ 358 | 8 | 00358 | Sat Feb 28 00:00:00 1970 PST
+ 359 | 509 | 00359_update9 | Sun Mar 01 00:00:00 1970 PST
+ 360 | 0 | 00360 | Mon Mar 02 00:00:00 1970 PST
+ 361 | 1 | 00361 | Tue Mar 03 00:00:00 1970 PST
+ 363 | 303 | 00363_update3 | Thu Mar 05 00:00:00 1970 PST
+ 364 | 4 | 00364 | Fri Mar 06 00:00:00 1970 PST
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST
+ 368 | 8 | 00368 | Tue Mar 10 00:00:00 1970 PST
+ 369 | 509 | 00369_update9 | Wed Mar 11 00:00:00 1970 PST
+ 370 | 0 | 00370 | Thu Mar 12 00:00:00 1970 PST
+ 371 | 1 | 00371 | Fri Mar 13 00:00:00 1970 PST
+ 373 | 303 | 00373_update3 | Sun Mar 15 00:00:00 1970 PST
+ 374 | 4 | 00374 | Mon Mar 16 00:00:00 1970 PST
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST
+ 378 | 8 | 00378 | Fri Mar 20 00:00:00 1970 PST
+ 379 | 509 | 00379_update9 | Sat Mar 21 00:00:00 1970 PST
+ 380 | 0 | 00380 | Sun Mar 22 00:00:00 1970 PST
+ 381 | 1 | 00381 | Mon Mar 23 00:00:00 1970 PST
+ 383 | 303 | 00383_update3 | Wed Mar 25 00:00:00 1970 PST
+ 384 | 4 | 00384 | Thu Mar 26 00:00:00 1970 PST
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST
+ 388 | 8 | 00388 | Mon Mar 30 00:00:00 1970 PST
+ 389 | 509 | 00389_update9 | Tue Mar 31 00:00:00 1970 PST
+ 390 | 0 | 00390 | Wed Apr 01 00:00:00 1970 PST
+ 391 | 1 | 00391 | Thu Apr 02 00:00:00 1970 PST
+ 393 | 303 | 00393_update3 | Sat Apr 04 00:00:00 1970 PST
+ 394 | 4 | 00394 | Sun Apr 05 00:00:00 1970 PST
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST
+ 398 | 8 | 00398 | Thu Apr 09 00:00:00 1970 PST
+ 399 | 509 | 00399_update9 | Fri Apr 10 00:00:00 1970 PST
+ 400 | 0 | 00400 | Thu Jan 01 00:00:00 1970 PST
+ 401 | 1 | 00401 | Fri Jan 02 00:00:00 1970 PST
+ 403 | 303 | 00403_update3 | Sun Jan 04 00:00:00 1970 PST
+ 404 | 4 | 00404 | Mon Jan 05 00:00:00 1970 PST
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST
+ 408 | 8 | 00408 | Fri Jan 09 00:00:00 1970 PST
+ 409 | 509 | 00409_update9 | Sat Jan 10 00:00:00 1970 PST
+ 410 | 0 | 00410 | Sun Jan 11 00:00:00 1970 PST
+ 411 | 1 | 00411 | Mon Jan 12 00:00:00 1970 PST
+ 413 | 303 | 00413_update3 | Wed Jan 14 00:00:00 1970 PST
+ 414 | 4 | 00414 | Thu Jan 15 00:00:00 1970 PST
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST
+ 418 | 8 | 00418 | Mon Jan 19 00:00:00 1970 PST
+ 419 | 509 | 00419_update9 | Tue Jan 20 00:00:00 1970 PST
+ 420 | 0 | 00420 | Wed Jan 21 00:00:00 1970 PST
+ 421 | 1 | 00421 | Thu Jan 22 00:00:00 1970 PST
+ 423 | 303 | 00423_update3 | Sat Jan 24 00:00:00 1970 PST
+ 424 | 4 | 00424 | Sun Jan 25 00:00:00 1970 PST
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST
+ 428 | 8 | 00428 | Thu Jan 29 00:00:00 1970 PST
+ 429 | 509 | 00429_update9 | Fri Jan 30 00:00:00 1970 PST
+ 430 | 0 | 00430 | Sat Jan 31 00:00:00 1970 PST
+ 431 | 1 | 00431 | Sun Feb 01 00:00:00 1970 PST
+ 433 | 303 | 00433_update3 | Tue Feb 03 00:00:00 1970 PST
+ 434 | 4 | 00434 | Wed Feb 04 00:00:00 1970 PST
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST
+ 438 | 8 | 00438 | Sun Feb 08 00:00:00 1970 PST
+ 439 | 509 | 00439_update9 | Mon Feb 09 00:00:00 1970 PST
+ 440 | 0 | 00440 | Tue Feb 10 00:00:00 1970 PST
+ 441 | 1 | 00441 | Wed Feb 11 00:00:00 1970 PST
+ 443 | 303 | 00443_update3 | Fri Feb 13 00:00:00 1970 PST
+ 444 | 4 | 00444 | Sat Feb 14 00:00:00 1970 PST
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST
+ 448 | 8 | 00448 | Wed Feb 18 00:00:00 1970 PST
+ 449 | 509 | 00449_update9 | Thu Feb 19 00:00:00 1970 PST
+ 450 | 0 | 00450 | Fri Feb 20 00:00:00 1970 PST
+ 451 | 1 | 00451 | Sat Feb 21 00:00:00 1970 PST
+ 453 | 303 | 00453_update3 | Mon Feb 23 00:00:00 1970 PST
+ 454 | 4 | 00454 | Tue Feb 24 00:00:00 1970 PST
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST
+ 458 | 8 | 00458 | Sat Feb 28 00:00:00 1970 PST
+ 459 | 509 | 00459_update9 | Sun Mar 01 00:00:00 1970 PST
+ 460 | 0 | 00460 | Mon Mar 02 00:00:00 1970 PST
+ 461 | 1 | 00461 | Tue Mar 03 00:00:00 1970 PST
+ 463 | 303 | 00463_update3 | Thu Mar 05 00:00:00 1970 PST
+ 464 | 4 | 00464 | Fri Mar 06 00:00:00 1970 PST
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST
+ 468 | 8 | 00468 | Tue Mar 10 00:00:00 1970 PST
+ 469 | 509 | 00469_update9 | Wed Mar 11 00:00:00 1970 PST
+ 470 | 0 | 00470 | Thu Mar 12 00:00:00 1970 PST
+ 471 | 1 | 00471 | Fri Mar 13 00:00:00 1970 PST
+ 473 | 303 | 00473_update3 | Sun Mar 15 00:00:00 1970 PST
+ 474 | 4 | 00474 | Mon Mar 16 00:00:00 1970 PST
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST
+ 478 | 8 | 00478 | Fri Mar 20 00:00:00 1970 PST
+ 479 | 509 | 00479_update9 | Sat Mar 21 00:00:00 1970 PST
+ 480 | 0 | 00480 | Sun Mar 22 00:00:00 1970 PST
+ 481 | 1 | 00481 | Mon Mar 23 00:00:00 1970 PST
+ 483 | 303 | 00483_update3 | Wed Mar 25 00:00:00 1970 PST
+ 484 | 4 | 00484 | Thu Mar 26 00:00:00 1970 PST
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST
+ 488 | 8 | 00488 | Mon Mar 30 00:00:00 1970 PST
+ 489 | 509 | 00489_update9 | Tue Mar 31 00:00:00 1970 PST
+ 490 | 0 | 00490 | Wed Apr 01 00:00:00 1970 PST
+ 491 | 1 | 00491 | Thu Apr 02 00:00:00 1970 PST
+ 493 | 303 | 00493_update3 | Sat Apr 04 00:00:00 1970 PST
+ 494 | 4 | 00494 | Sun Apr 05 00:00:00 1970 PST
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST
+ 498 | 8 | 00498 | Thu Apr 09 00:00:00 1970 PST
+ 499 | 509 | 00499_update9 | Fri Apr 10 00:00:00 1970 PST
+ 500 | 0 | 00500 | Thu Jan 01 00:00:00 1970 PST
+ 501 | 1 | 00501 | Fri Jan 02 00:00:00 1970 PST
+ 503 | 303 | 00503_update3 | Sun Jan 04 00:00:00 1970 PST
+ 504 | 4 | 00504 | Mon Jan 05 00:00:00 1970 PST
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST
+ 508 | 8 | 00508 | Fri Jan 09 00:00:00 1970 PST
+ 509 | 509 | 00509_update9 | Sat Jan 10 00:00:00 1970 PST
+ 510 | 0 | 00510 | Sun Jan 11 00:00:00 1970 PST
+ 511 | 1 | 00511 | Mon Jan 12 00:00:00 1970 PST
+ 513 | 303 | 00513_update3 | Wed Jan 14 00:00:00 1970 PST
+ 514 | 4 | 00514 | Thu Jan 15 00:00:00 1970 PST
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST
+ 518 | 8 | 00518 | Mon Jan 19 00:00:00 1970 PST
+ 519 | 509 | 00519_update9 | Tue Jan 20 00:00:00 1970 PST
+ 520 | 0 | 00520 | Wed Jan 21 00:00:00 1970 PST
+ 521 | 1 | 00521 | Thu Jan 22 00:00:00 1970 PST
+ 523 | 303 | 00523_update3 | Sat Jan 24 00:00:00 1970 PST
+ 524 | 4 | 00524 | Sun Jan 25 00:00:00 1970 PST
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST
+ 528 | 8 | 00528 | Thu Jan 29 00:00:00 1970 PST
+ 529 | 509 | 00529_update9 | Fri Jan 30 00:00:00 1970 PST
+ 530 | 0 | 00530 | Sat Jan 31 00:00:00 1970 PST
+ 531 | 1 | 00531 | Sun Feb 01 00:00:00 1970 PST
+ 533 | 303 | 00533_update3 | Tue Feb 03 00:00:00 1970 PST
+ 534 | 4 | 00534 | Wed Feb 04 00:00:00 1970 PST
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST
+ 538 | 8 | 00538 | Sun Feb 08 00:00:00 1970 PST
+ 539 | 509 | 00539_update9 | Mon Feb 09 00:00:00 1970 PST
+ 540 | 0 | 00540 | Tue Feb 10 00:00:00 1970 PST
+ 541 | 1 | 00541 | Wed Feb 11 00:00:00 1970 PST
+ 543 | 303 | 00543_update3 | Fri Feb 13 00:00:00 1970 PST
+ 544 | 4 | 00544 | Sat Feb 14 00:00:00 1970 PST
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST
+ 548 | 8 | 00548 | Wed Feb 18 00:00:00 1970 PST
+ 549 | 509 | 00549_update9 | Thu Feb 19 00:00:00 1970 PST
+ 550 | 0 | 00550 | Fri Feb 20 00:00:00 1970 PST
+ 551 | 1 | 00551 | Sat Feb 21 00:00:00 1970 PST
+ 553 | 303 | 00553_update3 | Mon Feb 23 00:00:00 1970 PST
+ 554 | 4 | 00554 | Tue Feb 24 00:00:00 1970 PST
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST
+ 558 | 8 | 00558 | Sat Feb 28 00:00:00 1970 PST
+ 559 | 509 | 00559_update9 | Sun Mar 01 00:00:00 1970 PST
+ 560 | 0 | 00560 | Mon Mar 02 00:00:00 1970 PST
+ 561 | 1 | 00561 | Tue Mar 03 00:00:00 1970 PST
+ 563 | 303 | 00563_update3 | Thu Mar 05 00:00:00 1970 PST
+ 564 | 4 | 00564 | Fri Mar 06 00:00:00 1970 PST
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST
+ 568 | 8 | 00568 | Tue Mar 10 00:00:00 1970 PST
+ 569 | 509 | 00569_update9 | Wed Mar 11 00:00:00 1970 PST
+ 570 | 0 | 00570 | Thu Mar 12 00:00:00 1970 PST
+ 571 | 1 | 00571 | Fri Mar 13 00:00:00 1970 PST
+ 573 | 303 | 00573_update3 | Sun Mar 15 00:00:00 1970 PST
+ 574 | 4 | 00574 | Mon Mar 16 00:00:00 1970 PST
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST
+ 578 | 8 | 00578 | Fri Mar 20 00:00:00 1970 PST
+ 579 | 509 | 00579_update9 | Sat Mar 21 00:00:00 1970 PST
+ 580 | 0 | 00580 | Sun Mar 22 00:00:00 1970 PST
+ 581 | 1 | 00581 | Mon Mar 23 00:00:00 1970 PST
+ 583 | 303 | 00583_update3 | Wed Mar 25 00:00:00 1970 PST
+ 584 | 4 | 00584 | Thu Mar 26 00:00:00 1970 PST
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST
+ 588 | 8 | 00588 | Mon Mar 30 00:00:00 1970 PST
+ 589 | 509 | 00589_update9 | Tue Mar 31 00:00:00 1970 PST
+ 590 | 0 | 00590 | Wed Apr 01 00:00:00 1970 PST
+ 591 | 1 | 00591 | Thu Apr 02 00:00:00 1970 PST
+ 593 | 303 | 00593_update3 | Sat Apr 04 00:00:00 1970 PST
+ 594 | 4 | 00594 | Sun Apr 05 00:00:00 1970 PST
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST
+ 598 | 8 | 00598 | Thu Apr 09 00:00:00 1970 PST
+ 599 | 509 | 00599_update9 | Fri Apr 10 00:00:00 1970 PST
+ 600 | 0 | 00600 | Thu Jan 01 00:00:00 1970 PST
+ 601 | 1 | 00601 | Fri Jan 02 00:00:00 1970 PST
+ 603 | 303 | 00603_update3 | Sun Jan 04 00:00:00 1970 PST
+ 604 | 4 | 00604 | Mon Jan 05 00:00:00 1970 PST
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST
+ 608 | 8 | 00608 | Fri Jan 09 00:00:00 1970 PST
+ 609 | 509 | 00609_update9 | Sat Jan 10 00:00:00 1970 PST
+ 610 | 0 | 00610 | Sun Jan 11 00:00:00 1970 PST
+ 611 | 1 | 00611 | Mon Jan 12 00:00:00 1970 PST
+ 613 | 303 | 00613_update3 | Wed Jan 14 00:00:00 1970 PST
+ 614 | 4 | 00614 | Thu Jan 15 00:00:00 1970 PST
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST
+ 618 | 8 | 00618 | Mon Jan 19 00:00:00 1970 PST
+ 619 | 509 | 00619_update9 | Tue Jan 20 00:00:00 1970 PST
+ 620 | 0 | 00620 | Wed Jan 21 00:00:00 1970 PST
+ 621 | 1 | 00621 | Thu Jan 22 00:00:00 1970 PST
+ 623 | 303 | 00623_update3 | Sat Jan 24 00:00:00 1970 PST
+ 624 | 4 | 00624 | Sun Jan 25 00:00:00 1970 PST
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST
+ 628 | 8 | 00628 | Thu Jan 29 00:00:00 1970 PST
+ 629 | 509 | 00629_update9 | Fri Jan 30 00:00:00 1970 PST
+ 630 | 0 | 00630 | Sat Jan 31 00:00:00 1970 PST
+ 631 | 1 | 00631 | Sun Feb 01 00:00:00 1970 PST
+ 633 | 303 | 00633_update3 | Tue Feb 03 00:00:00 1970 PST
+ 634 | 4 | 00634 | Wed Feb 04 00:00:00 1970 PST
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST
+ 638 | 8 | 00638 | Sun Feb 08 00:00:00 1970 PST
+ 639 | 509 | 00639_update9 | Mon Feb 09 00:00:00 1970 PST
+ 640 | 0 | 00640 | Tue Feb 10 00:00:00 1970 PST
+ 641 | 1 | 00641 | Wed Feb 11 00:00:00 1970 PST
+ 643 | 303 | 00643_update3 | Fri Feb 13 00:00:00 1970 PST
+ 644 | 4 | 00644 | Sat Feb 14 00:00:00 1970 PST
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST
+ 648 | 8 | 00648 | Wed Feb 18 00:00:00 1970 PST
+ 649 | 509 | 00649_update9 | Thu Feb 19 00:00:00 1970 PST
+ 650 | 0 | 00650 | Fri Feb 20 00:00:00 1970 PST
+ 651 | 1 | 00651 | Sat Feb 21 00:00:00 1970 PST
+ 653 | 303 | 00653_update3 | Mon Feb 23 00:00:00 1970 PST
+ 654 | 4 | 00654 | Tue Feb 24 00:00:00 1970 PST
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST
+ 658 | 8 | 00658 | Sat Feb 28 00:00:00 1970 PST
+ 659 | 509 | 00659_update9 | Sun Mar 01 00:00:00 1970 PST
+ 660 | 0 | 00660 | Mon Mar 02 00:00:00 1970 PST
+ 661 | 1 | 00661 | Tue Mar 03 00:00:00 1970 PST
+ 663 | 303 | 00663_update3 | Thu Mar 05 00:00:00 1970 PST
+ 664 | 4 | 00664 | Fri Mar 06 00:00:00 1970 PST
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST
+ 668 | 8 | 00668 | Tue Mar 10 00:00:00 1970 PST
+ 669 | 509 | 00669_update9 | Wed Mar 11 00:00:00 1970 PST
+ 670 | 0 | 00670 | Thu Mar 12 00:00:00 1970 PST
+ 671 | 1 | 00671 | Fri Mar 13 00:00:00 1970 PST
+ 673 | 303 | 00673_update3 | Sun Mar 15 00:00:00 1970 PST
+ 674 | 4 | 00674 | Mon Mar 16 00:00:00 1970 PST
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST
+ 678 | 8 | 00678 | Fri Mar 20 00:00:00 1970 PST
+ 679 | 509 | 00679_update9 | Sat Mar 21 00:00:00 1970 PST
+ 680 | 0 | 00680 | Sun Mar 22 00:00:00 1970 PST
+ 681 | 1 | 00681 | Mon Mar 23 00:00:00 1970 PST
+ 683 | 303 | 00683_update3 | Wed Mar 25 00:00:00 1970 PST
+ 684 | 4 | 00684 | Thu Mar 26 00:00:00 1970 PST
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST
+ 688 | 8 | 00688 | Mon Mar 30 00:00:00 1970 PST
+ 689 | 509 | 00689_update9 | Tue Mar 31 00:00:00 1970 PST
+ 690 | 0 | 00690 | Wed Apr 01 00:00:00 1970 PST
+ 691 | 1 | 00691 | Thu Apr 02 00:00:00 1970 PST
+ 693 | 303 | 00693_update3 | Sat Apr 04 00:00:00 1970 PST
+ 694 | 4 | 00694 | Sun Apr 05 00:00:00 1970 PST
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST
+ 698 | 8 | 00698 | Thu Apr 09 00:00:00 1970 PST
+ 699 | 509 | 00699_update9 | Fri Apr 10 00:00:00 1970 PST
+ 700 | 0 | 00700 | Thu Jan 01 00:00:00 1970 PST
+ 701 | 1 | 00701 | Fri Jan 02 00:00:00 1970 PST
+ 703 | 303 | 00703_update3 | Sun Jan 04 00:00:00 1970 PST
+ 704 | 4 | 00704 | Mon Jan 05 00:00:00 1970 PST
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST
+ 708 | 8 | 00708 | Fri Jan 09 00:00:00 1970 PST
+ 709 | 509 | 00709_update9 | Sat Jan 10 00:00:00 1970 PST
+ 710 | 0 | 00710 | Sun Jan 11 00:00:00 1970 PST
+ 711 | 1 | 00711 | Mon Jan 12 00:00:00 1970 PST
+ 713 | 303 | 00713_update3 | Wed Jan 14 00:00:00 1970 PST
+ 714 | 4 | 00714 | Thu Jan 15 00:00:00 1970 PST
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST
+ 718 | 8 | 00718 | Mon Jan 19 00:00:00 1970 PST
+ 719 | 509 | 00719_update9 | Tue Jan 20 00:00:00 1970 PST
+ 720 | 0 | 00720 | Wed Jan 21 00:00:00 1970 PST
+ 721 | 1 | 00721 | Thu Jan 22 00:00:00 1970 PST
+ 723 | 303 | 00723_update3 | Sat Jan 24 00:00:00 1970 PST
+ 724 | 4 | 00724 | Sun Jan 25 00:00:00 1970 PST
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST
+ 728 | 8 | 00728 | Thu Jan 29 00:00:00 1970 PST
+ 729 | 509 | 00729_update9 | Fri Jan 30 00:00:00 1970 PST
+ 730 | 0 | 00730 | Sat Jan 31 00:00:00 1970 PST
+ 731 | 1 | 00731 | Sun Feb 01 00:00:00 1970 PST
+ 733 | 303 | 00733_update3 | Tue Feb 03 00:00:00 1970 PST
+ 734 | 4 | 00734 | Wed Feb 04 00:00:00 1970 PST
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST
+ 738 | 8 | 00738 | Sun Feb 08 00:00:00 1970 PST
+ 739 | 509 | 00739_update9 | Mon Feb 09 00:00:00 1970 PST
+ 740 | 0 | 00740 | Tue Feb 10 00:00:00 1970 PST
+ 741 | 1 | 00741 | Wed Feb 11 00:00:00 1970 PST
+ 743 | 303 | 00743_update3 | Fri Feb 13 00:00:00 1970 PST
+ 744 | 4 | 00744 | Sat Feb 14 00:00:00 1970 PST
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST
+ 748 | 8 | 00748 | Wed Feb 18 00:00:00 1970 PST
+ 749 | 509 | 00749_update9 | Thu Feb 19 00:00:00 1970 PST
+ 750 | 0 | 00750 | Fri Feb 20 00:00:00 1970 PST
+ 751 | 1 | 00751 | Sat Feb 21 00:00:00 1970 PST
+ 753 | 303 | 00753_update3 | Mon Feb 23 00:00:00 1970 PST
+ 754 | 4 | 00754 | Tue Feb 24 00:00:00 1970 PST
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST
+ 758 | 8 | 00758 | Sat Feb 28 00:00:00 1970 PST
+ 759 | 509 | 00759_update9 | Sun Mar 01 00:00:00 1970 PST
+ 760 | 0 | 00760 | Mon Mar 02 00:00:00 1970 PST
+ 761 | 1 | 00761 | Tue Mar 03 00:00:00 1970 PST
+ 763 | 303 | 00763_update3 | Thu Mar 05 00:00:00 1970 PST
+ 764 | 4 | 00764 | Fri Mar 06 00:00:00 1970 PST
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST
+ 768 | 8 | 00768 | Tue Mar 10 00:00:00 1970 PST
+ 769 | 509 | 00769_update9 | Wed Mar 11 00:00:00 1970 PST
+ 770 | 0 | 00770 | Thu Mar 12 00:00:00 1970 PST
+ 771 | 1 | 00771 | Fri Mar 13 00:00:00 1970 PST
+ 773 | 303 | 00773_update3 | Sun Mar 15 00:00:00 1970 PST
+ 774 | 4 | 00774 | Mon Mar 16 00:00:00 1970 PST
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST
+ 778 | 8 | 00778 | Fri Mar 20 00:00:00 1970 PST
+ 779 | 509 | 00779_update9 | Sat Mar 21 00:00:00 1970 PST
+ 780 | 0 | 00780 | Sun Mar 22 00:00:00 1970 PST
+ 781 | 1 | 00781 | Mon Mar 23 00:00:00 1970 PST
+ 783 | 303 | 00783_update3 | Wed Mar 25 00:00:00 1970 PST
+ 784 | 4 | 00784 | Thu Mar 26 00:00:00 1970 PST
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST
+ 788 | 8 | 00788 | Mon Mar 30 00:00:00 1970 PST
+ 789 | 509 | 00789_update9 | Tue Mar 31 00:00:00 1970 PST
+ 790 | 0 | 00790 | Wed Apr 01 00:00:00 1970 PST
+ 791 | 1 | 00791 | Thu Apr 02 00:00:00 1970 PST
+ 793 | 303 | 00793_update3 | Sat Apr 04 00:00:00 1970 PST
+ 794 | 4 | 00794 | Sun Apr 05 00:00:00 1970 PST
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST
+ 798 | 8 | 00798 | Thu Apr 09 00:00:00 1970 PST
+ 799 | 509 | 00799_update9 | Fri Apr 10 00:00:00 1970 PST
+ 800 | 0 | 00800 | Thu Jan 01 00:00:00 1970 PST
+ 801 | 1 | 00801 | Fri Jan 02 00:00:00 1970 PST
+ 803 | 303 | 00803_update3 | Sun Jan 04 00:00:00 1970 PST
+ 804 | 4 | 00804 | Mon Jan 05 00:00:00 1970 PST
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST
+ 808 | 8 | 00808 | Fri Jan 09 00:00:00 1970 PST
+ 809 | 509 | 00809_update9 | Sat Jan 10 00:00:00 1970 PST
+ 810 | 0 | 00810 | Sun Jan 11 00:00:00 1970 PST
+ 811 | 1 | 00811 | Mon Jan 12 00:00:00 1970 PST
+ 813 | 303 | 00813_update3 | Wed Jan 14 00:00:00 1970 PST
+ 814 | 4 | 00814 | Thu Jan 15 00:00:00 1970 PST
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST
+ 818 | 8 | 00818 | Mon Jan 19 00:00:00 1970 PST
+ 819 | 509 | 00819_update9 | Tue Jan 20 00:00:00 1970 PST
+ 820 | 0 | 00820 | Wed Jan 21 00:00:00 1970 PST
+ 821 | 1 | 00821 | Thu Jan 22 00:00:00 1970 PST
+ 823 | 303 | 00823_update3 | Sat Jan 24 00:00:00 1970 PST
+ 824 | 4 | 00824 | Sun Jan 25 00:00:00 1970 PST
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST
+ 828 | 8 | 00828 | Thu Jan 29 00:00:00 1970 PST
+ 829 | 509 | 00829_update9 | Fri Jan 30 00:00:00 1970 PST
+ 830 | 0 | 00830 | Sat Jan 31 00:00:00 1970 PST
+ 831 | 1 | 00831 | Sun Feb 01 00:00:00 1970 PST
+ 833 | 303 | 00833_update3 | Tue Feb 03 00:00:00 1970 PST
+ 834 | 4 | 00834 | Wed Feb 04 00:00:00 1970 PST
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST
+ 838 | 8 | 00838 | Sun Feb 08 00:00:00 1970 PST
+ 839 | 509 | 00839_update9 | Mon Feb 09 00:00:00 1970 PST
+ 840 | 0 | 00840 | Tue Feb 10 00:00:00 1970 PST
+ 841 | 1 | 00841 | Wed Feb 11 00:00:00 1970 PST
+ 843 | 303 | 00843_update3 | Fri Feb 13 00:00:00 1970 PST
+ 844 | 4 | 00844 | Sat Feb 14 00:00:00 1970 PST
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST
+ 848 | 8 | 00848 | Wed Feb 18 00:00:00 1970 PST
+ 849 | 509 | 00849_update9 | Thu Feb 19 00:00:00 1970 PST
+ 850 | 0 | 00850 | Fri Feb 20 00:00:00 1970 PST
+ 851 | 1 | 00851 | Sat Feb 21 00:00:00 1970 PST
+ 853 | 303 | 00853_update3 | Mon Feb 23 00:00:00 1970 PST
+ 854 | 4 | 00854 | Tue Feb 24 00:00:00 1970 PST
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST
+ 858 | 8 | 00858 | Sat Feb 28 00:00:00 1970 PST
+ 859 | 509 | 00859_update9 | Sun Mar 01 00:00:00 1970 PST
+ 860 | 0 | 00860 | Mon Mar 02 00:00:00 1970 PST
+ 861 | 1 | 00861 | Tue Mar 03 00:00:00 1970 PST
+ 863 | 303 | 00863_update3 | Thu Mar 05 00:00:00 1970 PST
+ 864 | 4 | 00864 | Fri Mar 06 00:00:00 1970 PST
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST
+ 868 | 8 | 00868 | Tue Mar 10 00:00:00 1970 PST
+ 869 | 509 | 00869_update9 | Wed Mar 11 00:00:00 1970 PST
+ 870 | 0 | 00870 | Thu Mar 12 00:00:00 1970 PST
+ 871 | 1 | 00871 | Fri Mar 13 00:00:00 1970 PST
+ 873 | 303 | 00873_update3 | Sun Mar 15 00:00:00 1970 PST
+ 874 | 4 | 00874 | Mon Mar 16 00:00:00 1970 PST
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST
+ 878 | 8 | 00878 | Fri Mar 20 00:00:00 1970 PST
+ 879 | 509 | 00879_update9 | Sat Mar 21 00:00:00 1970 PST
+ 880 | 0 | 00880 | Sun Mar 22 00:00:00 1970 PST
+ 881 | 1 | 00881 | Mon Mar 23 00:00:00 1970 PST
+ 883 | 303 | 00883_update3 | Wed Mar 25 00:00:00 1970 PST
+ 884 | 4 | 00884 | Thu Mar 26 00:00:00 1970 PST
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST
+ 888 | 8 | 00888 | Mon Mar 30 00:00:00 1970 PST
+ 889 | 509 | 00889_update9 | Tue Mar 31 00:00:00 1970 PST
+ 890 | 0 | 00890 | Wed Apr 01 00:00:00 1970 PST
+ 891 | 1 | 00891 | Thu Apr 02 00:00:00 1970 PST
+ 893 | 303 | 00893_update3 | Sat Apr 04 00:00:00 1970 PST
+ 894 | 4 | 00894 | Sun Apr 05 00:00:00 1970 PST
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST
+ 898 | 8 | 00898 | Thu Apr 09 00:00:00 1970 PST
+ 899 | 509 | 00899_update9 | Fri Apr 10 00:00:00 1970 PST
+ 900 | 0 | 00900 | Thu Jan 01 00:00:00 1970 PST
+ 901 | 1 | 00901 | Fri Jan 02 00:00:00 1970 PST
+ 903 | 303 | 00903_update3 | Sun Jan 04 00:00:00 1970 PST
+ 904 | 4 | 00904 | Mon Jan 05 00:00:00 1970 PST
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST
+ 908 | 8 | 00908 | Fri Jan 09 00:00:00 1970 PST
+ 909 | 509 | 00909_update9 | Sat Jan 10 00:00:00 1970 PST
+ 910 | 0 | 00910 | Sun Jan 11 00:00:00 1970 PST
+ 911 | 1 | 00911 | Mon Jan 12 00:00:00 1970 PST
+ 913 | 303 | 00913_update3 | Wed Jan 14 00:00:00 1970 PST
+ 914 | 4 | 00914 | Thu Jan 15 00:00:00 1970 PST
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST
+ 918 | 8 | 00918 | Mon Jan 19 00:00:00 1970 PST
+ 919 | 509 | 00919_update9 | Tue Jan 20 00:00:00 1970 PST
+ 920 | 0 | 00920 | Wed Jan 21 00:00:00 1970 PST
+ 921 | 1 | 00921 | Thu Jan 22 00:00:00 1970 PST
+ 923 | 303 | 00923_update3 | Sat Jan 24 00:00:00 1970 PST
+ 924 | 4 | 00924 | Sun Jan 25 00:00:00 1970 PST
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST
+ 928 | 8 | 00928 | Thu Jan 29 00:00:00 1970 PST
+ 929 | 509 | 00929_update9 | Fri Jan 30 00:00:00 1970 PST
+ 930 | 0 | 00930 | Sat Jan 31 00:00:00 1970 PST
+ 931 | 1 | 00931 | Sun Feb 01 00:00:00 1970 PST
+ 933 | 303 | 00933_update3 | Tue Feb 03 00:00:00 1970 PST
+ 934 | 4 | 00934 | Wed Feb 04 00:00:00 1970 PST
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST
+ 938 | 8 | 00938 | Sun Feb 08 00:00:00 1970 PST
+ 939 | 509 | 00939_update9 | Mon Feb 09 00:00:00 1970 PST
+ 940 | 0 | 00940 | Tue Feb 10 00:00:00 1970 PST
+ 941 | 1 | 00941 | Wed Feb 11 00:00:00 1970 PST
+ 943 | 303 | 00943_update3 | Fri Feb 13 00:00:00 1970 PST
+ 944 | 4 | 00944 | Sat Feb 14 00:00:00 1970 PST
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST
+ 948 | 8 | 00948 | Wed Feb 18 00:00:00 1970 PST
+ 949 | 509 | 00949_update9 | Thu Feb 19 00:00:00 1970 PST
+ 950 | 0 | 00950 | Fri Feb 20 00:00:00 1970 PST
+ 951 | 1 | 00951 | Sat Feb 21 00:00:00 1970 PST
+ 953 | 303 | 00953_update3 | Mon Feb 23 00:00:00 1970 PST
+ 954 | 4 | 00954 | Tue Feb 24 00:00:00 1970 PST
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST
+ 958 | 8 | 00958 | Sat Feb 28 00:00:00 1970 PST
+ 959 | 509 | 00959_update9 | Sun Mar 01 00:00:00 1970 PST
+ 960 | 0 | 00960 | Mon Mar 02 00:00:00 1970 PST
+ 961 | 1 | 00961 | Tue Mar 03 00:00:00 1970 PST
+ 963 | 303 | 00963_update3 | Thu Mar 05 00:00:00 1970 PST
+ 964 | 4 | 00964 | Fri Mar 06 00:00:00 1970 PST
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST
+ 968 | 8 | 00968 | Tue Mar 10 00:00:00 1970 PST
+ 969 | 509 | 00969_update9 | Wed Mar 11 00:00:00 1970 PST
+ 970 | 0 | 00970 | Thu Mar 12 00:00:00 1970 PST
+ 971 | 1 | 00971 | Fri Mar 13 00:00:00 1970 PST
+ 973 | 303 | 00973_update3 | Sun Mar 15 00:00:00 1970 PST
+ 974 | 4 | 00974 | Mon Mar 16 00:00:00 1970 PST
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST
+ 978 | 8 | 00978 | Fri Mar 20 00:00:00 1970 PST
+ 979 | 509 | 00979_update9 | Sat Mar 21 00:00:00 1970 PST
+ 980 | 0 | 00980 | Sun Mar 22 00:00:00 1970 PST
+ 981 | 1 | 00981 | Mon Mar 23 00:00:00 1970 PST
+ 983 | 303 | 00983_update3 | Wed Mar 25 00:00:00 1970 PST
+ 984 | 4 | 00984 | Thu Mar 26 00:00:00 1970 PST
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST
+ 988 | 8 | 00988 | Mon Mar 30 00:00:00 1970 PST
+ 989 | 509 | 00989_update9 | Tue Mar 31 00:00:00 1970 PST
+ 990 | 0 | 00990 | Wed Apr 01 00:00:00 1970 PST
+ 991 | 1 | 00991 | Thu Apr 02 00:00:00 1970 PST
+ 993 | 303 | 00993_update3 | Sat Apr 04 00:00:00 1970 PST
+ 994 | 4 | 00994 | Sun Apr 05 00:00:00 1970 PST
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST
+ 998 | 8 | 00998 | Thu Apr 09 00:00:00 1970 PST
+ 999 | 509 | 00999_update9 | Fri Apr 10 00:00:00 1970 PST
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST
+ 1001 | 101 | 0000100001 |
+ 1003 | 403 | 0000300003_update3 |
+ 1004 | 104 | 0000400004 |
+ 1006 | 106 | 0000600006 |
+ 1007 | 507 | 0000700007_update7 |
+ 1008 | 108 | 0000800008 |
+ 1009 | 609 | 0000900009_update9 |
+ 1010 | 100 | 0001000010 |
+ 1011 | 101 | 0001100011 |
+ 1013 | 403 | 0001300013_update3 |
+ 1014 | 104 | 0001400014 |
+ 1016 | 106 | 0001600016 |
+ 1017 | 507 | 0001700017_update7 |
+ 1018 | 108 | 0001800018 |
+ 1019 | 609 | 0001900019_update9 |
+ 1020 | 100 | 0002000020 |
+ 1101 | 201 | aaa |
+ 1103 | 503 | ccc_update3 |
+ 1104 | 204 | ddd |
+(819 rows)
+
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Output: (ft2.tableoid)::regclass
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: 1200, 999, NULL::integer, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+(6 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = 'bar'::text WHERE (("C 1" = 1200))
+(4 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------
+ Delete on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE (("C 1" = 1200))
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+-- Test UPDATE/DELETE with RETURNING on a three-table join
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id - 1200, to_char(id, 'FM00000') FROM generate_series(1201, 1300) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.*, ft4.c1, ft4.c2, ft4.c3
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c3 = 'foo'::text FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (TRUE)) WHERE ((r2.c1 = r3.c1)) AND ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) RETURNING r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3
+(4 rows)
+
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*;
+ ft2 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | ft4 | c1 | c2 | c3
+--------------------------------+------+----+-----+----+----+----+------------+----+----------------+----+----+--------
+ (1206,6,foo,,,,"ft2 ",) | 1206 | 6 | foo | | | | ft2 | | (6,7,AAA006) | 6 | 7 | AAA006
+ (1212,12,foo,,,,"ft2 ",) | 1212 | 12 | foo | | | | ft2 | | (12,13,AAA012) | 12 | 13 | AAA012
+ (1218,18,foo,,,,"ft2 ",) | 1218 | 18 | foo | | | | ft2 | | (18,19,AAA018) | 18 | 19 | AAA018
+ (1224,24,foo,,,,"ft2 ",) | 1224 | 24 | foo | | | | ft2 | | (24,25,AAA024) | 24 | 25 | AAA024
+ (1230,30,foo,,,,"ft2 ",) | 1230 | 30 | foo | | | | ft2 | | (30,31,AAA030) | 30 | 31 | AAA030
+ (1236,36,foo,,,,"ft2 ",) | 1236 | 36 | foo | | | | ft2 | | (36,37,AAA036) | 36 | 37 | AAA036
+ (1242,42,foo,,,,"ft2 ",) | 1242 | 42 | foo | | | | ft2 | | (42,43,AAA042) | 42 | 43 | AAA042
+ (1248,48,foo,,,,"ft2 ",) | 1248 | 48 | foo | | | | ft2 | | (48,49,AAA048) | 48 | 49 | AAA048
+ (1254,54,foo,,,,"ft2 ",) | 1254 | 54 | foo | | | | ft2 | | (54,55,AAA054) | 54 | 55 | AAA054
+ (1260,60,foo,,,,"ft2 ",) | 1260 | 60 | foo | | | | ft2 | | (60,61,AAA060) | 60 | 61 | AAA060
+ (1266,66,foo,,,,"ft2 ",) | 1266 | 66 | foo | | | | ft2 | | (66,67,AAA066) | 66 | 67 | AAA066
+ (1272,72,foo,,,,"ft2 ",) | 1272 | 72 | foo | | | | ft2 | | (72,73,AAA072) | 72 | 73 | AAA072
+ (1278,78,foo,,,,"ft2 ",) | 1278 | 78 | foo | | | | ft2 | | (78,79,AAA078) | 78 | 79 | AAA078
+ (1284,84,foo,,,,"ft2 ",) | 1284 | 84 | foo | | | | ft2 | | (84,85,AAA084) | 84 | 85 | AAA084
+ (1290,90,foo,,,,"ft2 ",) | 1290 | 90 | foo | | | | ft2 | | (90,91,AAA090) | 90 | 91 | AAA090
+ (1296,96,foo,,,,"ft2 ",) | 1296 | 96 | foo | | | | ft2 | | (96,97,AAA096) | 96 | 97 | AAA096
+(16 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: 100
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1)))) WHERE ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) AND (((r1."C 1" % 10) = 0))
+(4 rows)
+
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100;
+ ?column?
+----------
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+(10 rows)
+
+DELETE FROM ft2 WHERE ft2.c1 > 1200;
+-- Test UPDATE with a MULTIEXPR sub-select
+-- (maybe someday this'll be remotely executable, but not today)
+EXPLAIN (verbose, costs off)
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 target
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2, c7 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.ft2 target
+ Output: $1, $2, (SubPlan 1 (returns $1,$2)), target.ctid, target.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1100)) FOR UPDATE
+ SubPlan 1 (returns $1,$2)
+ -> Foreign Scan on public.ft2 src
+ Output: (src.c2 * 10), src.c7
+ Remote SQL: SELECT c2, c7 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(9 rows)
+
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+UPDATE ft2 AS target SET (c2) = (
+ SELECT c2 / 10
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+-- Test UPDATE involving a join that can be pushed down,
+-- but a SET clause that can't be
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 d
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2 WHERE ctid = $1
+ -> Foreign Scan
+ Output: CASE WHEN (random() >= '0'::double precision) THEN d.c2 ELSE 0 END, d.ctid, d.*, t.*
+ Relations: (public.ft2 d) INNER JOIN (public.ft2 t)
+ Remote SQL: SELECT r1.c2, r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r1."C 1" > 1000)))) FOR UPDATE OF r1
+ -> Hash Join
+ Output: d.c2, d.ctid, d.*, t.*
+ Hash Cond: (d.c1 = t.c1)
+ -> Foreign Scan on public.ft2 d
+ Output: d.c2, d.ctid, d.*, d.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1000)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Hash
+ Output: t.*, t.c1
+ -> Foreign Scan on public.ft2 t
+ Output: t.*, t.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(17 rows)
+
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+-- Test UPDATE/DELETE with WHERE or JOIN/ON conditions containing
+-- user-defined operators/functions
+ALTER SERVER loopback OPTIONS (DROP extensions);
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id % 10, to_char(id, 'FM00000') FROM generate_series(2001, 2010) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft2
+ Output: 'bar'::text, ctid, ft2.*
+ Filter: (postgres_fdw_abs(ft2.c1) > 2000)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" FOR UPDATE
+(7 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-----+----+----+----+------------+----
+ 2001 | 1 | bar | | | | ft2 |
+ 2002 | 2 | bar | | | | ft2 |
+ 2003 | 3 | bar | | | | ft2 |
+ 2004 | 4 | bar | | | | ft2 |
+ 2005 | 5 | bar | | | | ft2 |
+ 2006 | 6 | bar | | | | ft2 |
+ 2007 | 7 | bar | | | | ft2 |
+ 2008 | 8 | bar | | | | ft2 |
+ 2009 | 9 | bar | | | | ft2 |
+ 2010 | 0 | bar | | | | ft2 |
+(10 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Nested Loop
+ Output: 'baz'::text, ft2.ctid, ft2.*, ft4.*, ft5.*, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Join Filter: (ft2.c2 === ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.*, ft2.c2
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Relations: (public.ft4) INNER JOIN (public.ft5)
+ Remote SQL: SELECT CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r3.c1, r3.c2, r3.c3 FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1))))
+ -> Hash Join
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(24 rows)
+
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3
+------+----+-----+----+----+----+------------+----+----+----+--------+----+----+--------
+ 2006 | 6 | baz | | | | ft2 | | 6 | 7 | AAA006 | 6 | 7 | AAA006
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ctid = $1 RETURNING "C 1", c2, c3
+ -> Foreign Scan
+ Output: ft2.ctid, ft4.*, ft5.*
+ Filter: (ft4.c1 === ft5.c1)
+ Relations: ((public.ft2) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r2.c1, r3.c1 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c2 = r2.c1)) AND ((r1."C 1" > 2000)))) INNER JOIN "S 1"."T 4" r3 ON (TRUE)) FOR UPDATE OF r1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft5.*, ft4.c1, ft5.c1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft4.c1
+ Join Filter: (ft2.c2 = ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.c2
+ Remote SQL: SELECT c2, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(22 rows)
+
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3;
+ c1 | c2 | c3
+------+----+-----
+ 2006 | 6 | baz
+(1 row)
+
+DELETE FROM ft2 WHERE ft2.c1 > 2000;
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- Test that trigger on remote table works as expected
+CREATE OR REPLACE FUNCTION "S 1".F_BRTRIG() RETURNS trigger AS $$
+BEGIN
+ NEW.c3 = NEW.c3 || '_trig_update';
+ RETURN NEW;
+END;
+$$ LANGUAGE plpgsql;
+CREATE TRIGGER t1_br_insert BEFORE INSERT OR UPDATE
+ ON "S 1"."T 1" FOR EACH ROW EXECUTE PROCEDURE "S 1".F_BRTRIG();
+INSERT INTO ft2 (c1,c2,c3) VALUES (1208, 818, 'fff') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+----+------------+----
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+(1 row)
+
+INSERT INTO ft2 (c1,c2,c3,c6) VALUES (1218, 818, 'ggg', '(--;') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+------+------------+----
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+(1 row)
+
+UPDATE ft2 SET c2 = c2 + 600 WHERE c1 % 10 = 8 AND c1 < 1200 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+------------------------+------------------------------+--------------------------+----+------------+-----
+ 8 | 608 | 00008_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 18 | 608 | 00018_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 28 | 608 | 00028_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 38 | 608 | 00038_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 48 | 608 | 00048_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 58 | 608 | 00058_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 68 | 608 | 00068_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 78 | 608 | 00078_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 88 | 608 | 00088_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 98 | 608 | 00098_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 108 | 608 | 00108_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 118 | 608 | 00118_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 128 | 608 | 00128_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 138 | 608 | 00138_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 148 | 608 | 00148_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 158 | 608 | 00158_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 168 | 608 | 00168_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 178 | 608 | 00178_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 188 | 608 | 00188_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 198 | 608 | 00198_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 208 | 608 | 00208_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 218 | 608 | 00218_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 228 | 608 | 00228_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 238 | 608 | 00238_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 248 | 608 | 00248_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 258 | 608 | 00258_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 268 | 608 | 00268_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 278 | 608 | 00278_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 288 | 608 | 00288_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 298 | 608 | 00298_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 308 | 608 | 00308_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 318 | 608 | 00318_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 328 | 608 | 00328_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 338 | 608 | 00338_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 348 | 608 | 00348_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 358 | 608 | 00358_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 368 | 608 | 00368_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 378 | 608 | 00378_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 388 | 608 | 00388_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 398 | 608 | 00398_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 408 | 608 | 00408_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 418 | 608 | 00418_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 428 | 608 | 00428_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 438 | 608 | 00438_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 448 | 608 | 00448_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 458 | 608 | 00458_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 468 | 608 | 00468_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 478 | 608 | 00478_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 488 | 608 | 00488_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 498 | 608 | 00498_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 508 | 608 | 00508_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 518 | 608 | 00518_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 528 | 608 | 00528_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 538 | 608 | 00538_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 548 | 608 | 00548_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 558 | 608 | 00558_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 568 | 608 | 00568_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 578 | 608 | 00578_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 588 | 608 | 00588_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 598 | 608 | 00598_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 608 | 608 | 00608_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 618 | 608 | 00618_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 628 | 608 | 00628_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 638 | 608 | 00638_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 648 | 608 | 00648_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 658 | 608 | 00658_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 668 | 608 | 00668_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 678 | 608 | 00678_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 688 | 608 | 00688_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 698 | 608 | 00698_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 708 | 608 | 00708_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 718 | 608 | 00718_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 728 | 608 | 00728_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 738 | 608 | 00738_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 748 | 608 | 00748_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 758 | 608 | 00758_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 768 | 608 | 00768_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 778 | 608 | 00778_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 788 | 608 | 00788_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 798 | 608 | 00798_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 808 | 608 | 00808_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 818 | 608 | 00818_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 828 | 608 | 00828_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 838 | 608 | 00838_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 848 | 608 | 00848_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 858 | 608 | 00858_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 868 | 608 | 00868_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 878 | 608 | 00878_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 888 | 608 | 00888_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 898 | 608 | 00898_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 908 | 608 | 00908_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 918 | 608 | 00918_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 928 | 608 | 00928_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 938 | 608 | 00938_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 948 | 608 | 00948_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 958 | 608 | 00958_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 968 | 608 | 00968_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 978 | 608 | 00978_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 988 | 608 | 00988_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 998 | 608 | 00998_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 1008 | 708 | 0000800008_trig_update | | | | ft2 |
+ 1018 | 708 | 0001800018_trig_update | | | | ft2 |
+(102 rows)
+
+-- Test errors thrown on remote side during update
+ALTER TABLE "S 1"."T 1" ADD CONSTRAINT c2positive CHECK (c2 >= 0);
+INSERT INTO ft1(c1, c2) VALUES(11, 12); -- duplicate key
+ERROR: duplicate key value violates unique constraint "t1_pkey"
+DETAIL: Key ("C 1")=(11) already exists.
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT DO NOTHING; -- works
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO NOTHING; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO UPDATE SET c3 = 'ffg'; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+-- Test savepoint/rollback behavior
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+begin;
+update ft2 set c2 = 42 where c2 = 0;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 42 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s1;
+update ft2 set c2 = 44 where c2 = 4;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s1;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s2;
+update ft2 set c2 = 46 where c2 = 6;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 42 | 100
+ 44 | 100
+ 46 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+rollback to savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s3;
+update ft2 set c2 = -2 where c2 = 42 and c1 = 10; -- fail on remote side
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (10, -2, 00010_trig_update_trig_update, 1970-01-11 08:00:00+00, 1970-01-11 00:00:00, 0, 0 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (-2) WHERE ((c2 = 42)) AND (("C 1" = 10))
+rollback to savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+-- none of the above is committed yet remotely
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+commit;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+VACUUM ANALYZE "S 1"."T 1";
+-- Above DMLs add data with c6 as NULL in ft1, so test ORDER BY NULLS LAST and NULLs
+-- FIRST behavior here.
+-- ORDER BY DESC NULLS LAST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 795::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+------+------------+-----
+ 960 | 42 | 00960_trig_update | Mon Mar 02 00:00:00 1970 PST | Mon Mar 02 00:00:00 1970 | 0 | 0 | foo
+ 970 | 42 | 00970_trig_update | Thu Mar 12 00:00:00 1970 PST | Thu Mar 12 00:00:00 1970 | 0 | 0 | foo
+ 980 | 42 | 00980_trig_update | Sun Mar 22 00:00:00 1970 PST | Sun Mar 22 00:00:00 1970 | 0 | 0 | foo
+ 990 | 42 | 00990_trig_update | Wed Apr 01 00:00:00 1970 PST | Wed Apr 01 00:00:00 1970 | 0 | 0 | foo
+ 1000 | 42 | 01000_trig_update | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 1001 | 101 | 0000100001 | | | | ft2 |
+ 1003 | 403 | 0000300003_update3 | | | | ft2 |
+ 1004 | 104 | 0000400004 | | | | ft2 |
+ 1006 | 106 | 0000600006 | | | | ft2 |
+(10 rows)
+
+-- ORDER BY DESC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+------------------------------+--------------------------+----+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | ft2 | foo
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST | Tue Jan 20 00:00:00 1970 | 9 | ft2 | foo
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST | Fri Jan 30 00:00:00 1970 | 9 | ft2 | foo
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST | Mon Feb 09 00:00:00 1970 | 9 | ft2 | foo
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST | Thu Feb 19 00:00:00 1970 | 9 | ft2 | foo
+(10 rows)
+
+-- ORDER BY ASC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 ASC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-------------------+------------------------------+--------------------------+------+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 10 | 42 | 00010_trig_update | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+ 20 | 42 | 00020_trig_update | Wed Jan 21 00:00:00 1970 PST | Wed Jan 21 00:00:00 1970 | 0 | 0 | foo
+ 30 | 42 | 00030_trig_update | Sat Jan 31 00:00:00 1970 PST | Sat Jan 31 00:00:00 1970 | 0 | 0 | foo
+ 40 | 42 | 00040_trig_update | Tue Feb 10 00:00:00 1970 PST | Tue Feb 10 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- ===================================================================
+-- test check constraints
+-- ===================================================================
+-- Consistent check constraints provide consistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- check constraint is enforced on the remote side, not locally
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
+-- But inconsistent check constraints provide inconsistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 821
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- local check constraint is not actually enforced
+INSERT INTO ft1(c1, c2) VALUES(1111, 2);
+UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
+-- ===================================================================
+-- test WITH CHECK OPTION constraints
+-- ===================================================================
+CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
+CREATE TABLE base_tbl (a int, b int);
+ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE VIEW rw_view AS SELECT * FROM foreign_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT foreign_tbl.a,
+ foreign_tbl.b
+ FROM foreign_tbl
+ WHERE foreign_tbl.a < foreign_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 5
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 15
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 5), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 15), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP TRIGGER row_before_insupd_trigger ON base_tbl;
+DROP TABLE base_tbl;
+-- test WCO for partitions
+CREATE TABLE child_tbl (a int, b int);
+ALTER TABLE child_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON child_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'child_tbl');
+CREATE TABLE parent_tbl (a int, b int) PARTITION BY RANGE(a);
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+-- Detach and re-attach once, to stress the concurrent detach case.
+ALTER TABLE parent_tbl DETACH PARTITION foreign_tbl CONCURRENTLY;
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+CREATE VIEW rw_view AS SELECT * FROM parent_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT parent_tbl.a,
+ parent_tbl.b
+ FROM parent_tbl
+ WHERE parent_tbl.a < parent_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 5
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 15
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 5), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 15), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------
+ Insert on public.parent_tbl
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+DROP TRIGGER row_before_insupd_trigger ON child_tbl;
+DROP TABLE parent_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP FUNCTION row_before_insupd_trigfunc;
+-- ===================================================================
+-- test serial columns (ie, sequence-based defaults)
+-- ===================================================================
+create table loc1 (f1 serial, f2 text);
+alter table loc1 set (autovacuum_enabled = 'false');
+create foreign table rem1 (f1 serial, f2 text)
+ server loopback options(table_name 'loc1');
+select pg_catalog.setval('rem1_f1_seq', 10, false);
+ setval
+--------
+ 10
+(1 row)
+
+insert into loc1(f2) values('hi');
+insert into rem1(f2) values('hi remote');
+insert into loc1(f2) values('bye');
+insert into rem1(f2) values('bye remote');
+select * from loc1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+select * from rem1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+-- ===================================================================
+-- test generated columns
+-- ===================================================================
+create table gloc1 (
+ a int,
+ b int generated always as (a * 2) stored);
+alter table gloc1 set (autovacuum_enabled = 'false');
+create foreign table grem1 (
+ a int,
+ b int generated always as (a * 2) stored)
+ server loopback options(table_name 'gloc1');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+explain (verbose, costs off)
+update grem1 set a = 22 where a = 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.grem1
+ Remote SQL: UPDATE public.gloc1 SET a = $2, b = DEFAULT WHERE ctid = $1
+ -> Foreign Scan on public.grem1
+ Output: 22, ctid, grem1.*
+ Remote SQL: SELECT a, b, ctid FROM public.gloc1 WHERE ((a = 2)) FOR UPDATE
+(5 rows)
+
+update grem1 set a = 22 where a = 2;
+select * from gloc1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+select * from grem1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+delete from grem1;
+-- test copy from
+copy grem1 from stdin;
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+-- test batch insert
+alter server loopback options (add batch_size '10');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 10
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test local triggers
+-- ===================================================================
+-- Trigger functions "borrowed" from triggers regress test.
+CREATE FUNCTION trigger_func() RETURNS trigger LANGUAGE plpgsql AS $$
+BEGIN
+ RAISE NOTICE 'trigger_func(%) called: action = %, when = %, level = %',
+ TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN NULL;
+END;$$;
+CREATE TRIGGER trig_stmt_before BEFORE DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE TRIGGER trig_stmt_after AFTER DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE OR REPLACE FUNCTION trigger_data() RETURNS trigger
+LANGUAGE plpgsql AS $$
+
+declare
+ oldnew text[];
+ relid text;
+ argstr text;
+begin
+
+ relid := TG_relid::regclass;
+ argstr := '';
+ for i in 0 .. TG_nargs - 1 loop
+ if i > 0 then
+ argstr := argstr || ', ';
+ end if;
+ argstr := argstr || TG_argv[i];
+ end loop;
+
+ RAISE NOTICE '%(%) % % % ON %',
+ tg_name, argstr, TG_when, TG_level, TG_OP, relid;
+ oldnew := '{}'::text[];
+ if TG_OP != 'INSERT' then
+ oldnew := array_append(oldnew, format('OLD: %s', OLD));
+ end if;
+
+ if TG_OP != 'DELETE' then
+ oldnew := array_append(oldnew, format('NEW: %s', NEW));
+ end if;
+
+ RAISE NOTICE '%', array_to_string(oldnew, ',');
+
+ if TG_OP = 'DELETE' then
+ return OLD;
+ else
+ return NEW;
+ end if;
+end;
+$$;
+-- Test basic functionality
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+delete from rem1;
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = AFTER, level = STATEMENT
+insert into rem1 values(1,'insert');
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+update rem1 set f2 = f2 || f2;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+truncate rem1;
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = BEFORE, level = STATEMENT
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = AFTER, level = STATEMENT
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_stmt_before ON rem1;
+DROP TRIGGER trig_stmt_after ON rem1;
+DELETE from rem1;
+-- Test multiple AFTER ROW triggers on a foreign table
+CREATE TRIGGER trig_row_after1
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after2
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+insert into rem1 values(1,'insert');
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+update rem1 set f2 = f2 || f2;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+delete from rem1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+-- cleanup
+DROP TRIGGER trig_row_after1 ON rem1;
+DROP TRIGGER trig_row_after2 ON rem1;
+-- Test WHEN conditions
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_insupd
+AFTER INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Insert or update not matching: nothing happens
+INSERT INTO rem1 values(1, 'insert');
+UPDATE rem1 set f2 = 'test';
+-- Insert or update matching: triggers are fired
+INSERT INTO rem1 values(2, 'update');
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+UPDATE rem1 set f2 = 'update update' where f1 = '2';
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Trigger is fired for f1=2, not for f1=1
+DELETE FROM rem1;
+NOTICE: trig_row_before_delete(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+NOTICE: trig_row_after_delete(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+-- cleanup
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_after_insupd ON rem1;
+DROP TRIGGER trig_row_before_delete ON rem1;
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- Test various RETURN statements in BEFORE triggers.
+CREATE FUNCTION trig_row_before_insupdate() RETURNS TRIGGER AS $$
+ BEGIN
+ NEW.f2 := NEW.f2 || ' triggered !';
+ RETURN NEW;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+-- The new values should have 'triggered' appended
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------
+ insert triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+ 2 | insert triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------
+ 1 | triggered !
+ 2 | triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------
+ skidoo triggered !
+ skidoo triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | skidoo triggered !
+ 2 | skidoo triggered !
+(2 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f1 = 10; -- all columns should be transmitted
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: 10, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+UPDATE rem1 set f1 = 10;
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 10 | skidoo triggered ! triggered !
+ 10 | skidoo triggered ! triggered !
+(2 rows)
+
+DELETE FROM rem1;
+-- Add a second trigger, to check that the changes are propagated correctly
+-- from trigger to trigger
+CREATE TRIGGER trig_row_before_insupd2
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------------------
+ insert triggered ! triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+ 2 | insert triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------
+ 1 | triggered ! triggered !
+ 2 | triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------------------
+ skidoo triggered ! triggered !
+ skidoo triggered ! triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | skidoo triggered ! triggered !
+ 2 | skidoo triggered ! triggered !
+(2 rows)
+
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_before_insupd2 ON rem1;
+DELETE from rem1;
+INSERT INTO rem1 VALUES (1, 'test');
+-- Test with a trigger returning NULL
+CREATE FUNCTION trig_null() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_null
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_null();
+-- Nothing should have changed.
+INSERT INTO rem1 VALUES (2, 'test2');
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+UPDATE rem1 SET f2 = 'test2';
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DELETE from rem1;
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DROP TRIGGER trig_null ON rem1;
+DELETE from rem1;
+-- Test a combination of local and remote triggers
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_local_before BEFORE INSERT OR UPDATE ON loc1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1(f2) VALUES ('test');
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (12,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (12,"test triggered !")
+UPDATE rem1 SET f2 = 'testo';
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,testo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,"testo triggered !")
+-- Test returning a system attribute
+INSERT INTO rem1(f2) VALUES ('test') RETURNING ctid;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (13,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (13,"test triggered !")
+ ctid
+--------
+ (0,25)
+(1 row)
+
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_local_before ON loc1;
+-- Test direct foreign table modification functionality
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1 WHERE false; -- currently can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Result
+ Output: ctid
+ One-Time Filter: false
+(5 rows)
+
+-- Test with statement-level triggers
+CREATE TRIGGER trig_stmt_before
+ BEFORE DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_before ON rem1;
+CREATE TRIGGER trig_stmt_after
+ AFTER DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_after ON rem1;
+-- Test with row-level ON INSERT triggers
+CREATE TRIGGER trig_row_before_insert
+BEFORE INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_insert ON rem1;
+CREATE TRIGGER trig_row_after_insert
+AFTER INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_insert ON rem1;
+-- Test with row-level ON UPDATE triggers
+CREATE TRIGGER trig_row_before_update
+BEFORE UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_update ON rem1;
+CREATE TRIGGER trig_row_after_update
+AFTER UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = $2 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_update ON rem1;
+-- Test with row-level ON DELETE triggers
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_before_delete ON rem1;
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- ===================================================================
+-- test inheritance features
+-- ===================================================================
+CREATE TABLE a (aa TEXT);
+CREATE TABLE loct (aa TEXT, bb TEXT);
+ALTER TABLE a SET (autovacuum_enabled = 'false');
+ALTER TABLE loct SET (autovacuum_enabled = 'false');
+CREATE FOREIGN TABLE b (bb TEXT) INHERITS (a)
+ SERVER loopback OPTIONS (table_name 'loct');
+INSERT INTO a(aa) VALUES('aaa');
+INSERT INTO a(aa) VALUES('aaaa');
+INSERT INTO a(aa) VALUES('aaaaa');
+INSERT INTO b(aa) VALUES('bbb');
+INSERT INTO b(aa) VALUES('bbbb');
+INSERT INTO b(aa) VALUES('bbbbb');
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+(3 rows)
+
+UPDATE a SET aa = 'zzzzzz' WHERE aa LIKE 'aaaa%';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE b SET aa = 'new';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | new
+ b | new
+ b | new
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-----+----
+ b | new |
+ b | new |
+ b | new |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE a SET aa = 'newtoo';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+ b | newtoo
+ b | newtoo
+ b | newtoo
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+--------+----
+ b | newtoo |
+ b | newtoo |
+ b | newtoo |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+(3 rows)
+
+DELETE FROM a;
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+----+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+DROP TABLE a CASCADE;
+NOTICE: drop cascades to foreign table b
+DROP TABLE loct;
+-- Check SELECT FOR UPDATE/SHARE with an inherited source table
+create table loct1 (f1 int, f2 int, f3 int);
+create table loct2 (f1 int, f2 int, f3 int);
+alter table loct1 set (autovacuum_enabled = 'false');
+alter table loct2 set (autovacuum_enabled = 'false');
+create table foo (f1 int, f2 int);
+create foreign table foo2 (f3 int) inherits (foo)
+ server loopback options (table_name 'loct1');
+create table bar (f1 int, f2 int);
+create foreign table bar2 (f3 int) inherits (bar)
+ server loopback options (table_name 'loct2');
+alter table foo set (autovacuum_enabled = 'false');
+alter table bar set (autovacuum_enabled = 'false');
+insert into foo values(1,1);
+insert into foo values(3,3);
+insert into foo2 values(2,2,2);
+insert into foo2 values(4,4,4);
+insert into bar values(1,11);
+insert into bar values(2,22);
+insert into bar values(6,66);
+insert into bar2 values(3,33,33);
+insert into bar2 values(4,44,44);
+insert into bar2 values(7,77,77);
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for update;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for update;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for share;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for share;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+-- Now check SELECT FOR UPDATE/SHARE with an inherited source table,
+-- where the parent is itself a foreign table
+create table loct4 (f1 int, f2 int, f3 int);
+create foreign table foo2child (f3 int) inherits (foo2)
+ server loopback options (table_name 'loct4');
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct1
+ -> Foreign Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct4
+(24 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop foreign table foo2child;
+-- And with a local child relation of the foreign table parent
+create table foo2child (f3 int) inherits (foo2);
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.ctid, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+ -> Seq Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.ctid, foo2_2.tableoid
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop table foo2child;
+-- Check UPDATE with inherited target and an inherited source table
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Hash Join
+ Output: (bar.f2 + 100), foo.ctid, bar.tableoid, bar.ctid, (NULL::record), foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(25 rows)
+
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 111
+ bar | 2 | 122
+ bar | 6 | 66
+ bar2 | 3 | 133
+ bar2 | 4 | 144
+ bar2 | 7 | 77
+(6 rows)
+
+-- Check UPDATE with inherited target and an appendrel subquery
+explain (verbose, costs off)
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Merge Join
+ Output: (bar.f2 + 100), (ROW(foo.f1)), bar.tableoid, bar.ctid, (NULL::record)
+ Merge Cond: (bar.f1 = foo.f1)
+ -> Sort
+ Output: bar.f2, bar.f1, bar.tableoid, bar.ctid, (NULL::record)
+ Sort Key: bar.f1
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Sort
+ Output: (ROW(foo.f1)), foo.f1
+ Sort Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: ROW(foo.f1), foo.f1
+ -> Foreign Scan on public.foo2 foo_1
+ Output: ROW(foo_1.f1), foo_1.f1
+ Remote SQL: SELECT f1 FROM public.loct1
+ -> Seq Scan on public.foo foo_2
+ Output: ROW((foo_2.f1 + 3)), (foo_2.f1 + 3)
+ -> Foreign Scan on public.foo2 foo_3
+ Output: ROW((foo_3.f1 + 3)), (foo_3.f1 + 3)
+ Remote SQL: SELECT f1 FROM public.loct1
+(30 rows)
+
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 211
+ bar | 2 | 222
+ bar | 6 | 166
+ bar2 | 3 | 233
+ bar2 | 4 | 244
+ bar2 | 7 | 177
+(6 rows)
+
+-- Test forcing the remote server to produce sorted data for a merge join,
+-- but the foreign table is an inheritance child.
+truncate table loct1;
+truncate table only foo;
+\set num_rows_foo 2000
+insert into loct1 select generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2);
+insert into foo select generate_series(1, :num_rows_foo, 2), generate_series(1, :num_rows_foo, 2);
+SET enable_hashjoin to false;
+SET enable_nestloop to false;
+alter foreign table foo2 options (use_remote_estimate 'true');
+create index i_loct1_f1 on loct1(f1);
+create index i_foo_f1 on foo(f1);
+analyze foo;
+analyze loct1;
+-- inner join; expressions in the clauses appear in the equivalence class list
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 20 | 20
+ 22 | 22
+ 24 | 24
+ 26 | 26
+ 28 | 28
+ 30 | 30
+ 32 | 32
+ 34 | 34
+ 36 | 36
+ 38 | 38
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Left Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 10 | 10
+ 11 |
+ 12 | 12
+ 13 |
+ 14 | 14
+ 15 |
+ 16 | 16
+ 17 |
+ 18 | 18
+ 19 |
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test that WHERE CURRENT OF is not supported
+begin;
+declare c cursor for select * from bar where f1 = 7;
+fetch from c;
+ f1 | f2
+----+-----
+ 7 | 177
+(1 row)
+
+update bar set f2 = null where current of c;
+ERROR: WHERE CURRENT OF is not supported for this table type
+rollback;
+explain (verbose, costs off)
+delete from foo where f1 < 5 returning *;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Delete on public.foo
+ Output: foo_1.f1, foo_1.f2
+ Delete on public.foo foo_1
+ Foreign Delete on public.foo2 foo_2
+ -> Append
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.tableoid, foo_1.ctid
+ Index Cond: (foo_1.f1 < 5)
+ -> Foreign Delete on public.foo2 foo_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ((f1 < 5)) RETURNING f1, f2
+(10 rows)
+
+delete from foo where f1 < 5 returning *;
+ f1 | f2
+----+----
+ 1 | 1
+ 3 | 3
+ 0 | 0
+ 2 | 2
+ 4 | 4
+(5 rows)
+
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Update on public.bar
+ Output: bar_1.f1, bar_1.f2
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = (f2 + 100) RETURNING f1, f2
+(11 rows)
+
+update bar set f2 = f2 + 100 returning *;
+ f1 | f2
+----+-----
+ 1 | 311
+ 2 | 322
+ 6 | 266
+ 3 | 333
+ 4 | 344
+ 7 | 277
+(6 rows)
+
+-- Test that UPDATE/DELETE with inherited target works with row-level triggers
+CREATE TRIGGER trig_row_before
+BEFORE UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+explain (verbose, costs off)
+update bar set f2 = f2 + 100;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f1 = $2, f2 = $3, f3 = $4 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+(12 rows)
+
+update bar set f2 = f2 + 100;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+explain (verbose, costs off)
+delete from bar where f2 < 400;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Delete on public.bar
+ Delete on public.bar bar_1
+ Foreign Delete on public.bar2 bar_2
+ Remote SQL: DELETE FROM public.loct2 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.tableoid, bar_1.ctid, NULL::record
+ Filter: (bar_1.f2 < 400)
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 WHERE ((f2 < 400)) FOR UPDATE
+(11 rows)
+
+delete from bar where f2 < 400;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+-- cleanup
+drop table foo cascade;
+NOTICE: drop cascades to foreign table foo2
+drop table bar cascade;
+NOTICE: drop cascades to foreign table bar2
+drop table loct1;
+drop table loct2;
+-- Test pushing down UPDATE/DELETE joins to the remote server
+create table parent (a int, b text);
+create table loct1 (a int, b text);
+create table loct2 (a int, b text);
+create foreign table remt1 (a int, b text)
+ server loopback options (table_name 'loct1');
+create foreign table remt2 (a int, b text)
+ server loopback options (table_name 'loct2');
+alter foreign table remt1 inherit parent;
+insert into remt1 values (1, 'foo');
+insert into remt1 values (2, 'bar');
+insert into remt2 values (1, 'foo');
+insert into remt2 values (2, 'bar');
+analyze remt1;
+analyze remt2;
+explain (verbose, costs off)
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.parent
+ Output: parent_1.a, parent_1.b, remt2.a, remt2.b
+ Update on public.parent parent_1
+ Foreign Update on public.remt1 parent_2
+ Remote SQL: UPDATE public.loct1 SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: (parent.b || remt2.b), remt2.*, remt2.a, remt2.b, parent.tableoid, parent.ctid, (NULL::record)
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.b, parent_1.a, parent_1.tableoid, parent_1.ctid, NULL::record
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.b, parent_2.a, parent_2.tableoid, parent_2.ctid, parent_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.b, remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.b, remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ a | b | a | b
+---+--------+---+-----
+ 1 | foofoo | 1 | foo
+ 2 | barbar | 2 | bar
+(2 rows)
+
+explain (verbose, costs off)
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Delete on public.parent
+ Output: parent_1.*
+ Delete on public.parent parent_1
+ Foreign Delete on public.remt1 parent_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: remt2.*, parent.tableoid, parent.ctid
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.a, parent_1.tableoid, parent_1.ctid
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.a, parent_2.tableoid, parent_2.ctid
+ Remote SQL: SELECT a, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ parent
+------------
+ (1,foofoo)
+ (2,barbar)
+(2 rows)
+
+-- cleanup
+drop foreign table remt1;
+drop foreign table remt2;
+drop table loct1;
+drop table loct2;
+drop table parent;
+-- ===================================================================
+-- test tuple routing for foreign-table partitions
+-- ===================================================================
+-- Test insert tuple routing
+create table itrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table itrtest attach partition remp1 for values in (1);
+alter table itrtest attach partition remp2 for values in (2);
+insert into itrtest values (1, 'foo');
+insert into itrtest values (1, 'bar') returning *;
+ a | b
+---+-----
+ 1 | bar
+(1 row)
+
+insert into itrtest values (2, 'baz');
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----
+ 2 | qux
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------
+ 1 | test1
+ 2 | test2
+(2 rows)
+
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from itrtest;
+-- MERGE ought to fail cleanly
+merge into itrtest using (select 1, 'foo') as source on (true)
+ when matched then do nothing;
+ERROR: cannot execute MERGE on relation "remp1"
+DETAIL: This operation is not supported for foreign tables.
+create unique index loct1_idx on loct1 (a);
+-- DO NOTHING without an inference specification is supported
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+-----
+ 1 | foo
+(1 row)
+
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+---
+(0 rows)
+
+-- But other cases are not supported
+insert into itrtest values (1, 'bar') on conflict (a) do nothing;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+insert into itrtest values (1, 'bar') on conflict (a) do update set b = excluded.b;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+delete from itrtest;
+drop index loct1_idx;
+-- Test that remote triggers work with insert tuple routing
+create function br_insert_trigfunc() returns trigger as $$
+begin
+ new.b := new.b || ' triggered !';
+ return new;
+end
+$$ language plpgsql;
+create trigger loct1_br_insert_trigger before insert on loct1
+ for each row execute procedure br_insert_trigfunc();
+create trigger loct2_br_insert_trigger before insert on loct2
+ for each row execute procedure br_insert_trigfunc();
+-- The new values are concatenated with ' triggered !'
+insert into itrtest values (1, 'foo') returning *;
+ a | b
+---+-----------------
+ 1 | foo triggered !
+(1 row)
+
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----------------
+ 2 | qux triggered !
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+with result as (insert into itrtest values (1, 'test1'), (2, 'test2') returning *) select * from result;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+drop trigger loct1_br_insert_trigger on loct1;
+drop trigger loct2_br_insert_trigger on loct2;
+drop table itrtest;
+drop table loct1;
+drop table loct2;
+-- Test update tuple routing
+create table utrtest (a int, b text) partition by list (a);
+create table loct (a int check (a in (1)), b text);
+create foreign table remp (a int check (a in (1)), b text) server loopback options (table_name 'loct');
+create table locp (a int check (a in (2)), b text);
+alter table utrtest attach partition remp for values in (1);
+alter table utrtest attach partition locp for values in (2);
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- It's not allowed to move a row from a partition that is foreign to another
+update utrtest set a = 2 where b = 'foo' returning *;
+ERROR: new row for relation "loct" violates check constraint "loct_a_check"
+DETAIL: Failing row contains (2, foo).
+CONTEXT: remote SQL command: UPDATE public.loct SET a = 2 WHERE ((b = 'foo')) RETURNING a, b
+-- But the reverse is allowed
+update utrtest set a = 1 where b = 'qux' returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- The executor should not let unexercised FDWs shut down
+update utrtest set a = 1 where b = 'foo';
+-- Test that remote triggers work with update tuple routing
+create trigger loct_br_insert_trigger before insert on loct
+ for each row execute procedure br_insert_trigfunc();
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition is a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 WHERE (((a = 1) OR (a = 2))) RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ Filter: ((utrtest_2.a = 1) OR (utrtest_2.a = 2))
+(10 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition isn't a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 2 returning *;
+ QUERY PLAN
+-------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ -> Seq Scan on public.locp utrtest_1
+ Output: 1, utrtest_1.tableoid, utrtest_1.ctid
+ Filter: (utrtest_1.a = 2)
+(6 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 2 returning *;
+ a | b
+---+-----------------
+ 1 | qux triggered !
+(1 row)
+
+drop trigger loct_br_insert_trigger on loct;
+-- We can move rows to a foreign partition that has been updated already,
+-- but can't move rows to a foreign partition that hasn't been updated yet
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- Test the former case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+(9 rows)
+
+update utrtest set a = 1 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ Update on public.locp utrtest_2
+ -> Hash Join
+ Output: 1, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, utrtest.*
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Foreign Scan on public.remp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, utrtest_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Seq Scan on public.locp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- Change the definition of utrtest so that the foreign partition get updated
+-- after the local partition
+delete from utrtest;
+alter table utrtest detach partition remp;
+drop foreign table remp;
+alter table loct drop constraint loct_a_check;
+alter table loct add check (a in (3));
+create foreign table remp (a int check (a in (3)), b text) server loopback options (table_name 'loct');
+alter table utrtest attach partition remp for values in (3);
+insert into utrtest values (2, 'qux');
+insert into utrtest values (3, 'xyzzy');
+-- Test the latter case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: 3, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = 3 RETURNING a, b
+(9 rows)
+
+update utrtest set a = 3 returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ -> Hash Join
+ Output: 3, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, (NULL::record)
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Scan on public.remp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, utrtest_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+drop table utrtest;
+drop table loct;
+-- Test copy tuple routing
+create table ctrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table ctrtest attach partition remp1 for values in (1);
+alter table ctrtest attach partition remp2 for values in (2);
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp2 | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-----+---
+ remp2 | qux | 2
+(1 row)
+
+-- Copying into foreign partitions directly should work as well
+copy remp1 from stdin;
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+(2 rows)
+
+delete from ctrtest;
+-- Test copy tuple routing with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from ctrtest;
+alter server loopback options (drop batch_size);
+drop table ctrtest;
+drop table loct1;
+drop table loct2;
+-- ===================================================================
+-- test COPY FROM
+-- ===================================================================
+create table loc2 (f1 int, f2 text);
+alter table loc2 set (autovacuum_enabled = 'false');
+create foreign table rem2 (f1 int, f2 text) server loopback options(table_name 'loc2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2, line 1: "-1 xyzzy"
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test local triggers
+create trigger trig_stmt_before before insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_stmt_after after insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+copy rem2 from stdin;
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop trigger trig_row_before on rem2;
+drop trigger trig_row_after on rem2;
+drop trigger trig_stmt_before on rem2;
+drop trigger trig_stmt_after on rem2;
+delete from rem2;
+create trigger trig_row_before_insert before insert on rem2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on rem2;
+delete from rem2;
+create trigger trig_null before insert on rem2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on rem2;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Test a combination of local and remote triggers
+create trigger rem2_trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger rem2_trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger loc2_trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+copy rem2 from stdin;
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,"foo triggered !")
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,"bar triggered !")
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger rem2_trig_row_before on rem2;
+drop trigger rem2_trig_row_after on rem2;
+drop trigger loc2_trig_row_before_insert on loc2;
+delete from rem2;
+-- test COPY FROM with foreign table created in the same transaction
+create table loc3 (f1 int, f2 text);
+begin;
+create foreign table rem3 (f1 int, f2 text)
+ server loopback options(table_name 'loc3');
+copy rem3 from stdin;
+commit;
+select * from rem3;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop foreign table rem3;
+drop table loc3;
+-- Test COPY FROM with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+ 3 | baz triggered !
+(3 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Check with zero-column foreign table; batch insert will be disabled
+alter table loc2 drop column f1;
+alter table loc2 drop column f2;
+alter table rem2 drop column f1;
+alter table rem2 drop column f2;
+copy rem2 from stdin;
+select * from rem2;
+--
+(3 rows)
+
+delete from rem2;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test for TRUNCATE
+-- ===================================================================
+CREATE TABLE tru_rtable0 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable0');
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(1,10) x);
+CREATE TABLE tru_ptable (id int) PARTITION BY HASH(id);
+CREATE TABLE tru_ptable__p0 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tru_rtable1 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable__p1 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback OPTIONS (table_name 'tru_rtable1');
+INSERT INTO tru_ptable (SELECT x FROM generate_series(11,20) x);
+CREATE TABLE tru_pk_table(id int primary key);
+CREATE TABLE tru_fk_table(fkey int references tru_pk_table(id));
+INSERT INTO tru_pk_table (SELECT x FROM generate_series(1,10) x);
+INSERT INTO tru_fk_table (SELECT x % 10 + 1 FROM generate_series(5,25) x);
+CREATE FOREIGN TABLE tru_pk_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_pk_table');
+CREATE TABLE tru_rtable_parent (id int);
+CREATE TABLE tru_rtable_child (id int);
+CREATE FOREIGN TABLE tru_ftable_parent (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_parent');
+CREATE FOREIGN TABLE tru_ftable_child () INHERITS (tru_ftable_parent)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_child');
+INSERT INTO tru_rtable_parent (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_rtable_child (SELECT x FROM generate_series(10, 18) x);
+-- normal truncate
+SELECT sum(id) FROM tru_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_ftable;
+SELECT count(*) FROM tru_rtable0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'truncatable' option
+ALTER SERVER loopback OPTIONS (ADD truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (ADD truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER SERVER loopback OPTIONS (DROP truncatable);
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+-- partitioned table with both local and foreign tables as partitions
+SELECT sum(id) FROM tru_ptable; -- 155
+ sum
+-----
+ 155
+(1 row)
+
+TRUNCATE tru_ptable;
+SELECT count(*) FROM tru_ptable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ptable__p0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable__p1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_rtable1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'CASCADE' option
+SELECT sum(id) FROM tru_pk_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_pk_ftable; -- failed by FK reference
+ERROR: cannot truncate a table referenced in a foreign key constraint
+DETAIL: Table "tru_fk_table" references "tru_pk_table".
+HINT: Truncate table "tru_fk_table" at the same time, or use TRUNCATE ... CASCADE.
+CONTEXT: remote SQL command: TRUNCATE public.tru_pk_table CONTINUE IDENTITY RESTRICT
+TRUNCATE tru_pk_ftable CASCADE;
+SELECT count(*) FROM tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_fk_table; -- also truncated,0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate two tables at a command
+INSERT INTO tru_ftable (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_pk_ftable (SELECT x FROM generate_series(3,10) x);
+SELECT count(*) from tru_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+TRUNCATE tru_ftable, tru_pk_ftable CASCADE;
+SELECT count(*) from tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate with ONLY clause
+-- Since ONLY is specified, the table tru_ftable_child that inherits
+-- tru_ftable_parent locally is not truncated.
+TRUNCATE ONLY tru_ftable_parent;
+SELECT sum(id) FROM tru_ftable_parent; -- 126
+ sum
+-----
+ 126
+(1 row)
+
+TRUNCATE tru_ftable_parent;
+SELECT count(*) FROM tru_ftable_parent; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- in case when remote table has inherited children
+CREATE TABLE tru_rtable0_child () INHERITS (tru_rtable0);
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(5,9) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(10,14) x);
+SELECT sum(id) FROM tru_ftable; -- 95
+ sum
+-----
+ 95
+(1 row)
+
+-- Both parent and child tables in the foreign server are truncated
+-- even though ONLY is specified because ONLY has no effect
+-- when truncating a foreign table.
+TRUNCATE ONLY tru_ftable;
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(21,25) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(26,30) x);
+SELECT sum(id) FROM tru_ftable; -- 255
+ sum
+-----
+ 255
+(1 row)
+
+TRUNCATE tru_ftable; -- truncate both of parent and child
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- cleanup
+DROP FOREIGN TABLE tru_ftable_parent, tru_ftable_child, tru_pk_ftable,tru_ftable__p1,tru_ftable;
+DROP TABLE tru_rtable0, tru_rtable1, tru_ptable, tru_ptable__p0, tru_pk_table, tru_fk_table,
+tru_rtable_parent,tru_rtable_child, tru_rtable0_child;
+-- ===================================================================
+-- test IMPORT FOREIGN SCHEMA
+-- ===================================================================
+CREATE SCHEMA import_source;
+CREATE TABLE import_source.t1 (c1 int, c2 varchar NOT NULL);
+CREATE TABLE import_source.t2 (c1 int default 42, c2 varchar NULL, c3 text collate "POSIX");
+CREATE TYPE typ1 AS (m1 int, m2 varchar);
+CREATE TABLE import_source.t3 (c1 timestamptz default now(), c2 typ1);
+CREATE TABLE import_source."x 4" (c1 float8, "C 2" text, c3 varchar(42));
+CREATE TABLE import_source."x 5" (c1 float8);
+ALTER TABLE import_source."x 5" DROP COLUMN c1;
+CREATE TABLE import_source."x 6" (c1 int, c2 int generated always as (c1 * 2) stored);
+CREATE TABLE import_source.t4 (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE import_source.t4_part PARTITION OF import_source.t4
+ FOR VALUES FROM (1) TO (100);
+CREATE TABLE import_source.t4_part2 PARTITION OF import_source.t4
+ FOR VALUES FROM (100) TO (200);
+CREATE SCHEMA import_dest1;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest1;
+\det+ import_dest1.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest1 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest1 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest1 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest1 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest1 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest1 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest1 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest1.*
+ Foreign table "import_dest1.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest1.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest1.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest1.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest1.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest1.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest1.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Options
+CREATE SCHEMA import_dest2;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest2
+ OPTIONS (import_default 'true');
+\det+ import_dest2.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest2 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest2 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest2 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest2 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest2 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest2 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest2 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest2.*
+ Foreign table "import_dest2.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest2.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | 42 | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest2.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | now() | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest2.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest2.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest2.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest2.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+CREATE SCHEMA import_dest3;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest3
+ OPTIONS (import_collate 'false', import_generated 'false', import_not_null 'false');
+\det+ import_dest3.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest3 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest3 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest3 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest3 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest3 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest3 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest3 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest3.*
+ Foreign table "import_dest3.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest3.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest3.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest3.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest3.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest3.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest3.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Check LIMIT TO and EXCEPT
+CREATE SCHEMA import_dest4;
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t1, nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+(2 rows)
+
+IMPORT FOREIGN SCHEMA import_source EXCEPT (t1, "x 4", nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest4 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest4 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+ import_dest4 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest4 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+-- Assorted error cases
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest4;
+ERROR: relation "t1" already exists
+CONTEXT: importing foreign table "t1"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO import_dest4;
+ERROR: schema "nonesuch" is not present on foreign server "loopback"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO notthere;
+ERROR: schema "notthere" does not exist
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER nowhere INTO notthere;
+ERROR: server "nowhere" does not exist
+-- Check case of a type present only on the remote server.
+-- We can fake this by dropping the type locally in our transaction.
+CREATE TYPE "Colors" AS ENUM ('red', 'green', 'blue');
+CREATE TABLE import_source.t5 (c1 int, c2 text collate "C", "Col" "Colors");
+CREATE SCHEMA import_dest5;
+BEGIN;
+DROP TYPE "Colors" CASCADE;
+NOTICE: drop cascades to column Col of table import_source.t5
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t5)
+ FROM SERVER loopback INTO import_dest5; -- ERROR
+ERROR: type "public.Colors" does not exist
+LINE 4: "Col" public."Colors" OPTIONS (column_name 'Col')
+ ^
+QUERY: CREATE FOREIGN TABLE t5 (
+ c1 integer OPTIONS (column_name 'c1'),
+ c2 text OPTIONS (column_name 'c2') COLLATE pg_catalog."C",
+ "Col" public."Colors" OPTIONS (column_name 'Col')
+) SERVER loopback
+OPTIONS (schema_name 'import_source', table_name 't5');
+CONTEXT: importing foreign table "t5"
+ROLLBACK;
+BEGIN;
+CREATE SERVER fetch101 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( fetch_size '101' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER fetch101 OPTIONS( SET fetch_size '202' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=202'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30000 ( x int ) SERVER fetch101 OPTIONS ( fetch_size '30000' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '60000');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=60000'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- ===================================================================
+-- test partitionwise joins
+-- ===================================================================
+SET enable_partitionwise_join=on;
+CREATE TABLE fprt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE fprt1_p1 (LIKE fprt1);
+CREATE TABLE fprt1_p2 (LIKE fprt1);
+ALTER TABLE fprt1_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt1_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt1_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 2) i;
+INSERT INTO fprt1_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 2) i;
+CREATE FOREIGN TABLE ftprt1_p1 PARTITION OF fprt1 FOR VALUES FROM (0) TO (250)
+ SERVER loopback OPTIONS (table_name 'fprt1_p1', use_remote_estimate 'true');
+CREATE FOREIGN TABLE ftprt1_p2 PARTITION OF fprt1 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (TABLE_NAME 'fprt1_p2');
+ANALYZE fprt1;
+ANALYZE fprt1_p1;
+ANALYZE fprt1_p2;
+CREATE TABLE fprt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE fprt2_p1 (LIKE fprt2);
+CREATE TABLE fprt2_p2 (LIKE fprt2);
+ALTER TABLE fprt2_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt2_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt2_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 3) i;
+INSERT INTO fprt2_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 3) i;
+CREATE FOREIGN TABLE ftprt2_p1 (b int, c varchar, a int)
+ SERVER loopback OPTIONS (table_name 'fprt2_p1', use_remote_estimate 'true');
+ALTER TABLE fprt2 ATTACH PARTITION ftprt2_p1 FOR VALUES FROM (0) TO (250);
+CREATE FOREIGN TABLE ftprt2_p2 PARTITION OF fprt2 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (table_name 'fprt2_p2', use_remote_estimate 'true');
+ANALYZE fprt2;
+ANALYZE fprt2_p1;
+ANALYZE fprt2_p2;
+-- inner join three tables
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t3.c
+ -> Append
+ -> Foreign Scan
+ Relations: ((ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)) INNER JOIN (ftprt1_p1 t3_1)
+ -> Foreign Scan
+ Relations: ((ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)) INNER JOIN (ftprt1_p2 t3_2)
+(7 rows)
+
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0003
+ 250 | 250 | 0005
+ 400 | 400 | 0008
+(4 rows)
+
+-- left outer join + nullable clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.a, fprt2.b, fprt2.c
+ Relations: (public.ftprt1_p1 t1) LEFT JOIN (public.ftprt2_p1 fprt2)
+ Remote SQL: SELECT r5.a, r6.b, r6.c FROM (public.fprt1_p1 r5 LEFT JOIN public.fprt2_p1 r6 ON (((r5.a = r6.b)) AND ((r5.b = r6.a)) AND ((r6.a < 10)))) WHERE ((r5.a < 10)) ORDER BY r5.a ASC NULLS LAST, r6.b ASC NULLS LAST, r6.c ASC NULLS LAST
+(4 rows)
+
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ a | b | c
+---+---+------
+ 0 | 0 | 0000
+ 2 | |
+ 4 | |
+ 6 | 6 | 0000
+ 8 | |
+(5 rows)
+
+-- with whole-row reference; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ QUERY PLAN
+--------------------------------------------------------
+ Sort
+ Sort Key: ((t1.*)::fprt1), ((t2.*)::fprt2)
+ -> Hash Full Join
+ Hash Cond: (t1.a = t2.b)
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+(11 rows)
+
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ wr | wr
+----------------+----------------
+ (0,0,0000) | (0,0,0000)
+ (50,50,0001) |
+ (100,100,0002) |
+ (150,150,0003) | (150,150,0003)
+ (200,200,0004) |
+ (250,250,0005) | (250,250,0005)
+ (300,300,0006) |
+ (350,350,0007) |
+ (400,400,0008) | (400,400,0008)
+ (450,450,0009) |
+ | (75,75,0001)
+ | (225,225,0004)
+ | (325,325,0006)
+ | (475,475,0009)
+(14 rows)
+
+-- join with lateral reference
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t1.b
+ -> Append
+ -> Foreign Scan
+ Relations: (ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)
+ -> Foreign Scan
+ Relations: (ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)
+(7 rows)
+
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+-- with PHVs, partitionwise join selected but no join pushdown
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: fprt1.a, fprt2.b
+ -> Append
+ -> Hash Full Join
+ Hash Cond: (fprt1_1.a = fprt2_1.b)
+ -> Foreign Scan on ftprt1_p1 fprt1_1
+ -> Hash
+ -> Foreign Scan on ftprt2_p1 fprt2_1
+ -> Hash Full Join
+ Hash Cond: (fprt1_2.a = fprt2_2.b)
+ -> Foreign Scan on ftprt1_p2 fprt1_2
+ -> Hash
+ -> Foreign Scan on ftprt2_p2 fprt2_2
+(13 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | phv | b | phv
+-----+--------+-----+--------
+ 0 | t1_phv | 0 | t2_phv
+ 50 | t1_phv | |
+ 100 | t1_phv | |
+ 150 | t1_phv | 150 | t2_phv
+ 200 | t1_phv | |
+ 250 | t1_phv | 250 | t2_phv
+ 300 | t1_phv | |
+ 350 | t1_phv | |
+ 400 | t1_phv | 400 | t2_phv
+ 450 | t1_phv | |
+ | | 75 | t2_phv
+ | | 225 | t2_phv
+ | | 325 | t2_phv
+ | | 475 | t2_phv
+(14 rows)
+
+-- test FOR UPDATE; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ QUERY PLAN
+--------------------------------------------------------------
+ LockRows
+ -> Sort
+ Sort Key: t1.a
+ -> Hash Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+(12 rows)
+
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+RESET enable_partitionwise_join;
+-- ===================================================================
+-- test partitionwise aggregates
+-- ===================================================================
+CREATE TABLE pagg_tab (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE pagg_tab_p1 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p2 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p3 (LIKE pagg_tab);
+INSERT INTO pagg_tab_p1 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 10;
+INSERT INTO pagg_tab_p2 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 20 and (i % 30) >= 10;
+INSERT INTO pagg_tab_p3 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 30 and (i % 30) >= 20;
+-- Create foreign partitions
+CREATE FOREIGN TABLE fpagg_tab_p1 PARTITION OF pagg_tab FOR VALUES FROM (0) TO (10) SERVER loopback OPTIONS (table_name 'pagg_tab_p1');
+CREATE FOREIGN TABLE fpagg_tab_p2 PARTITION OF pagg_tab FOR VALUES FROM (10) TO (20) SERVER loopback OPTIONS (table_name 'pagg_tab_p2');
+CREATE FOREIGN TABLE fpagg_tab_p3 PARTITION OF pagg_tab FOR VALUES FROM (20) TO (30) SERVER loopback OPTIONS (table_name 'pagg_tab_p3');
+ANALYZE pagg_tab;
+ANALYZE fpagg_tab_p1;
+ANALYZE fpagg_tab_p2;
+ANALYZE fpagg_tab_p3;
+-- When GROUP BY clause matches with PARTITION KEY.
+-- Plan with partitionwise aggregates is disabled
+SET enable_partitionwise_aggregate TO false;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> HashAggregate
+ Group Key: pagg_tab.a
+ Filter: (avg(pagg_tab.b) < '22'::numeric)
+ -> Append
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab_1
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_2
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_3
+(9 rows)
+
+-- Plan with partitionwise aggregates is enabled
+SET enable_partitionwise_aggregate TO true;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> Append
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p1 pagg_tab)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p2 pagg_tab_1)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p3 pagg_tab_2)
+(9 rows)
+
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | sum | min | count
+----+------+-----+-------
+ 0 | 2000 | 0 | 100
+ 1 | 2100 | 1 | 100
+ 10 | 2000 | 0 | 100
+ 11 | 2100 | 1 | 100
+ 20 | 2000 | 0 | 100
+ 21 | 2100 | 1 | 100
+(6 rows)
+
+-- Check with whole-row reference
+-- Should have all the columns in the target list for the given relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, (count(((t1.*)::pagg_tab)))
+ Sort Key: t1.a
+ -> Append
+ -> HashAggregate
+ Output: t1.a, count(((t1.*)::pagg_tab))
+ Group Key: t1.a
+ Filter: (avg(t1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p1 t1
+ Output: t1.a, t1.*, t1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p1
+ -> HashAggregate
+ Output: t1_1.a, count(((t1_1.*)::pagg_tab))
+ Group Key: t1_1.a
+ Filter: (avg(t1_1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p2 t1_1
+ Output: t1_1.a, t1_1.*, t1_1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p2
+ -> HashAggregate
+ Output: t1_2.a, count(((t1_2.*)::pagg_tab))
+ Group Key: t1_2.a
+ Filter: (avg(t1_2.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p3 t1_2
+ Output: t1_2.a, t1_2.*, t1_2.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p3
+(25 rows)
+
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | count
+----+-------
+ 0 | 100
+ 1 | 100
+ 10 | 100
+ 11 | 100
+ 20 | 100
+ 21 | 100
+(6 rows)
+
+-- When GROUP BY clause does not match with PARTITION KEY.
+EXPLAIN (COSTS OFF)
+SELECT b, avg(a), max(a), count(*) FROM pagg_tab GROUP BY b HAVING sum(a) < 700 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.b
+ -> Finalize HashAggregate
+ Group Key: pagg_tab.b
+ Filter: (sum(pagg_tab.a) < 700)
+ -> Append
+ -> Partial HashAggregate
+ Group Key: pagg_tab.b
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab
+ -> Partial HashAggregate
+ Group Key: pagg_tab_1.b
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_1
+ -> Partial HashAggregate
+ Group Key: pagg_tab_2.b
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_2
+(15 rows)
+
+-- ===================================================================
+-- access rights and superuser
+-- ===================================================================
+-- Non-superuser cannot create a FDW without a password in the connstr
+CREATE ROLE regress_nosuper NOSUPERUSER;
+GRANT USAGE ON FOREIGN DATA WRAPPER postgres_fdw TO regress_nosuper;
+SET ROLE regress_nosuper;
+SHOW is_superuser;
+ is_superuser
+--------------
+ off
+(1 row)
+
+-- This will be OK, we can create the FDW
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback_nopw FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+-- But creation of user mappings for non-superusers should fail
+CREATE USER MAPPING FOR public SERVER loopback_nopw;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+CREATE FOREIGN TABLE pg_temp.ft1_nopw (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback_nopw OPTIONS (schema_name 'public', table_name 'ft1');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+-- If we add a password to the connstr it'll fail, because we don't allow passwords
+-- in connstrs only in user mappings.
+ALTER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+ERROR: invalid option "password"
+HINT: Perhaps you meant the option "passfile".
+-- If we add a password for our user mapping instead, we should get a different
+-- error because the password wasn't actually *used* when we run with trust auth.
+--
+-- This won't work with installcheck, but neither will most of the FDW checks.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+-- Unpriv user cannot make the mapping passwordless
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+ERROR: password_required=false is superuser-only
+HINT: User mappings with the password_required option set to false may only be created or modified by the superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+RESET ROLE;
+-- But the superuser can
+ALTER USER MAPPING FOR regress_nosuper SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+SET ROLE regress_nosuper;
+-- Should finally work now
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- unpriv user also cannot set sslcert / sslkey on the user mapping
+-- first set password_required so we see the right error messages
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (SET password_required 'true');
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslcert 'foo.crt');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslkey 'foo.key');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+-- We're done with the role named after a specific user and need to check the
+-- changes to the public mapping.
+DROP USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+-- This will fail again as it'll resolve the user mapping for public, which
+-- lacks password_required=false
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+RESET ROLE;
+-- The user mapping for public is passwordless and lacks the password_required=false
+-- mapping option, but will work because the current user is a superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- cleanup
+DROP USER MAPPING FOR public SERVER loopback_nopw;
+DROP OWNED BY regress_nosuper;
+DROP ROLE regress_nosuper;
+-- Clean-up
+RESET enable_partitionwise_aggregate;
+-- Two-phase transactions are not supported.
+BEGIN;
+SELECT count(*) FROM ft1;
+ count
+-------
+ 822
+(1 row)
+
+-- error here
+PREPARE TRANSACTION 'fdw_tpc';
+ERROR: cannot PREPARE a transaction that has operated on postgres_fdw foreign tables
+ROLLBACK;
+WARNING: there is no transaction in progress
+-- ===================================================================
+-- reestablish new connection
+-- ===================================================================
+-- Change application_name of remote connection to special one
+-- so that we can easily terminate the connection later.
+ALTER SERVER loopback OPTIONS (application_name 'fdw_retry_check');
+-- If debug_discard_caches is active, it results in
+-- dropping remote connections after every transaction, making it
+-- impossible to test termination meaningfully. So turn that off
+-- for this test.
+SET debug_discard_caches = 0;
+-- Make sure we have a remote connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- This query should detect the broken connection when starting new remote
+-- transaction, reestablish new connection, and then succeed.
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- If we detect the broken connection when starting a new remote
+-- subtransaction, we should fail instead of establishing a new connection.
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+SAVEPOINT s;
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT 1 FROM ft1 LIMIT 1; -- should fail
+ERROR: 08006
+\set VERBOSITY default
+COMMIT;
+RESET debug_discard_caches;
+-- =============================================================================
+-- test connection invalidation cases and postgres_fdw_get_connections function
+-- =============================================================================
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- This test case is for closing the connection in pgfdw_xact_callback
+BEGIN;
+-- Connection xact depth becomes 1 i.e. the connection is in midst of the xact.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT 1 FROM ft7 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback3 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback3
+(2 rows)
+
+-- Connections are not closed at the end of the alter and drop statements.
+-- That's because the connections are in midst of this xact,
+-- they are just marked as invalid in pgfdw_inval_callback.
+ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
+DROP SERVER loopback3 CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to user mapping for public on server loopback3
+drop cascades to foreign table ft7
+-- List all the existing cached connections. loopback and loopback3
+-- should be output as invalid connections. Also the server name for
+-- loopback3 should be NULL because the server was dropped.
+SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | valid
+-------------+-------
+ loopback | f
+ | f
+(2 rows)
+
+-- The invalid connections get closed in pgfdw_xact_callback during commit.
+COMMIT;
+-- All cached connections were closed while committing above xact, so no
+-- records should be output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+(0 rows)
+
+-- =======================================================================
+-- test postgres_fdw_disconnect and postgres_fdw_disconnect_all functions
+-- =======================================================================
+BEGIN;
+-- Ensure to cache loopback connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Ensure to cache loopback2 connection.
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Issue a warning and return false as loopback connection is still in use and
+-- can not be closed.
+SELECT postgres_fdw_disconnect('loopback');
+WARNING: cannot close connection for server "loopback" because it is still in use
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Return false as connections are still in use, warnings are issued.
+-- But disable warnings temporarily because the order of them is not stable.
+SET client_min_messages = 'ERROR';
+SELECT postgres_fdw_disconnect_all();
+ postgres_fdw_disconnect_all
+-----------------------------
+ f
+(1 row)
+
+RESET client_min_messages;
+COMMIT;
+-- Ensure that loopback2 connection is closed.
+SELECT 1 FROM postgres_fdw_disconnect('loopback2');
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT server_name FROM postgres_fdw_get_connections() WHERE server_name = 'loopback2';
+ server_name
+-------------
+(0 rows)
+
+-- Return false as loopback2 connection is closed already.
+SELECT postgres_fdw_disconnect('loopback2');
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- Return an error as there is no foreign server with given name.
+SELECT postgres_fdw_disconnect('unknownserver');
+ERROR: server "unknownserver" does not exist
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- =============================================================================
+-- test case for having multiple cached connections for a foreign server
+-- =============================================================================
+CREATE ROLE regress_multi_conn_user1 SUPERUSER;
+CREATE ROLE regress_multi_conn_user2 SUPERUSER;
+CREATE USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+CREATE USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+BEGIN;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user1
+SET ROLE regress_multi_conn_user1;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user2
+SET ROLE regress_multi_conn_user2;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Should output two connections for loopback server
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback
+(2 rows)
+
+COMMIT;
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- Clean up
+DROP USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+DROP USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+DROP ROLE regress_multi_conn_user1;
+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
+-- ===================================================================
+BEGIN;
+CREATE SERVER batch10 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( batch_size '10' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER batch10 OPTIONS( SET batch_size '20' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=20'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30 ( x int ) SERVER batch10 OPTIONS ( batch_size '30' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30 OPTIONS ( SET batch_size '40');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=40'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+CREATE TABLE batch_table ( x int );
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '10' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 10
+ -> Function Scan on pg_catalog.generate_series i
+ Output: i.i
+ Function Call: generate_series(1, 10)
+(6 rows)
+
+INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+INSERT INTO ftable SELECT * FROM generate_series(11, 31) i;
+INSERT INTO ftable VALUES (32);
+INSERT INTO ftable VALUES (33), (34);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 34
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- try if large batches exceed max number of bind parameters
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '100000' );
+INSERT INTO ftable SELECT * FROM generate_series(1, 70000) i;
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 70000
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- Disable batch insert
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '1' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (1), (2);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 2
+(1 row)
+
+-- Disable batch inserting into foreign tables with BEFORE ROW INSERT triggers
+-- even if the batch_size option is enabled.
+ALTER FOREIGN TABLE ftable OPTIONS ( SET batch_size '10' );
+CREATE TRIGGER trig_row_before BEFORE INSERT ON ftable
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (3), (4);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (3), (4);
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (3)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (4)
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 4
+(1 row)
+
+-- Clean up
+DROP TRIGGER trig_row_before ON ftable;
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+-- Use partitioning
+CREATE TABLE batch_table ( x int ) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0', batch_size '10');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1', batch_size '1');
+CREATE TABLE batch_table_p2
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 2);
+INSERT INTO batch_table SELECT * FROM generate_series(1, 66) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 66
+(1 row)
+
+-- Check that enabling batched inserts doesn't interfere with cross-partition
+-- updates
+CREATE TABLE batch_cp_upd_test (a int) PARTITION BY LIST (a);
+CREATE TABLE batch_cp_upd_test1 (LIKE batch_cp_upd_test);
+CREATE FOREIGN TABLE batch_cp_upd_test1_f
+ PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_cp_upd_test1', batch_size '10');
+CREATE TABLE batch_cp_up_test1 PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (2);
+INSERT INTO batch_cp_upd_test VALUES (1), (2);
+-- The following moves a row from the local partition to the foreign one
+UPDATE batch_cp_upd_test t SET a = 1 FROM (VALUES (1), (2)) s(a) WHERE t.a = s.a;
+ERROR: cannot route tuples into foreign table to be updated "batch_cp_upd_test1_f"
+SELECT tableoid::regclass, * FROM batch_cp_upd_test;
+ tableoid | a
+----------------------+---
+ batch_cp_upd_test1_f | 1
+ batch_cp_up_test1 | 2
+(2 rows)
+
+-- Clean up
+DROP TABLE batch_table, batch_cp_upd_test, batch_table_p0, batch_table_p1 CASCADE;
+-- Use partitioning
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+CREATE TABLE batch_table ( x int, field1 text, field2 text) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+ALTER TABLE batch_table_p0 ADD CONSTRAINT p0_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+ALTER TABLE batch_table_p1 ADD CONSTRAINT p1_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1');
+INSERT INTO batch_table SELECT i, 'test'||i, 'test'|| i FROM generate_series(1, 50) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 50
+(1 row)
+
+SELECT * FROM batch_table ORDER BY x;
+ x | field1 | field2
+----+--------+--------
+ 1 | test1 | test1
+ 2 | test2 | test2
+ 3 | test3 | test3
+ 4 | test4 | test4
+ 5 | test5 | test5
+ 6 | test6 | test6
+ 7 | test7 | test7
+ 8 | test8 | test8
+ 9 | test9 | test9
+ 10 | test10 | test10
+ 11 | test11 | test11
+ 12 | test12 | test12
+ 13 | test13 | test13
+ 14 | test14 | test14
+ 15 | test15 | test15
+ 16 | test16 | test16
+ 17 | test17 | test17
+ 18 | test18 | test18
+ 19 | test19 | test19
+ 20 | test20 | test20
+ 21 | test21 | test21
+ 22 | test22 | test22
+ 23 | test23 | test23
+ 24 | test24 | test24
+ 25 | test25 | test25
+ 26 | test26 | test26
+ 27 | test27 | test27
+ 28 | test28 | test28
+ 29 | test29 | test29
+ 30 | test30 | test30
+ 31 | test31 | test31
+ 32 | test32 | test32
+ 33 | test33 | test33
+ 34 | test34 | test34
+ 35 | test35 | test35
+ 36 | test36 | test36
+ 37 | test37 | test37
+ 38 | test38 | test38
+ 39 | test39 | test39
+ 40 | test40 | test40
+ 41 | test41 | test41
+ 42 | test42 | test42
+ 43 | test43 | test43
+ 44 | test44 | test44
+ 45 | test45 | test45
+ 46 | test46 | test46
+ 47 | test47 | test47
+ 48 | test48 | test48
+ 49 | test49 | test49
+ 50 | test50 | test50
+(50 rows)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+-- ===================================================================
+-- test asynchronous execution
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD async_capable 'true');
+ALTER SERVER loopback2 OPTIONS (ADD async_capable 'true');
+CREATE TABLE async_pt (a int, b int, c text) PARTITION BY RANGE (a);
+CREATE TABLE base_tbl1 (a int, b int, c text);
+CREATE TABLE base_tbl2 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p1 PARTITION OF async_pt FOR VALUES FROM (1000) TO (2000)
+ SERVER loopback OPTIONS (table_name 'base_tbl1');
+CREATE FOREIGN TABLE async_p2 PARTITION OF async_pt FOR VALUES FROM (2000) TO (3000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl2');
+INSERT INTO async_p1 SELECT 1000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+INSERT INTO async_p2 SELECT 2000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+-- simple queries
+CREATE TABLE result_tbl (a int, b int, c text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE (((b % 100) = 0))
+(8 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1000 | 0 | 0000
+ 1100 | 100 | 0100
+ 1200 | 200 | 0200
+ 1300 | 300 | 0300
+ 1400 | 400 | 0400
+ 1500 | 500 | 0500
+ 1600 | 600 | 0600
+ 1700 | 700 | 0700
+ 1800 | 800 | 0800
+ 1900 | 900 | 0900
+ 2000 | 0 | 0000
+ 2100 | 100 | 0100
+ 2200 | 200 | 0200
+ 2300 | 300 | 0300
+ 2400 | 400 | 0400
+ 2500 | 500 | 0500
+ 2600 | 600 | 0600
+ 2700 | 700 | 0700
+ 2800 | 800 | 0800
+ 2900 | 900 | 0900
+(20 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, ('AAA'::text || async_pt_1.c)
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, ('AAA'::text || async_pt_2.c)
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+---------
+ 1505 | 505 | AAA0505
+ 2505 | 505 | AAA0505
+(2 rows)
+
+DELETE FROM result_tbl;
+-- Check case where multiple partitions use the same connection
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl3');
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Async Foreign Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(14 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+DROP FOREIGN TABLE async_p3;
+DROP TABLE base_tbl3;
+-- Check case where the partitioned table has local/remote partitions
+CREATE TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000);
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+(13 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+-- partitionwise joins
+SET enable_partitionwise_join TO true;
+CREATE TABLE join_tbl (a1 int, b1 int, c1 text, a2 int, b2 int, c2 text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t2_1.b, t2_1.c
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t2_2.b, t2_2.c
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, t1_3.c, t2_3.a, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+ 2000 | 0 | 0000 | 2000 | 0 | 0000
+ 2100 | 100 | 0100 | 2100 | 100 | 0100
+ 2200 | 200 | 0200 | 2200 | 200 | 0200
+ 2300 | 300 | 0300 | 2300 | 300 | 0300
+ 2400 | 400 | 0400 | 2400 | 400 | 0400
+ 2500 | 500 | 0500 | 2500 | 500 | 0500
+ 2600 | 600 | 0600 | 2600 | 600 | 0600
+ 2700 | 700 | 0700 | 2700 | 700 | 0700
+ 2800 | 800 | 0800 | 2800 | 800 | 0800
+ 2900 | 900 | 0900 | 2900 | 900 | 0900
+ 3000 | 0 | 0000 | 3000 | 0 | 0000
+ 3100 | 100 | 0100 | 3100 | 100 | 0100
+ 3200 | 200 | 0200 | 3200 | 200 | 0200
+ 3300 | 300 | 0300 | 3300 | 300 | 0300
+ 3400 | 400 | 0400 | 3400 | 400 | 0400
+ 3500 | 500 | 0500 | 3500 | 500 | 0500
+ 3600 | 600 | 0600 | 3600 | 600 | 0600
+ 3700 | 700 | 0700 | 3700 | 700 | 0700
+ 3800 | 800 | 0800 | 3800 | 800 | 0800
+ 3900 | 900 | 0900 | 3900 | 900 | 0900
+(30 rows)
+
+DELETE FROM join_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, ('AAA'::text || t1_1.c), t2_1.a, t2_1.b, ('AAA'::text || t2_1.c)
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, ('AAA'::text || t1_2.c), t2_2.a, t2_2.b, ('AAA'::text || t2_2.c)
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, ('AAA'::text || t1_3.c), t2_3.a, t2_3.b, ('AAA'::text || t2_3.c)
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+---------+------+-----+---------
+ 1000 | 0 | AAA0000 | 1000 | 0 | AAA0000
+ 1100 | 100 | AAA0100 | 1100 | 100 | AAA0100
+ 1200 | 200 | AAA0200 | 1200 | 200 | AAA0200
+ 1300 | 300 | AAA0300 | 1300 | 300 | AAA0300
+ 1400 | 400 | AAA0400 | 1400 | 400 | AAA0400
+ 1500 | 500 | AAA0500 | 1500 | 500 | AAA0500
+ 1600 | 600 | AAA0600 | 1600 | 600 | AAA0600
+ 1700 | 700 | AAA0700 | 1700 | 700 | AAA0700
+ 1800 | 800 | AAA0800 | 1800 | 800 | AAA0800
+ 1900 | 900 | AAA0900 | 1900 | 900 | AAA0900
+ 2000 | 0 | AAA0000 | 2000 | 0 | AAA0000
+ 2100 | 100 | AAA0100 | 2100 | 100 | AAA0100
+ 2200 | 200 | AAA0200 | 2200 | 200 | AAA0200
+ 2300 | 300 | AAA0300 | 2300 | 300 | AAA0300
+ 2400 | 400 | AAA0400 | 2400 | 400 | AAA0400
+ 2500 | 500 | AAA0500 | 2500 | 500 | AAA0500
+ 2600 | 600 | AAA0600 | 2600 | 600 | AAA0600
+ 2700 | 700 | AAA0700 | 2700 | 700 | AAA0700
+ 2800 | 800 | AAA0800 | 2800 | 800 | AAA0800
+ 2900 | 900 | AAA0900 | 2900 | 900 | AAA0900
+ 3000 | 0 | AAA0000 | 3000 | 0 | AAA0000
+ 3100 | 100 | AAA0100 | 3100 | 100 | AAA0100
+ 3200 | 200 | AAA0200 | 3200 | 200 | AAA0200
+ 3300 | 300 | AAA0300 | 3300 | 300 | AAA0300
+ 3400 | 400 | AAA0400 | 3400 | 400 | AAA0400
+ 3500 | 500 | AAA0500 | 3500 | 500 | AAA0500
+ 3600 | 600 | AAA0600 | 3600 | 600 | AAA0600
+ 3700 | 700 | AAA0700 | 3700 | 700 | AAA0700
+ 3800 | 800 | AAA0800 | 3800 | 800 | AAA0800
+ 3900 | 900 | AAA0900 | 3900 | 900 | AAA0900
+(30 rows)
+
+DELETE FROM join_tbl;
+RESET enable_partitionwise_join;
+-- Test rescan of an async Append node with do_exec_prune=false
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: ((t1.a = t2.a) AND (t1.b = t2.b))
+ -> Foreign Scan on public.async_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t2_1
+ Output: t2_1.a, t2_1.b, t2_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t2_2
+ Output: t2_2.a, t2_2.b, t2_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+(16 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+(10 rows)
+
+DELETE FROM join_tbl;
+RESET enable_hashjoin;
+-- Test interaction of async execution with plan-time partition pruning
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 3000;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(7 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 2000;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Foreign Scan on public.async_p1 async_pt
+ Output: async_pt.a, async_pt.b, async_pt.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 2000))
+(3 rows)
+
+-- Test interaction of async execution with run-time partition pruning
+SET plan_cache_mode TO force_generic_plan;
+PREPARE async_pt_query (int, int) AS
+ INSERT INTO result_tbl SELECT * FROM async_pt WHERE a < $1 AND b === $2;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (3000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 1
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < $1::integer))
+(11 rows)
+
+EXECUTE async_pt_query (3000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (2000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 2
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+(7 rows)
+
+EXECUTE async_pt_query (2000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+(1 row)
+
+DELETE FROM result_tbl;
+RESET plan_cache_mode;
+CREATE TABLE local_tbl(a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo'), (2505, 505, 'bar');
+ANALYZE local_tbl;
+CREATE INDEX base_tbl1_idx ON base_tbl1 (a);
+CREATE INDEX base_tbl2_idx ON base_tbl2 (a);
+CREATE INDEX async_p3_idx ON async_p3 (a);
+ANALYZE base_tbl1;
+ANALYZE base_tbl2;
+ANALYZE async_p3;
+ALTER FOREIGN TABLE async_p1 OPTIONS (use_remote_estimate 'true');
+ALTER FOREIGN TABLE async_p2 OPTIONS (use_remote_estimate 'true');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: local_tbl.a, local_tbl.b, local_tbl.c, async_pt.a, async_pt.b, async_pt.c
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ Filter: (local_tbl.c = 'bar'::text)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (($1::integer = a))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE (($1::integer = a))
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (local_tbl.a = async_pt_3.a)
+(15 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Nested Loop (actual rows=1 loops=1)
+ -> Seq Scan on local_tbl (actual rows=1 loops=1)
+ Filter: (c = 'bar'::text)
+ Rows Removed by Filter: 1
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (never executed)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=1 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (never executed)
+ Filter: (local_tbl.a = a)
+(9 rows)
+
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ a | b | c | a | b | c
+------+-----+-----+------+-----+------
+ 2505 | 505 | bar | 2505 | 505 | 0505
+(1 row)
+
+ALTER FOREIGN TABLE async_p1 OPTIONS (DROP use_remote_estimate);
+ALTER FOREIGN TABLE async_p2 OPTIONS (DROP use_remote_estimate);
+DROP TABLE local_tbl;
+DROP INDEX base_tbl1_idx;
+DROP INDEX base_tbl2_idx;
+DROP INDEX async_p3_idx;
+-- UNION queries
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> HashAggregate
+ Output: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ Group Key: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(11 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(8 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+-- Disable async execution if we use gating Result nodes for pseudoconstant
+-- quals
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Result
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+(18 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+(SELECT * FROM async_p1 WHERE CURRENT_USER = SESSION_USER)
+UNION ALL
+(SELECT * FROM async_p2 WHERE CURRENT_USER = SESSION_USER);
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(13 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ((SELECT * FROM async_p1 WHERE b < 10) UNION ALL (SELECT * FROM async_p2 WHERE b < 10)) s WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((b < 10))
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(13 rows)
+
+-- Test that pending requests are processed properly
+SET enable_mergejoin TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: (t1.a = t2.a)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+ -> Materialize
+ Output: t2.a, t2.b, t2.c
+ -> Foreign Scan on public.async_p2 t2
+ Output: t2.a, t2.b, t2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(20 rows)
+
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ a | b | c | a | b | c
+------+-----+------+------+-----+------
+ 2505 | 505 | 0505 | 2505 | 505 | 0505
+(1 row)
+
+CREATE TABLE local_tbl (a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo');
+ANALYZE local_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, async_pt.a, async_pt.b, async_pt.c, ($0)
+ Join Filter: (t1.a = async_pt.a)
+ InitPlan 1 (returns $0)
+ -> Aggregate
+ Output: count(*)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_4
+ Remote SQL: SELECT NULL FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_5
+ Remote SQL: SELECT NULL FROM public.base_tbl2 WHERE ((a < 3000))
+ -> Seq Scan on public.local_tbl t1
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(20 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Nested Loop Left Join (actual rows=1 loops=1)
+ Join Filter: (t1.a = async_pt.a)
+ Rows Removed by Join Filter: 399
+ InitPlan 1 (returns $0)
+ -> Aggregate (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_4 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_5 (actual rows=200 loops=1)
+ -> Seq Scan on local_tbl t1 (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=200 loops=1)
+(12 rows)
+
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ a | b | c | a | b | c | count
+------+-----+-----+------+-----+------+-------
+ 1505 | 505 | foo | 1505 | 505 | 0505 | 400
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+----------------------------------------------------------------
+ Limit
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+(14 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit (actual rows=1 loops=1)
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 t1_1 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Async Foreign Scan on async_p2 t1_2 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Seq Scan on async_p3 t1_3 (actual rows=1 loops=1)
+ Filter: (b === 505)
+ Rows Removed by Filter: 101
+(9 rows)
+
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ a | b | c
+------+-----+------
+ 3505 | 505 | 0505
+(1 row)
+
+-- Check with foreign modify
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE remote_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl3');
+INSERT INTO remote_tbl VALUES (2505, 505, 'bar');
+CREATE TABLE base_tbl4 (a int, b int, c text);
+CREATE FOREIGN TABLE insert_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl4');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Insert on public.insert_tbl
+ Remote SQL: INSERT INTO public.base_tbl4(a, b, c) VALUES ($1, $2, $3)
+ Batch Size: 1
+ -> Append
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ -> Async Foreign Scan on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(9 rows)
+
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+SELECT * FROM insert_tbl ORDER BY a;
+ a | b | c
+------+-----+-----
+ 1505 | 505 | foo
+ 2505 | 505 | bar
+(2 rows)
+
+-- Check with direct modify
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ CTE t
+ -> Update on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ -> Foreign Update on public.remote_tbl
+ Remote SQL: UPDATE public.base_tbl3 SET c = (c || c) RETURNING a, b, c
+ -> Nested Loop Left Join
+ Output: async_pt.a, async_pt.b, async_pt.c, t.a, t.b, t.c
+ Join Filter: ((async_pt.a = t.a) AND (async_pt.b = t.b))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ -> CTE Scan on t
+ Output: t.a, t.b, t.c
+(23 rows)
+
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+--------
+ 1505 | 505 | 0505 | | |
+ 2505 | 505 | 0505 | 2505 | 505 | barbar
+ 3505 | 505 | 0505 | | |
+(3 rows)
+
+DELETE FROM join_tbl;
+DROP TABLE local_tbl;
+DROP FOREIGN TABLE remote_tbl;
+DROP FOREIGN TABLE insert_tbl;
+DROP TABLE base_tbl3;
+DROP TABLE base_tbl4;
+RESET enable_mergejoin;
+RESET enable_hashjoin;
+-- Test that UPDATE/DELETE with inherited target works with async_capable enabled
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Update on public.async_p1 async_pt_1
+ Foreign Update on public.async_p2 async_pt_2
+ Update on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Update on public.async_p1 async_pt_1
+ Remote SQL: UPDATE public.base_tbl1 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Update on public.async_p2 async_pt_2
+ Remote SQL: UPDATE public.base_tbl2 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: (async_pt_3.c || async_pt_3.c), async_pt_3.tableoid, async_pt_3.ctid, NULL::record
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Delete on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Delete on public.async_p1 async_pt_1
+ Foreign Delete on public.async_p2 async_pt_2
+ Delete on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Delete on public.async_p1 async_pt_1
+ Remote SQL: DELETE FROM public.base_tbl1 WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Delete on public.async_p2 async_pt_2
+ Remote SQL: DELETE FROM public.base_tbl2 WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.tableoid, async_pt_3.ctid
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+-- Check EXPLAIN ANALYZE for a query that scans empty partitions asynchronously
+DELETE FROM async_p1;
+DELETE FROM async_p2;
+DELETE FROM async_p3;
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Append (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=0 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (actual rows=0 loops=1)
+(4 rows)
+
+-- Clean up
+DROP TABLE async_pt;
+DROP TABLE base_tbl1;
+DROP TABLE base_tbl2;
+DROP TABLE result_tbl;
+DROP TABLE join_tbl;
+-- Test that an asynchronous fetch is processed before restarting the scan in
+-- ReScanForeignScan
+CREATE TABLE base_tbl (a int, b int);
+INSERT INTO base_tbl VALUES (1, 11), (2, 22), (3, 33);
+CREATE FOREIGN TABLE foreign_tbl (b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE FOREIGN TABLE foreign_tbl2 () INHERITS (foreign_tbl)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Seq Scan on public.base_tbl
+ Output: base_tbl.a
+ Filter: (SubPlan 1)
+ SubPlan 1
+ -> Result
+ Output: base_tbl.a
+ -> Append
+ -> Async Foreign Scan on public.foreign_tbl foreign_tbl_1
+ Remote SQL: SELECT NULL FROM public.base_tbl
+ -> Async Foreign Scan on public.foreign_tbl2 foreign_tbl_2
+ Remote SQL: SELECT NULL FROM public.base_tbl
+(11 rows)
+
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ a
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+-- Clean up
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to foreign table foreign_tbl2
+DROP TABLE base_tbl;
+ALTER SERVER loopback OPTIONS (DROP async_capable);
+ALTER SERVER loopback2 OPTIONS (DROP async_capable);
+-- ===================================================================
+-- test invalid server, foreign table and foreign data wrapper options
+-- ===================================================================
+-- Invalid fdw_startup_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_startup_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_startup_cost": 100$%$#$#
+-- Invalid fdw_tuple_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_tuple_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_tuple_cost": 100$%$#$#
+-- Invalid fetch_size option
+CREATE FOREIGN TABLE inv_fsz (c1 int )
+ SERVER loopback OPTIONS (fetch_size '100$%$#$#');
+ERROR: invalid value for integer option "fetch_size": 100$%$#$#
+-- Invalid batch_size option
+CREATE FOREIGN TABLE inv_bsz (c1 int )
+ SERVER loopback OPTIONS (batch_size '100$%$#$#');
+ERROR: invalid value for integer option "batch_size": 100$%$#$#
+-- No option is allowed to be specified at foreign data wrapper level
+ALTER FOREIGN DATA WRAPPER postgres_fdw OPTIONS (nonexistent 'fdw');
+ERROR: invalid option "nonexistent"
+HINT: There are no valid options in this context.
+-- ===================================================================
+-- test postgres_fdw.application_name GUC
+-- ===================================================================
+--- Turn debug_discard_caches off for this test to make sure that
+--- the remote connection is alive when checking its application_name.
+SET debug_discard_caches = 0;
+-- Specify escape sequences in application_name option of a server
+-- object so as to test that they are replaced with status information
+-- expectedly.
+--
+-- Since pg_stat_activity.application_name may be truncated to less than
+-- NAMEDATALEN characters, note that substring() needs to be used
+-- at the condition of test query to make sure that the string consisting
+-- of database name and process ID is also less than that.
+ALTER SERVER loopback2 OPTIONS (application_name 'fdw_%d%p');
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_database() || pg_backend_pid() for
+ current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- postgres_fdw.application_name overrides application_name option
+-- of a server object if both settings are present.
+SET postgres_fdw.application_name TO 'fdw_%a%u%%';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('application_name') ||
+ CURRENT_USER || '%' for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- Test %c (session ID) and %C (cluster name) escape sequences.
+SET postgres_fdw.application_name TO 'fdw_%C%c';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('cluster_name') ||
+ to_hex(trunc(EXTRACT(EPOCH FROM (SELECT backend_start FROM
+ pg_stat_get_activity(pg_backend_pid()))))::integer) || '.' ||
+ to_hex(pg_backend_pid())
+ for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+--Clean up
+RESET postgres_fdw.application_name;
+RESET debug_discard_caches;
+-- ===================================================================
+-- test parallel commit
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (ADD parallel_commit 'true');
+ALTER SERVER loopback2 OPTIONS (ADD parallel_commit 'true');
+CREATE TABLE ploc1 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem1 (f1 int, f2 text)
+ SERVER loopback OPTIONS (table_name 'ploc1');
+CREATE TABLE ploc2 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem2 (f1 int, f2 text)
+ SERVER loopback2 OPTIONS (table_name 'ploc2');
+BEGIN;
+INSERT INTO prem1 VALUES (101, 'foo');
+INSERT INTO prem2 VALUES (201, 'bar');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+-----
+ 101 | foo
+(1 row)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+-----
+ 201 | bar
+(1 row)
+
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (102, 'foofoo');
+INSERT INTO prem2 VALUES (202, 'barbar');
+RELEASE SAVEPOINT s;
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+(2 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+(2 rows)
+
+-- This tests executing DEALLOCATE ALL against foreign servers in parallel
+-- during pre-commit
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (103, 'baz');
+INSERT INTO prem2 VALUES (203, 'qux');
+ROLLBACK TO SAVEPOINT s;
+RELEASE SAVEPOINT s;
+INSERT INTO prem1 VALUES (104, 'bazbaz');
+INSERT INTO prem2 VALUES (204, 'quxqux');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+ 104 | bazbaz
+(3 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+ 204 | quxqux
+(3 rows)
+
+ALTER SERVER loopback OPTIONS (DROP parallel_commit);
+ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for health-check feature
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Set GUC for checking the health of remote servers
+SET postgres_fdw.health_check_interval TO '1s';
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+-- FIXME: this should be skipped in some platforms
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- While sleeping the process down will be detected.
+SELECT pg_sleep(3);
+ pg_sleep
+----------
+
+(1 row)
+
+COMMIT;
+ERROR: server closed the connection unexpectedly
+ This probably means the server terminated abnormally
+ before or while processing the request.
+CONTEXT: remote SQL command: COMMIT TRANSACTION
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index b0dbb41fb5..f6e8ca1973 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3788,3 +3788,30 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+
+-- ===================================================================
+-- test for health-check feature
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Set GUC for checking the health of remote servers
+SET postgres_fdw.health_check_interval TO '1s';
+
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+-- Terminate the remote backend process
+-- FIXME: this should be skipped in some platforms
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+-- While sleeping the process down will be detected.
+SELECT pg_sleep(3);
+COMMIT;
+
+-- Clean up
+RESET debug_discard_caches;
--
2.27.0
On Monday, October 17, 2022 9:25 PM Kuroda, Hayato/黒田 隼人 <kuroda.hayato@fujitsu.com> wrote:
I mainly followed the steps there and
replaced the command "SELECT" for the remote table at 6-9 with "INSERT"
command.
Then, after waiting for few seconds, the "COMMIT" succeeded like below
output, even after the server stop of the worker side.I understood that we should not call disconnect_pg_server(entry->conn) even if
we detect the disconnection.
If should be controlled in Xact callback. This will be modified in next version.
Hi,
FYI, I quickly rechecked the patch's behavior on that scenario with v17.
Now, the last "COMMIT" above failed expectedly, which looks reasonable behavior.
Thank you for having modified it.
Best Regards,
Takamichi Osumi
Hi,
As far as I can think of, it should probably be a single background task
checking whether the server is down. If so, sending an invalidation
message
to all the backends such that related backends could act on the
invalidation and throw an error. This is to cover the use-case you
described on [1].Indeed your approach covers the use case I said, but I'm not sure whether
it is really good.
In your approach, once the background worker process will manage all
foreign servers.
It may be OK if there are a few servers, but if there are hundreds of
servers,
the time interval during checks will be longer.
I expect users typically will have a lot more backends than the servers. We
can have a threshold for spinning a new bg worker (e.g., every 10 servers
gets a new bg worker etc.). Still, I think that'd be an optimization that
is probably not necessary for the majority of the users?
Currently, each FDW can decide whether we do health checks or not per the
backend.
For example, we can skip health checks if the foreign server is not used
now.
The background worker cannot control such a way.
Based on the above, I do not agree that we introduce a new background
worker and make it to do a health check.
Again, the definition of "health check" is probably different for me. I'd
expect the health check to happen continuously, ideally keeping track of
how many consecutive times it succeeded and/or last time it
failed/succeeded etc.
A transaction failing with a bad error message (or holding some resources
locally until the transaction is committed) doesn't sound essential to me.
Is there any specific workload are you referring for optimizing to rollback
a transaction earlier if a remote server dies? What kind of workload would
benefit from that? Maybe there is, but not clear to me and haven't seen
discussed on the thread (sorry if I missed).
I'm trying to understand if we are trying to solve a problem that does not
really exists. I'm bringing this up, because I often deal with
architectures where there is a local node and remote transaction on
different Postgres servers. And, I have not encountered many (or any)
pattern that'd benefit from this change much. In fact, I think, on the
contrary, this might add significant overhead for OLTP type of high query
throughput systems.
Moreover, methods to connect to foreign servers and check health are
different per FDW.
In terms of mysql_fdw [1], we must do mysql_init() and
mysql_real_connect().
About file_fdw, we do not have to connect, but developers may want to
calculate checksum and compare.
Therefore, we must provide callback functions anyway.
I think providing callback functions is useful for any case. Each fdw (or
in general extension) should be able to provide its own "health check"
function.
Thanks,
Onder KALACI
Dear Önder, all,
Thank you for responding and sorry for late response.
A transaction failing with a bad error message (or holding some resources
locally until the transaction is committed) doesn't sound essential to me.
Is there any specific workload are you referring for optimizing to rollback
a transaction earlier if a remote server dies? What kind of workload would
benefit from that? Maybe there is, but not clear to me and haven't seen
discussed on the thread (sorry if I missed).
I (and my company) worried about overnight batch processing that
contains some accesses to foreign servers. If the transaction is opened overnight and
one of foreign servers is crashed during it, the transaction must be rollbacked.
But there is a possibility that DBAs do not recognize the crash and
they waste a time until the morning. This problem may affect customer's business.
(It may not be sufficient to check the status from another different server.
DBAs must check the network between the databases, and they may be oversight.)
This is a motivation we thought.
I'm trying to understand if we are trying to solve a problem that does not
really exists. I'm bringing this up, because I often deal with
architectures where there is a local node and remote transaction on
different Postgres servers. And, I have not encountered many (or any)
pattern that'd benefit from this change much. In fact, I think, on the
contrary, this might add significant overhead for OLTP type of high query
throughput systems.
As I said above, I did not considered about OLTP system. But I agreed that the current
callback mechanism may have significant overhead.
Actually, we may not decide the correct way to detect the failure now.
Your argument, which operations should be done by BGworker and we record stats about checking,
seems to be efficient and may be smarter but this may be not match my motivation now.
My approach may have large overhead and may be not able to use for OLTP system.
So how about implementing a check function as an SQL function once and update incrementally?
This still satisfy our motivation and it can avoid overhead because we can reduce the number of calling it.
If we decide that we establish a new connection in the checking function, we can refactor the it.
And if we decide that we introduce health-check BGworker, then we can add a process that calls implemented function periodically.
PSA patchset that implemented as an SQL function. I moved the checking function to libpq layer, fe-misc.c.
Note that poll() is used here, it means that currently this function can be used on some limited platforms.
I have added a parameter check_all that controls the scope of to-be-checked servers,
But this is not related with my motivation so we can remove if not needed.
(I have not implemented another version that uses epoll() or kqueue(),
because they seem to be not called on the libpq layer. Do you know any reasons?)
How do you think?
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v18-0001-Add-PQConncheck-to-libpq.patchapplication/octet-stream; name=v18-0001-Add-PQConncheck-to-libpq.patchDownload
From 0682db975f1e715e727d2acfe335fec81e44811a Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:20 +0000
Subject: [PATCH v18 1/3] Add PQConncheck to libpq
This new libpq function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
---
doc/src/sgml/libpq.sgml | 24 +++++++++++++++++++
src/interfaces/libpq/exports.txt | 1 +
src/interfaces/libpq/fe-misc.c | 41 ++++++++++++++++++++++++++++++++
src/interfaces/libpq/libpq-fe.h | 3 +++
4 files changed, 69 insertions(+)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 3c9bd3d673..99ef0f61a4 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,30 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQConncheck">
+ <term><function>PQConncheck</function><indexterm><primary>PQConncheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQConncheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQConncheck"/> returns <literal>1</literal>
+ if the remote peer seems to be closed, returns <literal>0</literal> if
+ the socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..3c4f946b51 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,4 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQConncheck 187
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 795500c593..6502adcc09 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -1224,6 +1224,47 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Helper function for PQconncheck().
+ *
+ * Return >0 if opposite side seems to be disconnected.
+ */
+static int
+pqConncheck_internal(int sock)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ struct pollfd input_fd;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP;
+ input_fd.revents = 0;
+
+ poll(&input_fd, 1, 0);
+
+ return input_fd.revents & POLLRDHUP;
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad.
+ */
+int
+PQConncheck(PGconn *conn)
+{
+ /* quick exit if invalid connection has come */
+ if (conn == NULL ||
+ conn->sock == PGINVALID_SOCKET ||
+ conn->status != CONNECTION_OK)
+ return -1;
+
+ return pqConncheck_internal(conn->sock);
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index b7df3224c0..8b2d78f3ef 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,9 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQConncheck(PGconn *conn);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v18-0002-postgres_fdw-add-postgres_fdw_verify_foreign_ser.patchapplication/octet-stream; name=v18-0002-postgres_fdw-add-postgres_fdw_verify_foreign_ser.patchDownload
From 90cc57c6a55f279df1a427f665c272bbe0d9d1a8 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:42 +0000
Subject: [PATCH v18 2/3] postgres_fdw: add postgres_fdw_verify_foreign_servers
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQConncheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if all checked connections are still valid. False is returned
if the checking is not supported on this platform.
---
contrib/postgres_fdw/connection.c | 48 +++++++++++++++++++
.../postgres_fdw/postgres_fdw--1.0--1.1.sql | 5 ++
doc/src/sgml/postgres-fdw.sgml | 26 ++++++++++
3 files changed, 79 insertions(+)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index f0c45b00db..584b914814 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -86,6 +86,7 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_foreign_servers);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -1862,3 +1863,50 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Check health of remote servers.
+ *
+ * This function searches the hash table from the beginning and performs a
+ * health-check on each entry.
+ *
+ * Return true if all servers seem good, return false if we could not check on
+ * this platform, and raise an ERROR if a disconnection is found.
+ *
+ */
+Datum
+postgres_fdw_verify_foreign_servers(PG_FUNCTION_ARGS)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool check_all = PG_GETARG_BOOL(0);
+
+ /* quick exit if connection cache has been not initialized yet. */
+ if (ConnectionHash == NULL)
+ PG_RETURN_BOOL(true);
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ if (entry->conn == NULL ||
+ (entry->xact_depth == 0 && !check_all))
+ continue;
+ if (PQConncheck(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so throw ereport(ERROR).
+ */
+ ForeignServer *server;
+
+ server = GetForeignServer(entry->serverid);
+ ereport(ERROR,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("could not connect to server \"%s\"",
+ server->servername),
+ errdetail("Socket close is detected."),
+ errhint("Please check the health of the server.")));
+ }
+ }
+
+ PG_RETURN_BOOL(true);
+}
diff --git a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
index ed4ca378d4..d0a82410c9 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
@@ -18,3 +18,8 @@ CREATE FUNCTION postgres_fdw_disconnect_all ()
RETURNS bool
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_foreign_servers (boolean)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 527f4deaaa..790a5256ac 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -790,6 +790,32 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_foreign_servers(check_all boolean) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote open connections that are
+ established by <filename>postgres_fdw</filename>. This check is performed
+ by polling the socket and allows long-running transactions to be aborted
+ sooner if the kernel reports that the connection is closed. This function is
+ currently available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if all checked connections are still valid.
+ <literal>false</literal> is returned if the checking is not supported on
+ this platform. If the local session seems to be disconnected from other
+ servers, an error is reported. When check_all is set to true, all
+ established connections are checked. Otherwise connections that have been
+ used in the transaction are checked. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_foreign_servers
+-------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
</variablelist>
</sect2>
--
2.27.0
v18-0003-add-test.patchapplication/octet-stream; name=v18-0003-add-test.patchDownload
From 8b1045a4cf0fe0fbbabcca0d8fcd366f47950a15 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v18 3/3] add test
Note that this test has some variant comparison files. One comparison file is needed
because some platforms like Windows cannot check the status of the socket.
Another file is because the output is not stabilized.
The ordering of ERROR and WARNING seems to depend on the timing.
---
.../postgres_fdw/expected/postgres_fdw.out | 37 +
.../postgres_fdw/expected/postgres_fdw_1.out | 11615 +++++++++++++++
.../postgres_fdw/expected/postgres_fdw_2.out | 11622 ++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 26 +
4 files changed, 23300 insertions(+)
create mode 100644 contrib/postgres_fdw/expected/postgres_fdw_1.out
create mode 100644 contrib/postgres_fdw/expected/postgres_fdw_2.out
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 558e94b845..f17bb703e7 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11576,3 +11576,40 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT postgres_fdw_verify_foreign_servers(false); -- should fail on supported platform
+ERROR: 08006
+WARNING: 08006
+\set VERBOSITY default
+COMMIT;
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/expected/postgres_fdw_1.out b/contrib/postgres_fdw/expected/postgres_fdw_1.out
new file mode 100644
index 0000000000..3ce169c837
--- /dev/null
+++ b/contrib/postgres_fdw/expected/postgres_fdw_1.out
@@ -0,0 +1,11615 @@
+-- ===================================================================
+-- create FDW objects
+-- ===================================================================
+CREATE EXTENSION postgres_fdw;
+CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw;
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback2 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback3 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+CREATE USER MAPPING FOR public SERVER testserver1
+ OPTIONS (user 'value', password 'value');
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback2;
+CREATE USER MAPPING FOR public SERVER loopback3;
+-- ===================================================================
+-- create objects used through FDW loopback server
+-- ===================================================================
+CREATE TYPE user_enum AS ENUM ('foo', 'bar', 'buz');
+CREATE SCHEMA "S 1";
+CREATE TABLE "S 1"."T 1" (
+ "C 1" int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10),
+ c8 user_enum,
+ CONSTRAINT t1_pkey PRIMARY KEY ("C 1")
+);
+CREATE TABLE "S 1"."T 2" (
+ c1 int NOT NULL,
+ c2 text,
+ CONSTRAINT t2_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 3" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t3_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 4" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t4_pkey PRIMARY KEY (c1)
+);
+-- Disable autovacuum for these tables to avoid unexpected effects of that
+ALTER TABLE "S 1"."T 1" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 2" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 3" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 4" SET (autovacuum_enabled = 'false');
+INSERT INTO "S 1"."T 1"
+ SELECT id,
+ id % 10,
+ to_char(id, 'FM00000'),
+ '1970-01-01'::timestamptz + ((id % 100) || ' days')::interval,
+ '1970-01-01'::timestamp + ((id % 100) || ' days')::interval,
+ id % 10,
+ id % 10,
+ 'foo'::user_enum
+ FROM generate_series(1, 1000) id;
+INSERT INTO "S 1"."T 2"
+ SELECT id,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+INSERT INTO "S 1"."T 3"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 3" WHERE c1 % 2 != 0; -- delete for outer join tests
+INSERT INTO "S 1"."T 4"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests
+ANALYZE "S 1"."T 1";
+ANALYZE "S 1"."T 2";
+ANALYZE "S 1"."T 3";
+ANALYZE "S 1"."T 4";
+-- ===================================================================
+-- create foreign tables
+-- ===================================================================
+CREATE FOREIGN TABLE ft1 (
+ c0 int,
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft1 DROP COLUMN c0;
+CREATE FOREIGN TABLE ft2 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ cx int,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft2',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft2 DROP COLUMN cx;
+CREATE FOREIGN TABLE ft4 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 3');
+CREATE FOREIGN TABLE ft5 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft6 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback2 OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft7 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback3 OPTIONS (schema_name 'S 1', table_name 'T 4');
+-- ===================================================================
+-- tests for validator
+-- ===================================================================
+-- requiressl and some other parameters are omitted because
+-- valid values for them depend on configure options
+ALTER SERVER testserver1 OPTIONS (
+ use_remote_estimate 'false',
+ updatable 'true',
+ fdw_startup_cost '123.456',
+ fdw_tuple_cost '0.123',
+ service 'value',
+ connect_timeout 'value',
+ dbname 'value',
+ host 'value',
+ hostaddr 'value',
+ port 'value',
+ --client_encoding 'value',
+ application_name 'value',
+ --fallback_application_name 'value',
+ keepalives 'value',
+ keepalives_idle 'value',
+ keepalives_interval 'value',
+ tcp_user_timeout 'value',
+ -- requiressl 'value',
+ sslcompression 'value',
+ sslmode 'value',
+ sslcert 'value',
+ sslkey 'value',
+ sslrootcert 'value',
+ sslcrl 'value',
+ --requirepeer 'value',
+ krbsrvname 'value',
+ gsslib 'value'
+ --replication 'value'
+);
+-- Error, invalid list syntax
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo; bar');
+ERROR: parameter "extensions" must be a list of extension names
+-- OK but gets a warning
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo, bar');
+WARNING: extension "foo" is not installed
+WARNING: extension "bar" is not installed
+ALTER SERVER testserver1 OPTIONS (DROP extensions);
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (DROP user, DROP password);
+-- Attempt to add a valid option that's not allowed in a user mapping
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslmode 'require');
+ERROR: invalid option "sslmode"
+-- But we can add valid ones fine
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslpassword 'dummy');
+-- Ensure valid options we haven't used in a user mapping yet are
+-- permitted to check validation.
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslkey 'value', ADD sslcert 'value');
+ALTER FOREIGN TABLE ft1 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft2 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+ALTER FOREIGN TABLE ft2 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+\det+
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------+-------+-----------+---------------------------------------+-------------
+ public | ft1 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft2 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft4 | loopback | (schema_name 'S 1', table_name 'T 3') |
+ public | ft5 | loopback | (schema_name 'S 1', table_name 'T 4') |
+ public | ft6 | loopback2 | (schema_name 'S 1', table_name 'T 4') |
+ public | ft7 | loopback3 | (schema_name 'S 1', table_name 'T 4') |
+(6 rows)
+
+-- Test that alteration of server options causes reconnection
+-- Remote's errors might be non-English, so hide them to ensure stable results
+\set VERBOSITY terse
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET dbname 'no such database');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+DO $d$
+ BEGIN
+ EXECUTE $$ALTER SERVER loopback
+ OPTIONS (SET dbname '$$||current_database()||$$')$$;
+ END;
+$d$;
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+-- Test that alteration of user mapping options causes reconnection
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (ADD user 'no such user');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (DROP user);
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+\set VERBOSITY default
+-- Now we should be able to run ANALYZE.
+-- To exercise multiple code paths, we use local stats on ft1
+-- and remote-estimate mode on ft2.
+ANALYZE ft1;
+ALTER FOREIGN TABLE ft2 OPTIONS (use_remote_estimate 'true');
+-- ===================================================================
+-- test error case for create publication on foreign table
+-- ===================================================================
+CREATE PUBLICATION testpub_ftbl FOR TABLE ft1; -- should fail
+ERROR: cannot add relation "ft1" to publication
+DETAIL: This operation is not supported for foreign tables.
+-- ===================================================================
+-- simple queries
+-- ===================================================================
+-- single table without alias
+EXPLAIN (COSTS OFF) SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------
+ Foreign Scan on ft1
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- single table with alias - also test that tableoid sort is not pushed to remote side
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ -> Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Sort Key: t1.c3, t1.c1, t1.tableoid
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(8 rows)
+
+SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF) SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: t1.*, c3, c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c3 ASC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(3 rows)
+
+SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ t1
+--------------------------------------------------------------------------------------------
+ (101,1,00101,"Fri Jan 02 00:00:00 1970 PST","Fri Jan 02 00:00:00 1970",1,"1 ",foo)
+ (102,2,00102,"Sat Jan 03 00:00:00 1970 PST","Sat Jan 03 00:00:00 1970",2,"2 ",foo)
+ (103,3,00103,"Sun Jan 04 00:00:00 1970 PST","Sun Jan 04 00:00:00 1970",3,"3 ",foo)
+ (104,4,00104,"Mon Jan 05 00:00:00 1970 PST","Mon Jan 05 00:00:00 1970",4,"4 ",foo)
+ (105,5,00105,"Tue Jan 06 00:00:00 1970 PST","Tue Jan 06 00:00:00 1970",5,"5 ",foo)
+ (106,6,00106,"Wed Jan 07 00:00:00 1970 PST","Wed Jan 07 00:00:00 1970",6,"6 ",foo)
+ (107,7,00107,"Thu Jan 08 00:00:00 1970 PST","Thu Jan 08 00:00:00 1970",7,"7 ",foo)
+ (108,8,00108,"Fri Jan 09 00:00:00 1970 PST","Fri Jan 09 00:00:00 1970",8,"8 ",foo)
+ (109,9,00109,"Sat Jan 10 00:00:00 1970 PST","Sat Jan 10 00:00:00 1970",9,"9 ",foo)
+ (110,0,00110,"Sun Jan 11 00:00:00 1970 PST","Sun Jan 11 00:00:00 1970",0,"0 ",foo)
+(10 rows)
+
+-- empty result
+SELECT * FROM ft1 WHERE false;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- with WHERE clause
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c7 >= '1')) AND (("C 1" = 101)) AND ((c6 = '1'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- with FOR UPDATE/SHARE
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 101)) FOR UPDATE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 102)) FOR SHARE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+-- aggregate
+SELECT COUNT(*) FROM ft1 t1;
+ count
+-------
+ 1000
+(1 row)
+
+-- subquery
+SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- subquery+MAX
+SELECT * FROM ft1 t1 WHERE t1.c3 = (SELECT MAX(c3) FROM ft2 t2) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+(1 row)
+
+-- used in CTE
+WITH t1 AS (SELECT * FROM ft1 WHERE c1 <= 10) SELECT t2.c1, t2.c2, t2.c3, t2.c4 FROM t1, ft2 t2 WHERE t1.c1 = t2.c1 ORDER BY t1.c1;
+ c1 | c2 | c3 | c4
+----+----+-------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+(10 rows)
+
+-- fixed values
+SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1;
+ ?column? | ?column?
+----------+----------
+ fixed |
+(1 row)
+
+-- Test forcing the remote server to produce sorted data for a merge join.
+SET enable_hashjoin TO false;
+SET enable_nestloop TO false;
+-- inner join; expressions in the clauses appear in the equivalence class list
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Left Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- A join between local table and foreign join. ORDER BY clause is added to the
+-- foreign join so that the local table can be joined using merge join strategy.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Merge Right Join
+ Output: t1."C 1"
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r3."C 1" FROM ("S 1"."T 1" r2 INNER JOIN "S 1"."T 1" r3 ON (((r3."C 1" = r2."C 1")))) ORDER BY r2."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- Test similar to above, except that the full join prevents any equivalence
+-- classes from being merged. This produces single relation equivalence classes
+-- included in join restrictions.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Right Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1, t2.c1
+ Relations: (public.ft2 t3) LEFT JOIN (public.ft1 t2)
+ Remote SQL: SELECT r3."C 1", r2."C 1" FROM ("S 1"."T 1" r3 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+-- Test similar to above with all full outer joins
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Full Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) FULL JOIN (public.ft2 t3)
+ Remote SQL: SELECT r2."C 1", r3."C 1" FROM ("S 1"."T 1" r2 FULL JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test executing assertion in estimate_path_cost_size() that makes sure that
+-- retrieved_rows for foreign rel re-used to cost pre-sorted foreign paths is
+-- a sensible value even when the rel has tuples=0
+CREATE TABLE loct_empty (c1 int NOT NULL, c2 text);
+CREATE FOREIGN TABLE ft_empty (c1 int NOT NULL, c2 text)
+ SERVER loopback OPTIONS (table_name 'loct_empty');
+INSERT INTO loct_empty
+ SELECT id, 'AAA' || to_char(id, 'FM000') FROM generate_series(1, 100) id;
+DELETE FROM loct_empty;
+ANALYZE ft_empty;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Foreign Scan on public.ft_empty
+ Output: c1, c2
+ Remote SQL: SELECT c1, c2 FROM public.loct_empty ORDER BY c1 ASC NULLS LAST
+(3 rows)
+
+-- ===================================================================
+-- WHERE with remotely-executable conditions
+-- ===================================================================
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1; -- Var, OpExpr(b), Const
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL; -- NullTest
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL; -- NullTest
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((round(abs("C 1"), 0) = 1::numeric))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1; -- OpExpr(l)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = (- "C 1")))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" IS NOT NULL) IS DISTINCT FROM ("C 1" IS NOT NULL)))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]); -- ScalarArrayOpExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ANY (ARRAY[c2, 1, ("C 1" + 0)])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1]; -- SubscriptingRef
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ((ARRAY["C 1", c2, 3])[1])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar'; -- check special chars
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c6 = E'foo''s\\bar'))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c8 = 'foo'; -- can't be sent to remote
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- parameterized remote path for foreign table
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM "S 1"."T 1" a, ft2 b WHERE a."C 1" = 47 AND b.c1 = a.c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Index Scan using t1_pkey on "S 1"."T 1" a
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Index Cond: (a."C 1" = 47)
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(8 rows)
+
+SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 47 | 7 | 00047 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo | 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+(1 row)
+
+-- check both safe and unsafe join conditions
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 a, ft2 b
+ WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Foreign Scan on public.ft2 a
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Filter: (a.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c2 = 6))
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Filter: ((b.c7)::text = upper((a.c7)::text))
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(10 rows)
+
+SELECT * FROM ft2 a, ft2 b
+WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+(100 rows)
+
+-- bug before 9.3.5 due to sloppy handling of remote-estimate parameters
+SELECT * FROM ft1 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft2 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+SELECT * FROM ft2 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft1 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+-- we should not push order by clause with volatile expressions or unsafe
+-- collations
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, random();
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, (random())
+ Sort Key: ft2.c1, (random())
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, random()
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, ft2.c3 collate "C";
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, ((c3)::text)
+ Sort Key: ft2.c1, ft2.c3 COLLATE "C"
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- user-defined operator/function
+CREATE FUNCTION postgres_fdw_abs(int) RETURNS int AS $$
+BEGIN
+RETURN abs($1);
+END
+$$ LANGUAGE plpgsql IMMUTABLE;
+CREATE OPERATOR === (
+ LEFTARG = int,
+ RIGHTARG = int,
+ PROCEDURE = int4eq,
+ COMMUTATOR = ===
+);
+-- built-in operators and functions can be shipped for remote execution
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ QUERY PLAN
+----------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- by default, user-defined ones cannot
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 = postgres_fdw_abs(t1.c2))
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- ORDER BY can be shipped, though
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- but let's put them in an extension ...
+ALTER EXTENSION postgres_fdw ADD FUNCTION postgres_fdw_abs(int);
+ALTER EXTENSION postgres_fdw ADD OPERATOR === (int, int);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- ... now they can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- and both ORDER BY and LIMIT can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2)) ORDER BY c2 ASC NULLS LAST LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- Test CASE pushdown
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE WHEN ("C 1" > 990) THEN "C 1" ELSE NULL::integer END) < 1000)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ c1 | c2 | c3
+-----+----+-------
+ 991 | 1 | 00991
+ 992 | 2 | 00992
+ 993 | 3 | 00993
+ 994 | 4 | 00994
+ 995 | 5 | 00995
+ 996 | 6 | 00996
+ 997 | 7 | 00997
+ 998 | 8 | 00998
+ 999 | 9 | 00999
+(9 rows)
+
+-- Nested CASE
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE (CASE WHEN (c2 > 0) THEN c2 ELSE NULL::integer END) WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END) > 600)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ c1 | c2 | c3
+----+----+----
+(0 rows)
+
+-- CASE arg WHEN
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE mod(c1, 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" > (CASE mod("C 1", 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)))
+(3 rows)
+
+-- CASE cannot be pushed down because of unshippable arg clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE random()::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (ft1.c1 > CASE (random())::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- these are shippable
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c6 WHEN 'foo' THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c6 WHEN 'foo'::text THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c3 WHEN c6 THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+-- but this is not because of collation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 COLLATE "C" WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: CASE (ft1.c3)::text WHEN ft1.c6 THEN true ELSE (ft1.c3 < 'bar'::text) END
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- a regconfig constant referring to this text search configuration
+-- is initially unshippable
+CREATE TEXT SEARCH CONFIGURATION public.custom_search
+ (COPY = pg_catalog.english);
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Filter: (length(to_tsvector('custom_search'::regconfig, ft1.c3)) > 0)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642))
+(4 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- but if it's in a shippable extension, it can be shipped
+ALTER EXTENSION postgres_fdw ADD TEXT SEARCH CONFIGURATION public.custom_search;
+-- however, that doesn't flush the shippability cache, so do a quick reconnect
+\c -
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642)) AND ((length(to_tsvector('public.custom_search'::regconfig, c3)) > 0))
+(3 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- ===================================================================
+-- JOIN queries
+-- ===================================================================
+-- Analyze ft4 and ft5 so that we have better statistics. These tables do not
+-- have use_remote_estimate set.
+ANALYZE ft4;
+ANALYZE ft5;
+-- join two tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3, t1.c3
+ Relations: ((public.ft1 t1) INNER JOIN (public.ft2 t2)) INNER JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3, r1.c3 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) INNER JOIN "S 1"."T 3" r4 ON (((r1."C 1" = r4.c1)))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 22 |
+ 24 | 24
+ 26 |
+ 28 |
+ 30 | 30
+ 32 |
+ 34 |
+ 36 | 36
+ 38 |
+ 40 |
+(10 rows)
+
+-- left outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + placement of clauses.
+-- clauses within the nullable side are not pulled up, but top level clause on
+-- non-nullable side is pushed into non-nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- clauses within the nullable side are not pulled up, but the top level clause
+-- on nullable side is not pushed down into nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE (((r4.c1 < 10) OR (r4.c1 IS NULL))) AND ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t2) LEFT JOIN (public.ft5 t1)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r1 ON (((r1.c1 = r2.c1)))) ORDER BY r2.c1 ASC NULLS LAST, r1.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ | 22
+ 24 | 24
+ | 26
+ | 28
+ 30 | 30
+ | 32
+ | 34
+ 36 | 36
+ | 38
+ | 40
+(10 rows)
+
+-- right outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 45::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ c1 | c1
+-----+----
+ 92 |
+ 94 |
+ 96 | 96
+ 98 |
+ 100 |
+ | 3
+ | 9
+ | 15
+ | 21
+ | 27
+(10 rows)
+
+-- full outer join with restrictions on the joining relations
+-- a. the joining relations are both base relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s4.c1, s5.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s5.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ c1 | c1
+----+----
+ 50 |
+ 52 |
+ 54 | 54
+ 56 |
+ 58 |
+ 60 | 60
+ | 51
+ | 57
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: 1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT NULL FROM ((SELECT NULL FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4 FULL JOIN (SELECT NULL FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5 ON (TRUE)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ ?column?
+----------
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- b. one of the joining relations is a base relation and the other is a join
+-- relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c1, t3.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 t2) LEFT JOIN (public.ft5 t3))
+ Remote SQL: SELECT s4.c1, s8.c1, s8.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT r5.c1, r6.c1 FROM ("S 1"."T 3" r5 LEFT JOIN "S 1"."T 4" r6 ON (((r5.c1 = r6.c1)))) WHERE ((r5.c1 >= 50)) AND ((r5.c1 <= 60))) s8(c1, c2) ON (((s4.c1 = s8.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s8.c1 ASC NULLS LAST, s8.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+(6 rows)
+
+-- c. test deparsing the remote query as nested subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft4_1.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 ft4_1) FULL JOIN (public.ft5))
+ Remote SQL: SELECT s4.c1, s10.c1, s10.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT s8.c1, s9.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL)))) s10(c1, c2) ON (((s4.c1 = s10.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s10.c1 ASC NULLS LAST, s10.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+ | | 51
+ | | 57
+(8 rows)
+
+-- d. test deparsing rowmarked relations as subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Nested Loop
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Foreign Scan
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s8.c1, s8.c2, s9.c1, s9.c2 FROM ((SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1, c2) FULL JOIN (SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1, c2) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL))) ORDER BY s8.c1 ASC NULLS LAST, s9.c1 ASC NULLS LAST
+ -> Sort
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Full Join
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Hash Cond: (ft4.c1 = ft5.c1)
+ Filter: ((ft4.c1 IS NULL) OR (ft4.c1 IS NOT NULL))
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Hash
+ Output: ft5.c1, ft5.*
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Materialize
+ Output: "T 3".c1, "T 3".ctid
+ -> Seq Scan on "S 1"."T 3"
+ Output: "T 3".c1, "T 3".ctid
+ Filter: ("T 3".c1 = 50)
+(28 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 50 | 52 |
+ 50 | 54 | 54
+ 50 | 56 |
+ 50 | 58 |
+ 50 | 60 | 60
+ 50 | | 51
+ 50 | | 57
+(8 rows)
+
+-- full outer join + inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t3.c1
+ Relations: ((public.ft4 t1) INNER JOIN (public.ft5 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1.c1, r2.c1, r4.c1 FROM (("S 1"."T 3" r1 INNER JOIN "S 1"."T 4" r2 ON (((r1.c1 = (r2.c1 + 1))) AND ((r1.c1 >= 50)) AND ((r1.c1 <= 60)))) FULL JOIN "S 1"."T 3" r4 ON (((r2.c1 = r4.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST, r4.c1 ASC NULLS LAST LIMIT 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ c1 | c1 | c1
+----+----+----
+ 52 | 51 |
+ 58 | 57 |
+ | | 2
+ | | 4
+ | | 6
+ | | 8
+ | | 10
+ | | 12
+ | | 14
+ | | 16
+(10 rows)
+
+-- full outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- right outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+SET enable_memoize TO off;
+-- right outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+RESET enable_memoize;
+-- left outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: (public.ft4 t3) LEFT JOIN ((public.ft2 t1) INNER JOIN (public.ft2 t2))
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM ("S 1"."T 3" r4 LEFT JOIN ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join + WHERE clause, only matched rows
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 = r2.c1) OR (r1.c1 IS NULL)))
+(9 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 66 | 66
+ 72 | 72
+ 78 | 78
+ 84 | 84
+ 90 | 90
+ 96 | 96
+ | 3
+ | 9
+ | 15
+ | 21
+(10 rows)
+
+-- full outer join + WHERE clause with shippable extensions set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) WHERE ((public.postgres_fdw_abs(r1."C 1") > 0)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+-- full outer join + WHERE clause with shippable extensions not set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c2, t1.c3
+ -> Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Filter: (postgres_fdw_abs(t1.c1) > 0)
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- join two tables with FOR UPDATE clause
+-- tests whole-row reference for row marks
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1 FOR UPDATE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join two tables with FOR SHARE clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1 FOR SHARE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join in CTE
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t.c1_1, t.c2_1, t.c1_3
+ CTE t
+ -> Foreign Scan
+ Output: t1.c1, t1.c3, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r1.c3, r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+ -> Sort
+ Output: t.c1_1, t.c2_1, t.c1_3
+ Sort Key: t.c1_3, t.c1_1
+ -> CTE Scan on t
+ Output: t.c1_1, t.c2_1, t.c1_3
+(12 rows)
+
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ c1_1 | c2_1
+------+------
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- ctid with whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.ctid, t1.*, t2.*, t1.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r1."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+-- SEMI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Semi Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c1)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- ANTI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Anti Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c2)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 110
+ 111
+ 112
+ 113
+ 114
+ 115
+ 116
+ 117
+ 118
+ 119
+(10 rows)
+
+-- CROSS JOIN can be pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (TRUE)) ORDER BY r1."C 1" ASC NULLS LAST, r2."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- different server, not pushed down. No result expected.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Merge Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft6 t2
+ Output: t2.c1, t2.c2, t2.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+ -> Materialize
+ Output: t1.c1, t1.c2, t1.c3
+ -> Foreign Scan on public.ft5 t1
+ Output: t1.c1, t1.c2, t1.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+(13 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+----
+(0 rows)
+
+-- unsafe join conditions (c8 has a UDT), not pushed down. Practically a CROSS
+-- JOIN since c8 in both tables has same value.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Merge Left Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t1.c8 = t2.c8)
+ -> Sort
+ Output: t1.c1, t1.c8
+ Sort Key: t1.c8
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+ -> Sort
+ Output: t2.c1, t2.c8
+ Sort Key: t2.c8
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1, t2.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+(20 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- unsafe conditions on one side (c8 has a UDT), not pushed down.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Hash Right Join
+ Output: t1.c1, t2.c1, t1.c3
+ Hash Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+ -> Hash
+ Output: t1.c1, t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c3
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c3, c8 FROM "S 1"."T 1"
+(17 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join where unsafe to pushdown condition in WHERE clause has a column not
+-- in the SELECT clause. In this test unsafe clause needs to have column
+-- references from both joining sides so that the clause is not pushed down
+-- into one of the joining sides.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Filter: (t1.c8 = t2.c8)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, r1.c8, r2.c8 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(10 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- Aggregate after UNION, for testing setrefs
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ -> Sort
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ Sort Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, avg((t1.c1 + t2.c1))
+ Group Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, t2.c1
+ Group Key: t1.c1, t2.c1
+ -> Append
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+ -> Foreign Scan
+ Output: t1_1.c1, t2_1.c1
+ Relations: (public.ft1 t1_1) INNER JOIN (public.ft2 t2_1)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(20 rows)
+
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ t1c1 | avg
+------+----------------------
+ 101 | 202.0000000000000000
+ 102 | 204.0000000000000000
+ 103 | 206.0000000000000000
+ 104 | 208.0000000000000000
+ 105 | 210.0000000000000000
+ 106 | 212.0000000000000000
+ 107 | 214.0000000000000000
+ 108 | 216.0000000000000000
+ 109 | 218.0000000000000000
+ 110 | 220.0000000000000000
+(10 rows)
+
+-- join with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Nested Loop
+ Output: t1."C 1"
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ -> Memoize
+ Cache Key: t1.c2
+ Cache Mode: binary
+ -> Subquery Scan on q
+ -> HashAggregate
+ Output: t2.c1, t3.c1
+ Group Key: t2.c1, t3.c1
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")) AND ((r1.c2 = $1::integer))))
+(17 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ C 1
+-----
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- non-Var items in targetlist of the nullable rel of a join preventing
+-- push-down in some cases
+-- unable to push {ft1, ft2}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: (13), ft2.c1
+ Join Filter: (13 = ft2.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" WHERE (("C 1" >= 10)) AND (("C 1" <= 15)) ORDER BY "C 1" ASC NULLS LAST
+ -> Materialize
+ Output: (13)
+ -> Foreign Scan on public.ft1
+ Output: 13
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 13))
+(11 rows)
+
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ a | c1
+----+----
+ | 10
+ | 11
+ | 12
+ 13 | 13
+ | 14
+ | 15
+(6 rows)
+
+-- ok to push {ft1, ft2} but not {ft1, ft2, ft4}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: ft4.c1, (13), ft1.c1, ft2.c1
+ Join Filter: (ft4.c1 = ft1.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
+ -> Materialize
+ Output: ft1.c1, ft2.c1, (13)
+ -> Foreign Scan
+ Output: ft1.c1, ft2.c1, 13
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r5."C 1" FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = 12)) AND ((r4."C 1" = 12)))) ORDER BY r4."C 1" ASC NULLS LAST
+(12 rows)
+
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ c1 | a | b | c
+----+----+----+----
+ 10 | | |
+ 12 | 13 | 12 | 12
+ 14 | | |
+(3 rows)
+
+-- join with nullable side with some columns with null values
+UPDATE ft5 SET c3 = null where c1 % 9 = 0;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2
+ Relations: (public.ft5) INNER JOIN (public.ft4)
+ Remote SQL: SELECT CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1.c1, r1.c2, r1.c3) END, r1.c1, r1.c2, r1.c3, r2.c1, r2.c2 FROM ("S 1"."T 4" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c1 = r2.c1)) AND ((r2.c1 >= 10)) AND ((r2.c1 <= 30)))) ORDER BY r1.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ ft5 | c1 | c2 | c3 | c1 | c2
+----------------+----+----+--------+----+----
+ (12,13,AAA012) | 12 | 13 | AAA012 | 12 | 13
+ (18,19,) | 18 | 19 | | 18 | 19
+ (24,25,AAA024) | 24 | 25 | AAA024 | 24 | 25
+ (30,31,AAA030) | 30 | 31 | AAA030 | 30 | 31
+(4 rows)
+
+-- multi-way join involving multiple merge joins
+-- (this case used to have EPQ-related planning problems)
+CREATE TABLE local_tbl (c1 int NOT NULL, c2 int NOT NULL, c3 text, CONSTRAINT local_tbl_pkey PRIMARY KEY (c1));
+INSERT INTO local_tbl SELECT id, id % 10, to_char(id, 'FM0000') FROM generate_series(1, 1000) id;
+ANALYZE local_tbl;
+SET enable_nestloop TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ Inner Unique: true
+ Merge Cond: (ft1.c2 = local_tbl.c1)
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Relations: (((public.ft1) INNER JOIN (public.ft2)) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r3.c1, r3.c2, r3.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r4.c1, r4.c2, r4.c3, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4.c1, r4.c2, r4.c3) END FROM ((("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")) AND ((r2."C 1" < 100)) AND ((r1."C 1" < 100)))) INNER JOIN "S 1"."T 3" r3 ON (((r1.c2 = r3.c1)))) INNER JOIN "S 1"."T 4" r4 ON (((r1.c2 = r4.c1)))) ORDER BY r1.c2 ASC NULLS LAST FOR UPDATE OF r1 FOR UPDATE OF r2 FOR UPDATE OF r3 FOR UPDATE OF r4
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Merge Cond: (ft1.c2 = ft5.c1)
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Merge Cond: (ft1.c2 = ft4.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Sort Key: ft1.c2
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Merge Cond: (ft1.c1 = ft2.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) FOR UPDATE
+ -> Materialize
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Sort
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Sort Key: ft4.c1
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" FOR UPDATE
+ -> Sort
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Sort Key: ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" FOR UPDATE
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+(47 rows)
+
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3 | c1 | c2 | c3
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+--------+----+----+--------+----+----+------
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+(10 rows)
+
+RESET enable_nestloop;
+RESET enable_hashjoin;
+-- test that add_paths_with_pathkeys_for_rel() arranges for the epq_path to
+-- return columns needed by the parent ForeignScan node
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.*, COALESCE(ft1.c3 || ft2.c3, 'foobar') FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100)) ss ON (local_tbl.c1 = ss.c1) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ -> Merge Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ Merge Cond: (local_tbl.c1 = ft1.c1)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text))
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c3 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = r4."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4."C 1" ASC NULLS LAST
+ -> Result
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c3
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), ft2.c3
+ Sort Key: ft1.c1
+ -> Hash Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text), ft2.c3
+ Hash Cond: (ft1.c1 = ft2.c1)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Hash
+ Output: ft2.*, ft2.c1, ft2.c3
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(29 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD fdw_startup_cost '10000.0');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.* FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100 AND ft1.c1 = postgres_fdw_abs(ft2.c2))) ss ON (local_tbl.c3 = ss.c3) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ -> Nested Loop Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ Join Filter: (local_tbl.c3 = ft1.c3)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ Filter: (ft1.c1 = postgres_fdw_abs(ft2.c2))
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c2 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = r4."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4.c3 ASC NULLS LAST
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Sort Key: ft1.c3
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Merge Cond: ((ft1.c1 = (postgres_fdw_abs(ft2.c2))) AND (ft1.c1 = ft2.c1))
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Sort
+ Output: ft2.*, ft2.c1, ft2.c2, (postgres_fdw_abs(ft2.c2))
+ Sort Key: (postgres_fdw_abs(ft2.c2)), ft2.c1
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, postgres_fdw_abs(ft2.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(32 rows)
+
+ALTER SERVER loopback OPTIONS (DROP fdw_startup_cost);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+DROP TABLE local_tbl;
+-- check join pushdown in situations where multiple userids are involved
+CREATE ROLE regress_view_owner SUPERUSER;
+CREATE USER MAPPING FOR regress_view_owner SERVER loopback;
+GRANT SELECT ON ft4 TO regress_view_owner;
+GRANT SELECT ON ft5 TO regress_view_owner;
+CREATE VIEW v4 AS SELECT * FROM ft4;
+CREATE VIEW v5 AS SELECT * FROM ft5;
+ALTER VIEW v5 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, different view owners
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, ft5.c2, ft5.c1
+ -> Sort
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Left Join
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.c2, ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c2, ft5.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r6.c1, r9.c2, r9.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r9 ON (((r6.c1 = r9.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r9.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, view owner not current user
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, t2.c2, t2.c1
+ -> Sort
+ Output: ft4.c1, t2.c2, t2.c1
+ Sort Key: ft4.c1, t2.c1
+ -> Hash Left Join
+ Output: ft4.c1, t2.c2, t2.c1
+ Hash Cond: (ft4.c1 = t2.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: t2.c2, t2.c1
+ -> Foreign Scan on public.ft5 t2
+ Output: t2.c2, t2.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO CURRENT_USER;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c2, t2.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r6.c1, r2.c2, r2.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r2 ON (((r6.c1 = r2.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+-- cleanup
+DROP OWNED BY regress_view_owner;
+DROP ROLE regress_view_owner;
+-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+------+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+ 100 | 49700 | 497.0000000000000000 | 2 | 992 | 0 | 49700
+ 100 | 49800 | 498.0000000000000000 | 3 | 993 | 0 | 49800
+ 100 | 49900 | 499.0000000000000000 | 4 | 994 | 0 | 49900
+ 100 | 50500 | 505.0000000000000000 | 0 | 1000 | 0 | 50500
+(5 rows)
+
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST LIMIT 1::bigint
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+-----+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+(1 row)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * (random() <= 1)::int) as sum, avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Aggregate
+ Output: sum((c1 * ((random() <= '1'::double precision))::integer)), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT count(*), sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ count | sum | avg
+-------+---------+----------------------
+ 10000 | 5010000 | 501.0000000000000000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where ((t1.c1 * t2.c1)/(t1.c1 * t2.c1)) * random() <= 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(t1.c1), count(t2.c1)
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Filter: (((((t1.c1 * t2.c1) / (t1.c1 * t2.c1)))::double precision * random()) <= '1'::double precision)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(7 rows)
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY 1 ORDER BY (c2 / 2) ASC NULLS LAST
+(4 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 500
+ 2 | 1800
+ 3 | 3900
+ 4 | 6800
+(5 rows)
+
+-- Aggregates in subquery are pushed down.
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 ORDER BY c2 ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(6 rows)
+
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+------
+ 1000 | 4500
+(1 row)
+
+-- Aggregate is still pushed down by taking unshippable expression out
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer)), ((sum(c1) * c2)), c2
+ Sort Key: ((ft1.c2 * ((random() <= '1'::double precision))::integer)), ((sum(ft1.c1) * ft1.c2))
+ -> Foreign Scan
+ Output: (c2 * ((random() <= '1'::double precision))::integer), ((sum(c1) * c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum("C 1") * c2), c2 FROM "S 1"."T 1" GROUP BY 2
+(7 rows)
+
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ sum1 | sum2
+------+--------
+ 0 | 0
+ 1 | 49600
+ 2 | 99400
+ 3 | 149400
+ 4 | 199600
+ 5 | 250000
+ 6 | 300600
+ 7 | 351400
+ 8 | 402400
+ 9 | 453600
+(10 rows)
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::int order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Sort Key: ((ft2.c2 * ((random() <= '1'::double precision))::integer))
+ -> HashAggregate
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Group Key: (ft2.c2 * ((random() <= '1'::double precision))::integer)
+ -> Foreign Scan on public.ft2
+ Output: (c2 * ((random() <= '1'::double precision))::integer)
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- GROUP BY clause in various forms, cardinal, alias and constant expression
+explain (verbose, costs off)
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), c2, 5, 7.0, 9 FROM "S 1"."T 1" GROUP BY 2, 3, 5
+(7 rows)
+
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ w | x | y | z
+-----+---+---+-----
+ 100 | 0 | 5 | 7.0
+ 100 | 1 | 5 | 7.0
+ 100 | 2 | 5 | 7.0
+ 100 | 3 | 5 | 7.0
+ 100 | 4 | 5 | 7.0
+ 100 | 5 | 5 | 7.0
+ 100 | 6 | 5 | 7.0
+ 100 | 7 | 5 | 7.0
+ 100 | 8 | 5 | 7.0
+ 100 | 9 | 5 | 7.0
+(10 rows)
+
+-- GROUP BY clause referring to same column multiple times
+-- Also, ORDER BY contains an aggregate function
+explain (verbose, costs off)
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, c2, (sum(c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, c2, sum("C 1") FROM "S 1"."T 1" WHERE ((c2 > 6)) GROUP BY 1, 2 ORDER BY sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ c2 | c2
+----+----
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(3 rows)
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 49800)) ORDER BY c2 ASC NULLS LAST
+(4 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ c2 | sum
+----+-------
+ 1 | 49600
+ 2 | 49700
+(2 rows)
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, NULL::bigint, (sqrt((ft1.c2)::double precision))
+ Filter: (((((avg(ft1.c1)) / (avg(ft1.c1))))::double precision * random()) <= '1'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ count
+-------
+ 49
+(1 row)
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * (random() <= 1)::int) > 100 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1)), c2
+ Sort Key: (sum(ft1.c1))
+ -> HashAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Filter: (avg((ft1.c1 * ((random() <= '1'::double precision))::integer)) > '100'::numeric)
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(10 rows)
+
+-- Remote aggregate in combination with a local Param (for the output
+-- of an initplan) can be trouble, per bug #15781
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ QUERY PLAN
+--------------------------------------------------
+ Foreign Scan
+ Output: $0, (sum(ft1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1"
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+(6 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ QUERY PLAN
+---------------------------------------------------
+ GroupAggregate
+ Output: ($0), sum(ft1.c1)
+ Group Key: $0
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+ -> Foreign Scan on public.ft1
+ Output: $0, ft1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(8 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY 2 ORDER BY array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1,11,21,31,41,51,61,71,81,91}
+ {2,12,22,32,42,52,62,72,82,92}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {5,15,25,35,45,55,65,75,85,95}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+(10 rows)
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5)) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY 2 ORDER BY sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))) ASC NULLS LAST
+(4 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+(10 rows)
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3) ORDER BY (("C 1" % 3)) ASC NULLS LAST) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY 3
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft2 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where (c1 / c1) * random() <= 1) from ft1 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((((ft1.c1 / ft1.c1))::double precision * random()) <= '1'::double precision)))
+ -> HashAggregate
+ Output: sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST), percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
+(7 rows)
+
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | rank | percentile_cont
+----+------+-----------------
+ 0 | 101 | 10
+ 1 | 101 | 100
+ 2 | 1 | 200
+ 3 | 1 | 300
+ 4 | 1 | 400
+(5 rows)
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY 1, 3
+(4 rows)
+
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ c1 | rank
+----+------
+ 6 | 1
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Disable hash aggregation for plan stability.
+set enable_hashagg to false;
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY 1
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 0 | 10
+ 1 | 1
+ 2 | 2
+ 3 | 3
+ 4 | 4
+ 5 | 5
+ 6 | 6
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(10 rows)
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Cleanup
+reset enable_hashagg;
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+create operator family my_op_family using btree;
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- This should not be pushed either.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- Update local stats on ft2
+ANALYZE ft2;
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now this will be pushed as sort operator is part of the extension.
+alter server loopback options (add fdw_tuple_cost '0.5');
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY 2
+(4 rows)
+
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+alter server loopback options (drop fdw_tuple_cost);
+-- This should be pushed too.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST
+(3 rows)
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft2 t1 left join ft2 t2 on (t1.c1 = random() * t2.c2);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop Left Join
+ Output: t1.c3
+ Join Filter: ((t1.c1)::double precision = (random() * (t2.c2)::double precision))
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c3, t1.c1
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1"
+ -> Materialize
+ Output: t2.c2
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(13 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Inner Unique: true
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1 ft1_1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1
+(21 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 100 | 49600
+ 100 | 49700
+ 100 | 49800
+ 100 | 49900
+ 100 | 50000
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(10 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY 3 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL))) ORDER BY avg(r1.c1) ASC NULLS LAST, sum(r2.c1) ASC NULLS LAST
+(4 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- Aggregate over FULL join needing to deparse the joining relations as
+-- subqueries.
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(ft4.c1)), (avg(ft5.c1))
+ Relations: Aggregate on ((public.ft4) FULL JOIN (public.ft5))
+ Remote SQL: SELECT count(*), sum(s4.c1), avg(s5.c1) FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ count | sum | avg
+-------+-----+---------------------
+ 8 | 330 | 55.5000000000000000
+(1 row)
+
+-- ORDER BY expression is part of the target list but not pushed down to
+-- foreign server.
+explain (verbose, costs off)
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: (((sum(c2)) * ((random() <= '1'::double precision))::integer))
+ Sort Key: (((sum(ft1.c2)) * ((random() <= '1'::double precision))::integer))
+ -> Foreign Scan
+ Output: ((sum(c2)) * ((random() <= '1'::double precision))::integer)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
+(7 rows)
+
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ sum
+------
+ 4500
+(1 row)
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c2, qry.sum
+ Sort Key: t1.c2
+ -> Nested Loop
+ Output: t1.c2, qry.sum
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Index Cond: (t1."C 1" < 100)
+ Filter: (t1.c2 < 3)
+ -> Subquery Scan on qry
+ Output: qry.sum, t2.c1
+ Filter: ((t1.c2 * 2) = qry.sum)
+ -> Foreign Scan
+ Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY 2
+(16 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ c2 | sum
+----+-----
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+reset enable_hashagg;
+-- bug #15613: bad plan for foreign table scan with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: ref_0.c2, ref_0."C 1", (ref_0.c2), ref_1.c3, ref_0."C 1"
+ -> Nested Loop
+ Output: ref_0.c2, ref_0."C 1", ref_1.c3, (ref_0.c2)
+ -> Index Scan using t1_pkey on "S 1"."T 1" ref_0
+ Output: ref_0."C 1", ref_0.c2, ref_0.c3, ref_0.c4, ref_0.c5, ref_0.c6, ref_0.c7, ref_0.c8
+ Index Cond: (ref_0."C 1" < 10)
+ -> Foreign Scan on public.ft1 ref_1
+ Output: ref_1.c3, ref_0.c2
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+ -> Materialize
+ Output: ref_3.c3
+ -> Foreign Scan on public.ft2 ref_3
+ Output: ref_3.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+(15 rows)
+
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ c2 | c1 | c2 | c3
+----+----+----+-------
+ 1 | 1 | 1 | 00001
+ 2 | 2 | 2 | 00001
+ 3 | 3 | 3 | 00001
+ 4 | 4 | 4 | 00001
+ 5 | 5 | 5 | 00001
+ 6 | 6 | 6 | 00001
+ 7 | 7 | 7 | 00001
+ 8 | 8 | 8 | 00001
+ 9 | 9 | 9 | 00001
+(9 rows)
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(q.a), count(q.b)
+ -> Nested Loop Left Join
+ Output: q.a, q.b
+ Inner Unique: true
+ Join Filter: ((ft4.c1)::numeric <= q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Materialize
+ Output: q.a, q.b
+ -> Subquery Scan on q
+ Output: q.a, q.b
+ -> Foreign Scan
+ Output: 13, (avg(ft1.c1)), NULL::bigint
+ Relations: Aggregate on ((public.ft2) LEFT JOIN (public.ft1))
+ Remote SQL: SELECT 13, avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1"))))
+(17 rows)
+
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ sum | count
+-----+-------
+ 650 | 50
+(1 row)
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: c2, c6, (sum(c1))
+ Sort Key: ft1.c2, ft1.c6
+ -> HashAggregate
+ Output: c2, c6, sum(c1)
+ Hash Key: ft1.c2
+ Hash Key: ft1.c6
+ -> Foreign Scan on public.ft1
+ Output: c2, c6, c1
+ Remote SQL: SELECT "C 1", c2, c6 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 0 | | 50500
+ 1 | | 49600
+ 2 | | 49700
+ | 0 | 50500
+ | 1 | 49600
+ | 2 | 49700
+(6 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1)), (GROUPING(c2))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, sum(c1), GROUPING(c2)
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(9 rows)
+
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 0 | 50500 | 0
+ 1 | 49600 | 0
+ 2 | 49700 | 0
+(3 rows)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((sum(c1) / 1000)), c2
+ -> Sort
+ Output: ((sum(c1) / 1000)), c2
+ Sort Key: ((sum(ft2.c1) / 1000))
+ -> Foreign Scan
+ Output: ((sum(c1) / 1000)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT (sum("C 1") / 1000), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY 2
+(9 rows)
+
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ s
+----
+ 49
+ 50
+(2 rows)
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2)), (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, (sum(c2)), count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ c2 | sum | count
+----+-----+-------
+ 0 | 0 | 5
+ 1 | 100 | 5
+ 2 | 200 | 5
+ 3 | 300 | 5
+ 4 | 400 | 5
+ 5 | 500 | 5
+ 6 | 600 | 5
+ 7 | 700 | 5
+ 8 | 800 | 5
+ 9 | 900 | 5
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2 DESC
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {8,6,4,2,0}
+ 1 | {9,7,5,3,1}
+ 2 | {8,6,4,2}
+ 3 | {9,7,5,3}
+ 4 | {8,6,4}
+ 5 | {9,7,5}
+ 6 | {8,6}
+ 7 | {9,7}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {0,2,4,6,8}
+ 1 | {1,3,5,7,9}
+ 2 | {2,4,6,8}
+ 3 | {3,5,7,9}
+ 4 | {4,6,8}
+ 5 | {5,7,9}
+ 6 | {6,8}
+ 7 | {7,9}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+-- ===================================================================
+-- parameterized queries
+-- ===================================================================
+-- simple join
+PREPARE st1(int, int) AS SELECT t1.c3, t2.c3 FROM ft1 t1, ft2 t2 WHERE t1.c1 = $1 AND t2.c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st1(1, 2);
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c3, t2.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.c3, r2.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 2)) AND ((r1."C 1" = 1))))
+(4 rows)
+
+EXECUTE st1(1, 1);
+ c3 | c3
+-------+-------
+ 00001 | 00001
+(1 row)
+
+EXECUTE st1(101, 101);
+ c3 | c3
+-------+-------
+ 00101 | 00101
+(1 row)
+
+-- subquery using stable function (can't be sent to remote)
+PREPARE st2(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c4) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st2(10, 20);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t2.c3 = t1.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Filter: (date(t2.c4) = '01-17-1970'::date)
+ Remote SQL: SELECT c3, c4 FROM "S 1"."T 1" WHERE (("C 1" > 10))
+(15 rows)
+
+EXECUTE st2(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st2(101, 121);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+-- subquery using immutable function (can be sent to remote)
+PREPARE st3(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c5) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st3(10, 20);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t2.c3 = t1.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" > 10)) AND ((date(c5) = '1970-01-17'::date))
+(14 rows)
+
+EXECUTE st3(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st3(20, 30);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- custom plan should be chosen initially
+PREPARE st4(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 = $1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+-- once we try it enough times, should switch to generic plan
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(3 rows)
+
+-- value of $1 should not be sent to remote
+PREPARE st5(user_enum,int) AS SELECT * FROM ft1 t1 WHERE c8 = $1 and c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = $1)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(4 rows)
+
+EXECUTE st5('foo', 1);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- altering FDW options requires replanning
+PREPARE st6 AS SELECT * FROM ft1 t1 WHERE t1.c1 = t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(3 rows)
+
+PREPARE st7 AS INSERT INTO ft1 (c1,c2,c3) VALUES (1001,101,'foo');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 1" RENAME TO "T 0";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 0');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 0" WHERE (("C 1" = c2))
+(3 rows)
+
+EXECUTE st6;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 0"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 0" RENAME TO "T 1";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 1');
+PREPARE st8 AS SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+EXECUTE st8;
+ count
+-------
+ 9
+(1 row)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- cleanup
+DEALLOCATE st1;
+DEALLOCATE st2;
+DEALLOCATE st3;
+DEALLOCATE st4;
+DEALLOCATE st5;
+DEALLOCATE st6;
+DEALLOCATE st7;
+DEALLOCATE st8;
+-- System columns, except ctid and oid, should not be sent to remote
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'pg_class'::regclass LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.tableoid = '1259'::oid)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'ft1'::regclass LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: (tableoid)::regclass, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ tableoid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ ft1 | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((ctid = '(0,2)'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: ctid, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ ctid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ (0,1) | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- ===================================================================
+-- used in PL/pgSQL function
+-- ===================================================================
+CREATE OR REPLACE FUNCTION f_test(p_c1 int) RETURNS int AS $$
+DECLARE
+ v_c1 int;
+BEGIN
+ SELECT c1 INTO v_c1 FROM ft1 WHERE c1 = p_c1 LIMIT 1;
+ PERFORM c1 FROM ft1 WHERE c1 = p_c1 AND p_c1 = v_c1 LIMIT 1;
+ RETURN v_c1;
+END;
+$$ LANGUAGE plpgsql;
+SELECT f_test(100);
+ f_test
+--------
+ 100
+(1 row)
+
+DROP FUNCTION f_test(int);
+-- ===================================================================
+-- REINDEX
+-- ===================================================================
+-- remote table is not created here
+CREATE FOREIGN TABLE reindex_foreign (c1 int, c2 int)
+ SERVER loopback2 OPTIONS (table_name 'reindex_local');
+REINDEX TABLE reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+REINDEX TABLE CONCURRENTLY reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+DROP FOREIGN TABLE reindex_foreign;
+-- partitions and foreign tables
+CREATE TABLE reind_fdw_parent (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE reind_fdw_0_10 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (0) TO (10);
+CREATE FOREIGN TABLE reind_fdw_10_20 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (10) TO (20)
+ SERVER loopback OPTIONS (table_name 'reind_local_10_20');
+REINDEX TABLE reind_fdw_parent; -- ok
+REINDEX TABLE CONCURRENTLY reind_fdw_parent; -- ok
+DROP TABLE reind_fdw_parent;
+-- ===================================================================
+-- conversion error
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int;
+SELECT * FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8) WHERE x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx.x8 FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: whole-row reference to foreign table "ftx"
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: processing expression at position 2 in select list
+ANALYZE ft1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "c8" of foreign table "ft1"
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- local type can be different from remote type in some cases,
+-- in particular if similarly-named operators do equivalent things
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE text;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 = 'foo')) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (('foo' = c8)) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- we declared c8 to be text locally, but it's still the same type on
+-- the remote which will balk if we try to do anything incompatible
+-- with that remote type
+SELECT * FROM ft1 WHERE c8 LIKE 'foo' LIMIT 1; -- ERROR
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+SELECT * FROM ft1 WHERE c8::text LIKE 'foo' LIMIT 1; -- ERROR; cast not pushed down
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- subtransaction
+-- + local/remote error doesn't break cursor
+-- ===================================================================
+BEGIN;
+DECLARE c CURSOR FOR SELECT * FROM ft1 ORDER BY c1;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+SAVEPOINT s;
+ERROR OUT; -- ERROR
+ERROR: syntax error at or near "ERROR"
+LINE 1: ERROR OUT;
+ ^
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+SAVEPOINT s;
+SELECT * FROM ft1 WHERE 1 / (c1 - 1) > 0; -- ERROR
+ERROR: division by zero
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (((1 / ("C 1" - 1)) > 0))
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c1 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+COMMIT;
+-- ===================================================================
+-- test handling of collations
+-- ===================================================================
+create table loct3 (f1 text collate "C" unique, f2 text, f3 varchar(10) unique);
+create foreign table ft3 (f1 text collate "C", f2 text, f3 varchar(10))
+ server loopback options (table_name 'loct3', use_remote_estimate 'true');
+-- can be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "C" = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f2 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f3 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 and l.f1 = 'foo';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = $1::character varying(10)))
+(8 rows)
+
+-- can't be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "POSIX" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f1)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f1 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 COLLATE "C" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f2)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f2 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 COLLATE "POSIX" and l.f1 = 'foo';
+ QUERY PLAN
+-------------------------------------------------------------
+ Hash Join
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ Inner Unique: true
+ Hash Cond: ((f.f3)::text = (l.f3)::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+ -> Hash
+ Output: l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+(12 rows)
+
+-- ===================================================================
+-- test writable foreign table stuff
+-- ===================================================================
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Subquery Scan on "*SELECT*"
+ Output: "*SELECT*"."?column?", "*SELECT*"."?column?_1", NULL::integer, "*SELECT*"."?column?_2", NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+ -> Foreign Scan on public.ft2 ft2_1
+ Output: (ft2_1.c1 + 1000), (ft2_1.c2 + 100), (ft2_1.c3 || ft2_1.c3)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" LIMIT 20::bigint
+(8 rows)
+
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+INSERT INTO ft2 (c1,c2,c3)
+ VALUES (1101,201,'aaa'), (1102,202,'bbb'), (1103,203,'ccc') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----+----+----+----+------------+----
+ 1101 | 201 | aaa | | | | ft2 |
+ 1102 | 202 | bbb | | | | ft2 |
+ 1103 | 203 | ccc | | | | ft2 |
+(3 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1104,204,'ddd'), (1105,205,'eee');
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 300), c3 = (c3 || '_update3') WHERE ((("C 1" % 10) = 3))
+(3 rows)
+
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 400), c3 = (c3 || '_update7') WHERE ((("C 1" % 10) = 7)) RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+(4 rows)
+
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+----+------------+-----
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 1007 | 507 | 0000700007_update7 | | | | ft2 |
+ 1017 | 507 | 0001700017_update7 | | | | ft2 |
+(102 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9; -- can be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c2 = (r1.c2 + 500), c3 = (r1.c3 || '_update9'), c7 = 'ft2 '::character(10) FROM "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 9))
+(3 rows)
+
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9;
+EXPLAIN (verbose, costs off)
+ DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: c1, c4
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 5)) RETURNING "C 1", c4
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4;
+ c1 | c4
+------+------------------------------
+ 5 | Tue Jan 06 00:00:00 1970 PST
+ 15 | Fri Jan 16 00:00:00 1970 PST
+ 25 | Mon Jan 26 00:00:00 1970 PST
+ 35 | Thu Feb 05 00:00:00 1970 PST
+ 45 | Sun Feb 15 00:00:00 1970 PST
+ 55 | Wed Feb 25 00:00:00 1970 PST
+ 65 | Sat Mar 07 00:00:00 1970 PST
+ 75 | Tue Mar 17 00:00:00 1970 PST
+ 85 | Fri Mar 27 00:00:00 1970 PST
+ 95 | Mon Apr 06 00:00:00 1970 PST
+ 105 | Tue Jan 06 00:00:00 1970 PST
+ 115 | Fri Jan 16 00:00:00 1970 PST
+ 125 | Mon Jan 26 00:00:00 1970 PST
+ 135 | Thu Feb 05 00:00:00 1970 PST
+ 145 | Sun Feb 15 00:00:00 1970 PST
+ 155 | Wed Feb 25 00:00:00 1970 PST
+ 165 | Sat Mar 07 00:00:00 1970 PST
+ 175 | Tue Mar 17 00:00:00 1970 PST
+ 185 | Fri Mar 27 00:00:00 1970 PST
+ 195 | Mon Apr 06 00:00:00 1970 PST
+ 205 | Tue Jan 06 00:00:00 1970 PST
+ 215 | Fri Jan 16 00:00:00 1970 PST
+ 225 | Mon Jan 26 00:00:00 1970 PST
+ 235 | Thu Feb 05 00:00:00 1970 PST
+ 245 | Sun Feb 15 00:00:00 1970 PST
+ 255 | Wed Feb 25 00:00:00 1970 PST
+ 265 | Sat Mar 07 00:00:00 1970 PST
+ 275 | Tue Mar 17 00:00:00 1970 PST
+ 285 | Fri Mar 27 00:00:00 1970 PST
+ 295 | Mon Apr 06 00:00:00 1970 PST
+ 305 | Tue Jan 06 00:00:00 1970 PST
+ 315 | Fri Jan 16 00:00:00 1970 PST
+ 325 | Mon Jan 26 00:00:00 1970 PST
+ 335 | Thu Feb 05 00:00:00 1970 PST
+ 345 | Sun Feb 15 00:00:00 1970 PST
+ 355 | Wed Feb 25 00:00:00 1970 PST
+ 365 | Sat Mar 07 00:00:00 1970 PST
+ 375 | Tue Mar 17 00:00:00 1970 PST
+ 385 | Fri Mar 27 00:00:00 1970 PST
+ 395 | Mon Apr 06 00:00:00 1970 PST
+ 405 | Tue Jan 06 00:00:00 1970 PST
+ 415 | Fri Jan 16 00:00:00 1970 PST
+ 425 | Mon Jan 26 00:00:00 1970 PST
+ 435 | Thu Feb 05 00:00:00 1970 PST
+ 445 | Sun Feb 15 00:00:00 1970 PST
+ 455 | Wed Feb 25 00:00:00 1970 PST
+ 465 | Sat Mar 07 00:00:00 1970 PST
+ 475 | Tue Mar 17 00:00:00 1970 PST
+ 485 | Fri Mar 27 00:00:00 1970 PST
+ 495 | Mon Apr 06 00:00:00 1970 PST
+ 505 | Tue Jan 06 00:00:00 1970 PST
+ 515 | Fri Jan 16 00:00:00 1970 PST
+ 525 | Mon Jan 26 00:00:00 1970 PST
+ 535 | Thu Feb 05 00:00:00 1970 PST
+ 545 | Sun Feb 15 00:00:00 1970 PST
+ 555 | Wed Feb 25 00:00:00 1970 PST
+ 565 | Sat Mar 07 00:00:00 1970 PST
+ 575 | Tue Mar 17 00:00:00 1970 PST
+ 585 | Fri Mar 27 00:00:00 1970 PST
+ 595 | Mon Apr 06 00:00:00 1970 PST
+ 605 | Tue Jan 06 00:00:00 1970 PST
+ 615 | Fri Jan 16 00:00:00 1970 PST
+ 625 | Mon Jan 26 00:00:00 1970 PST
+ 635 | Thu Feb 05 00:00:00 1970 PST
+ 645 | Sun Feb 15 00:00:00 1970 PST
+ 655 | Wed Feb 25 00:00:00 1970 PST
+ 665 | Sat Mar 07 00:00:00 1970 PST
+ 675 | Tue Mar 17 00:00:00 1970 PST
+ 685 | Fri Mar 27 00:00:00 1970 PST
+ 695 | Mon Apr 06 00:00:00 1970 PST
+ 705 | Tue Jan 06 00:00:00 1970 PST
+ 715 | Fri Jan 16 00:00:00 1970 PST
+ 725 | Mon Jan 26 00:00:00 1970 PST
+ 735 | Thu Feb 05 00:00:00 1970 PST
+ 745 | Sun Feb 15 00:00:00 1970 PST
+ 755 | Wed Feb 25 00:00:00 1970 PST
+ 765 | Sat Mar 07 00:00:00 1970 PST
+ 775 | Tue Mar 17 00:00:00 1970 PST
+ 785 | Fri Mar 27 00:00:00 1970 PST
+ 795 | Mon Apr 06 00:00:00 1970 PST
+ 805 | Tue Jan 06 00:00:00 1970 PST
+ 815 | Fri Jan 16 00:00:00 1970 PST
+ 825 | Mon Jan 26 00:00:00 1970 PST
+ 835 | Thu Feb 05 00:00:00 1970 PST
+ 845 | Sun Feb 15 00:00:00 1970 PST
+ 855 | Wed Feb 25 00:00:00 1970 PST
+ 865 | Sat Mar 07 00:00:00 1970 PST
+ 875 | Tue Mar 17 00:00:00 1970 PST
+ 885 | Fri Mar 27 00:00:00 1970 PST
+ 895 | Mon Apr 06 00:00:00 1970 PST
+ 905 | Tue Jan 06 00:00:00 1970 PST
+ 915 | Fri Jan 16 00:00:00 1970 PST
+ 925 | Mon Jan 26 00:00:00 1970 PST
+ 935 | Thu Feb 05 00:00:00 1970 PST
+ 945 | Sun Feb 15 00:00:00 1970 PST
+ 955 | Wed Feb 25 00:00:00 1970 PST
+ 965 | Sat Mar 07 00:00:00 1970 PST
+ 975 | Tue Mar 17 00:00:00 1970 PST
+ 985 | Fri Mar 27 00:00:00 1970 PST
+ 995 | Mon Apr 06 00:00:00 1970 PST
+ 1005 |
+ 1015 |
+ 1105 |
+(103 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 2))
+(3 rows)
+
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2;
+SELECT c1,c2,c3,c4 FROM ft2 ORDER BY c1;
+ c1 | c2 | c3 | c4
+------+-----+--------------------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 3 | 303 | 00003_update3 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+ 11 | 1 | 00011 | Mon Jan 12 00:00:00 1970 PST
+ 13 | 303 | 00013_update3 | Wed Jan 14 00:00:00 1970 PST
+ 14 | 4 | 00014 | Thu Jan 15 00:00:00 1970 PST
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST
+ 18 | 8 | 00018 | Mon Jan 19 00:00:00 1970 PST
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST
+ 20 | 0 | 00020 | Wed Jan 21 00:00:00 1970 PST
+ 21 | 1 | 00021 | Thu Jan 22 00:00:00 1970 PST
+ 23 | 303 | 00023_update3 | Sat Jan 24 00:00:00 1970 PST
+ 24 | 4 | 00024 | Sun Jan 25 00:00:00 1970 PST
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST
+ 28 | 8 | 00028 | Thu Jan 29 00:00:00 1970 PST
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST
+ 30 | 0 | 00030 | Sat Jan 31 00:00:00 1970 PST
+ 31 | 1 | 00031 | Sun Feb 01 00:00:00 1970 PST
+ 33 | 303 | 00033_update3 | Tue Feb 03 00:00:00 1970 PST
+ 34 | 4 | 00034 | Wed Feb 04 00:00:00 1970 PST
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST
+ 38 | 8 | 00038 | Sun Feb 08 00:00:00 1970 PST
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST
+ 40 | 0 | 00040 | Tue Feb 10 00:00:00 1970 PST
+ 41 | 1 | 00041 | Wed Feb 11 00:00:00 1970 PST
+ 43 | 303 | 00043_update3 | Fri Feb 13 00:00:00 1970 PST
+ 44 | 4 | 00044 | Sat Feb 14 00:00:00 1970 PST
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST
+ 48 | 8 | 00048 | Wed Feb 18 00:00:00 1970 PST
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST
+ 50 | 0 | 00050 | Fri Feb 20 00:00:00 1970 PST
+ 51 | 1 | 00051 | Sat Feb 21 00:00:00 1970 PST
+ 53 | 303 | 00053_update3 | Mon Feb 23 00:00:00 1970 PST
+ 54 | 4 | 00054 | Tue Feb 24 00:00:00 1970 PST
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST
+ 58 | 8 | 00058 | Sat Feb 28 00:00:00 1970 PST
+ 59 | 509 | 00059_update9 | Sun Mar 01 00:00:00 1970 PST
+ 60 | 0 | 00060 | Mon Mar 02 00:00:00 1970 PST
+ 61 | 1 | 00061 | Tue Mar 03 00:00:00 1970 PST
+ 63 | 303 | 00063_update3 | Thu Mar 05 00:00:00 1970 PST
+ 64 | 4 | 00064 | Fri Mar 06 00:00:00 1970 PST
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST
+ 68 | 8 | 00068 | Tue Mar 10 00:00:00 1970 PST
+ 69 | 509 | 00069_update9 | Wed Mar 11 00:00:00 1970 PST
+ 70 | 0 | 00070 | Thu Mar 12 00:00:00 1970 PST
+ 71 | 1 | 00071 | Fri Mar 13 00:00:00 1970 PST
+ 73 | 303 | 00073_update3 | Sun Mar 15 00:00:00 1970 PST
+ 74 | 4 | 00074 | Mon Mar 16 00:00:00 1970 PST
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST
+ 78 | 8 | 00078 | Fri Mar 20 00:00:00 1970 PST
+ 79 | 509 | 00079_update9 | Sat Mar 21 00:00:00 1970 PST
+ 80 | 0 | 00080 | Sun Mar 22 00:00:00 1970 PST
+ 81 | 1 | 00081 | Mon Mar 23 00:00:00 1970 PST
+ 83 | 303 | 00083_update3 | Wed Mar 25 00:00:00 1970 PST
+ 84 | 4 | 00084 | Thu Mar 26 00:00:00 1970 PST
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST
+ 88 | 8 | 00088 | Mon Mar 30 00:00:00 1970 PST
+ 89 | 509 | 00089_update9 | Tue Mar 31 00:00:00 1970 PST
+ 90 | 0 | 00090 | Wed Apr 01 00:00:00 1970 PST
+ 91 | 1 | 00091 | Thu Apr 02 00:00:00 1970 PST
+ 93 | 303 | 00093_update3 | Sat Apr 04 00:00:00 1970 PST
+ 94 | 4 | 00094 | Sun Apr 05 00:00:00 1970 PST
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST
+ 98 | 8 | 00098 | Thu Apr 09 00:00:00 1970 PST
+ 99 | 509 | 00099_update9 | Fri Apr 10 00:00:00 1970 PST
+ 100 | 0 | 00100 | Thu Jan 01 00:00:00 1970 PST
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST
+ 103 | 303 | 00103_update3 | Sun Jan 04 00:00:00 1970 PST
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST
+ 109 | 509 | 00109_update9 | Sat Jan 10 00:00:00 1970 PST
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST
+ 111 | 1 | 00111 | Mon Jan 12 00:00:00 1970 PST
+ 113 | 303 | 00113_update3 | Wed Jan 14 00:00:00 1970 PST
+ 114 | 4 | 00114 | Thu Jan 15 00:00:00 1970 PST
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST
+ 118 | 8 | 00118 | Mon Jan 19 00:00:00 1970 PST
+ 119 | 509 | 00119_update9 | Tue Jan 20 00:00:00 1970 PST
+ 120 | 0 | 00120 | Wed Jan 21 00:00:00 1970 PST
+ 121 | 1 | 00121 | Thu Jan 22 00:00:00 1970 PST
+ 123 | 303 | 00123_update3 | Sat Jan 24 00:00:00 1970 PST
+ 124 | 4 | 00124 | Sun Jan 25 00:00:00 1970 PST
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST
+ 128 | 8 | 00128 | Thu Jan 29 00:00:00 1970 PST
+ 129 | 509 | 00129_update9 | Fri Jan 30 00:00:00 1970 PST
+ 130 | 0 | 00130 | Sat Jan 31 00:00:00 1970 PST
+ 131 | 1 | 00131 | Sun Feb 01 00:00:00 1970 PST
+ 133 | 303 | 00133_update3 | Tue Feb 03 00:00:00 1970 PST
+ 134 | 4 | 00134 | Wed Feb 04 00:00:00 1970 PST
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST
+ 138 | 8 | 00138 | Sun Feb 08 00:00:00 1970 PST
+ 139 | 509 | 00139_update9 | Mon Feb 09 00:00:00 1970 PST
+ 140 | 0 | 00140 | Tue Feb 10 00:00:00 1970 PST
+ 141 | 1 | 00141 | Wed Feb 11 00:00:00 1970 PST
+ 143 | 303 | 00143_update3 | Fri Feb 13 00:00:00 1970 PST
+ 144 | 4 | 00144 | Sat Feb 14 00:00:00 1970 PST
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST
+ 148 | 8 | 00148 | Wed Feb 18 00:00:00 1970 PST
+ 149 | 509 | 00149_update9 | Thu Feb 19 00:00:00 1970 PST
+ 150 | 0 | 00150 | Fri Feb 20 00:00:00 1970 PST
+ 151 | 1 | 00151 | Sat Feb 21 00:00:00 1970 PST
+ 153 | 303 | 00153_update3 | Mon Feb 23 00:00:00 1970 PST
+ 154 | 4 | 00154 | Tue Feb 24 00:00:00 1970 PST
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST
+ 158 | 8 | 00158 | Sat Feb 28 00:00:00 1970 PST
+ 159 | 509 | 00159_update9 | Sun Mar 01 00:00:00 1970 PST
+ 160 | 0 | 00160 | Mon Mar 02 00:00:00 1970 PST
+ 161 | 1 | 00161 | Tue Mar 03 00:00:00 1970 PST
+ 163 | 303 | 00163_update3 | Thu Mar 05 00:00:00 1970 PST
+ 164 | 4 | 00164 | Fri Mar 06 00:00:00 1970 PST
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST
+ 168 | 8 | 00168 | Tue Mar 10 00:00:00 1970 PST
+ 169 | 509 | 00169_update9 | Wed Mar 11 00:00:00 1970 PST
+ 170 | 0 | 00170 | Thu Mar 12 00:00:00 1970 PST
+ 171 | 1 | 00171 | Fri Mar 13 00:00:00 1970 PST
+ 173 | 303 | 00173_update3 | Sun Mar 15 00:00:00 1970 PST
+ 174 | 4 | 00174 | Mon Mar 16 00:00:00 1970 PST
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST
+ 178 | 8 | 00178 | Fri Mar 20 00:00:00 1970 PST
+ 179 | 509 | 00179_update9 | Sat Mar 21 00:00:00 1970 PST
+ 180 | 0 | 00180 | Sun Mar 22 00:00:00 1970 PST
+ 181 | 1 | 00181 | Mon Mar 23 00:00:00 1970 PST
+ 183 | 303 | 00183_update3 | Wed Mar 25 00:00:00 1970 PST
+ 184 | 4 | 00184 | Thu Mar 26 00:00:00 1970 PST
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST
+ 188 | 8 | 00188 | Mon Mar 30 00:00:00 1970 PST
+ 189 | 509 | 00189_update9 | Tue Mar 31 00:00:00 1970 PST
+ 190 | 0 | 00190 | Wed Apr 01 00:00:00 1970 PST
+ 191 | 1 | 00191 | Thu Apr 02 00:00:00 1970 PST
+ 193 | 303 | 00193_update3 | Sat Apr 04 00:00:00 1970 PST
+ 194 | 4 | 00194 | Sun Apr 05 00:00:00 1970 PST
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST
+ 198 | 8 | 00198 | Thu Apr 09 00:00:00 1970 PST
+ 199 | 509 | 00199_update9 | Fri Apr 10 00:00:00 1970 PST
+ 200 | 0 | 00200 | Thu Jan 01 00:00:00 1970 PST
+ 201 | 1 | 00201 | Fri Jan 02 00:00:00 1970 PST
+ 203 | 303 | 00203_update3 | Sun Jan 04 00:00:00 1970 PST
+ 204 | 4 | 00204 | Mon Jan 05 00:00:00 1970 PST
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST
+ 208 | 8 | 00208 | Fri Jan 09 00:00:00 1970 PST
+ 209 | 509 | 00209_update9 | Sat Jan 10 00:00:00 1970 PST
+ 210 | 0 | 00210 | Sun Jan 11 00:00:00 1970 PST
+ 211 | 1 | 00211 | Mon Jan 12 00:00:00 1970 PST
+ 213 | 303 | 00213_update3 | Wed Jan 14 00:00:00 1970 PST
+ 214 | 4 | 00214 | Thu Jan 15 00:00:00 1970 PST
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST
+ 218 | 8 | 00218 | Mon Jan 19 00:00:00 1970 PST
+ 219 | 509 | 00219_update9 | Tue Jan 20 00:00:00 1970 PST
+ 220 | 0 | 00220 | Wed Jan 21 00:00:00 1970 PST
+ 221 | 1 | 00221 | Thu Jan 22 00:00:00 1970 PST
+ 223 | 303 | 00223_update3 | Sat Jan 24 00:00:00 1970 PST
+ 224 | 4 | 00224 | Sun Jan 25 00:00:00 1970 PST
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST
+ 228 | 8 | 00228 | Thu Jan 29 00:00:00 1970 PST
+ 229 | 509 | 00229_update9 | Fri Jan 30 00:00:00 1970 PST
+ 230 | 0 | 00230 | Sat Jan 31 00:00:00 1970 PST
+ 231 | 1 | 00231 | Sun Feb 01 00:00:00 1970 PST
+ 233 | 303 | 00233_update3 | Tue Feb 03 00:00:00 1970 PST
+ 234 | 4 | 00234 | Wed Feb 04 00:00:00 1970 PST
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST
+ 238 | 8 | 00238 | Sun Feb 08 00:00:00 1970 PST
+ 239 | 509 | 00239_update9 | Mon Feb 09 00:00:00 1970 PST
+ 240 | 0 | 00240 | Tue Feb 10 00:00:00 1970 PST
+ 241 | 1 | 00241 | Wed Feb 11 00:00:00 1970 PST
+ 243 | 303 | 00243_update3 | Fri Feb 13 00:00:00 1970 PST
+ 244 | 4 | 00244 | Sat Feb 14 00:00:00 1970 PST
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST
+ 248 | 8 | 00248 | Wed Feb 18 00:00:00 1970 PST
+ 249 | 509 | 00249_update9 | Thu Feb 19 00:00:00 1970 PST
+ 250 | 0 | 00250 | Fri Feb 20 00:00:00 1970 PST
+ 251 | 1 | 00251 | Sat Feb 21 00:00:00 1970 PST
+ 253 | 303 | 00253_update3 | Mon Feb 23 00:00:00 1970 PST
+ 254 | 4 | 00254 | Tue Feb 24 00:00:00 1970 PST
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST
+ 258 | 8 | 00258 | Sat Feb 28 00:00:00 1970 PST
+ 259 | 509 | 00259_update9 | Sun Mar 01 00:00:00 1970 PST
+ 260 | 0 | 00260 | Mon Mar 02 00:00:00 1970 PST
+ 261 | 1 | 00261 | Tue Mar 03 00:00:00 1970 PST
+ 263 | 303 | 00263_update3 | Thu Mar 05 00:00:00 1970 PST
+ 264 | 4 | 00264 | Fri Mar 06 00:00:00 1970 PST
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST
+ 268 | 8 | 00268 | Tue Mar 10 00:00:00 1970 PST
+ 269 | 509 | 00269_update9 | Wed Mar 11 00:00:00 1970 PST
+ 270 | 0 | 00270 | Thu Mar 12 00:00:00 1970 PST
+ 271 | 1 | 00271 | Fri Mar 13 00:00:00 1970 PST
+ 273 | 303 | 00273_update3 | Sun Mar 15 00:00:00 1970 PST
+ 274 | 4 | 00274 | Mon Mar 16 00:00:00 1970 PST
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST
+ 278 | 8 | 00278 | Fri Mar 20 00:00:00 1970 PST
+ 279 | 509 | 00279_update9 | Sat Mar 21 00:00:00 1970 PST
+ 280 | 0 | 00280 | Sun Mar 22 00:00:00 1970 PST
+ 281 | 1 | 00281 | Mon Mar 23 00:00:00 1970 PST
+ 283 | 303 | 00283_update3 | Wed Mar 25 00:00:00 1970 PST
+ 284 | 4 | 00284 | Thu Mar 26 00:00:00 1970 PST
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST
+ 288 | 8 | 00288 | Mon Mar 30 00:00:00 1970 PST
+ 289 | 509 | 00289_update9 | Tue Mar 31 00:00:00 1970 PST
+ 290 | 0 | 00290 | Wed Apr 01 00:00:00 1970 PST
+ 291 | 1 | 00291 | Thu Apr 02 00:00:00 1970 PST
+ 293 | 303 | 00293_update3 | Sat Apr 04 00:00:00 1970 PST
+ 294 | 4 | 00294 | Sun Apr 05 00:00:00 1970 PST
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST
+ 298 | 8 | 00298 | Thu Apr 09 00:00:00 1970 PST
+ 299 | 509 | 00299_update9 | Fri Apr 10 00:00:00 1970 PST
+ 300 | 0 | 00300 | Thu Jan 01 00:00:00 1970 PST
+ 301 | 1 | 00301 | Fri Jan 02 00:00:00 1970 PST
+ 303 | 303 | 00303_update3 | Sun Jan 04 00:00:00 1970 PST
+ 304 | 4 | 00304 | Mon Jan 05 00:00:00 1970 PST
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST
+ 308 | 8 | 00308 | Fri Jan 09 00:00:00 1970 PST
+ 309 | 509 | 00309_update9 | Sat Jan 10 00:00:00 1970 PST
+ 310 | 0 | 00310 | Sun Jan 11 00:00:00 1970 PST
+ 311 | 1 | 00311 | Mon Jan 12 00:00:00 1970 PST
+ 313 | 303 | 00313_update3 | Wed Jan 14 00:00:00 1970 PST
+ 314 | 4 | 00314 | Thu Jan 15 00:00:00 1970 PST
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST
+ 318 | 8 | 00318 | Mon Jan 19 00:00:00 1970 PST
+ 319 | 509 | 00319_update9 | Tue Jan 20 00:00:00 1970 PST
+ 320 | 0 | 00320 | Wed Jan 21 00:00:00 1970 PST
+ 321 | 1 | 00321 | Thu Jan 22 00:00:00 1970 PST
+ 323 | 303 | 00323_update3 | Sat Jan 24 00:00:00 1970 PST
+ 324 | 4 | 00324 | Sun Jan 25 00:00:00 1970 PST
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST
+ 328 | 8 | 00328 | Thu Jan 29 00:00:00 1970 PST
+ 329 | 509 | 00329_update9 | Fri Jan 30 00:00:00 1970 PST
+ 330 | 0 | 00330 | Sat Jan 31 00:00:00 1970 PST
+ 331 | 1 | 00331 | Sun Feb 01 00:00:00 1970 PST
+ 333 | 303 | 00333_update3 | Tue Feb 03 00:00:00 1970 PST
+ 334 | 4 | 00334 | Wed Feb 04 00:00:00 1970 PST
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST
+ 338 | 8 | 00338 | Sun Feb 08 00:00:00 1970 PST
+ 339 | 509 | 00339_update9 | Mon Feb 09 00:00:00 1970 PST
+ 340 | 0 | 00340 | Tue Feb 10 00:00:00 1970 PST
+ 341 | 1 | 00341 | Wed Feb 11 00:00:00 1970 PST
+ 343 | 303 | 00343_update3 | Fri Feb 13 00:00:00 1970 PST
+ 344 | 4 | 00344 | Sat Feb 14 00:00:00 1970 PST
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST
+ 348 | 8 | 00348 | Wed Feb 18 00:00:00 1970 PST
+ 349 | 509 | 00349_update9 | Thu Feb 19 00:00:00 1970 PST
+ 350 | 0 | 00350 | Fri Feb 20 00:00:00 1970 PST
+ 351 | 1 | 00351 | Sat Feb 21 00:00:00 1970 PST
+ 353 | 303 | 00353_update3 | Mon Feb 23 00:00:00 1970 PST
+ 354 | 4 | 00354 | Tue Feb 24 00:00:00 1970 PST
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST
+ 358 | 8 | 00358 | Sat Feb 28 00:00:00 1970 PST
+ 359 | 509 | 00359_update9 | Sun Mar 01 00:00:00 1970 PST
+ 360 | 0 | 00360 | Mon Mar 02 00:00:00 1970 PST
+ 361 | 1 | 00361 | Tue Mar 03 00:00:00 1970 PST
+ 363 | 303 | 00363_update3 | Thu Mar 05 00:00:00 1970 PST
+ 364 | 4 | 00364 | Fri Mar 06 00:00:00 1970 PST
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST
+ 368 | 8 | 00368 | Tue Mar 10 00:00:00 1970 PST
+ 369 | 509 | 00369_update9 | Wed Mar 11 00:00:00 1970 PST
+ 370 | 0 | 00370 | Thu Mar 12 00:00:00 1970 PST
+ 371 | 1 | 00371 | Fri Mar 13 00:00:00 1970 PST
+ 373 | 303 | 00373_update3 | Sun Mar 15 00:00:00 1970 PST
+ 374 | 4 | 00374 | Mon Mar 16 00:00:00 1970 PST
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST
+ 378 | 8 | 00378 | Fri Mar 20 00:00:00 1970 PST
+ 379 | 509 | 00379_update9 | Sat Mar 21 00:00:00 1970 PST
+ 380 | 0 | 00380 | Sun Mar 22 00:00:00 1970 PST
+ 381 | 1 | 00381 | Mon Mar 23 00:00:00 1970 PST
+ 383 | 303 | 00383_update3 | Wed Mar 25 00:00:00 1970 PST
+ 384 | 4 | 00384 | Thu Mar 26 00:00:00 1970 PST
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST
+ 388 | 8 | 00388 | Mon Mar 30 00:00:00 1970 PST
+ 389 | 509 | 00389_update9 | Tue Mar 31 00:00:00 1970 PST
+ 390 | 0 | 00390 | Wed Apr 01 00:00:00 1970 PST
+ 391 | 1 | 00391 | Thu Apr 02 00:00:00 1970 PST
+ 393 | 303 | 00393_update3 | Sat Apr 04 00:00:00 1970 PST
+ 394 | 4 | 00394 | Sun Apr 05 00:00:00 1970 PST
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST
+ 398 | 8 | 00398 | Thu Apr 09 00:00:00 1970 PST
+ 399 | 509 | 00399_update9 | Fri Apr 10 00:00:00 1970 PST
+ 400 | 0 | 00400 | Thu Jan 01 00:00:00 1970 PST
+ 401 | 1 | 00401 | Fri Jan 02 00:00:00 1970 PST
+ 403 | 303 | 00403_update3 | Sun Jan 04 00:00:00 1970 PST
+ 404 | 4 | 00404 | Mon Jan 05 00:00:00 1970 PST
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST
+ 408 | 8 | 00408 | Fri Jan 09 00:00:00 1970 PST
+ 409 | 509 | 00409_update9 | Sat Jan 10 00:00:00 1970 PST
+ 410 | 0 | 00410 | Sun Jan 11 00:00:00 1970 PST
+ 411 | 1 | 00411 | Mon Jan 12 00:00:00 1970 PST
+ 413 | 303 | 00413_update3 | Wed Jan 14 00:00:00 1970 PST
+ 414 | 4 | 00414 | Thu Jan 15 00:00:00 1970 PST
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST
+ 418 | 8 | 00418 | Mon Jan 19 00:00:00 1970 PST
+ 419 | 509 | 00419_update9 | Tue Jan 20 00:00:00 1970 PST
+ 420 | 0 | 00420 | Wed Jan 21 00:00:00 1970 PST
+ 421 | 1 | 00421 | Thu Jan 22 00:00:00 1970 PST
+ 423 | 303 | 00423_update3 | Sat Jan 24 00:00:00 1970 PST
+ 424 | 4 | 00424 | Sun Jan 25 00:00:00 1970 PST
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST
+ 428 | 8 | 00428 | Thu Jan 29 00:00:00 1970 PST
+ 429 | 509 | 00429_update9 | Fri Jan 30 00:00:00 1970 PST
+ 430 | 0 | 00430 | Sat Jan 31 00:00:00 1970 PST
+ 431 | 1 | 00431 | Sun Feb 01 00:00:00 1970 PST
+ 433 | 303 | 00433_update3 | Tue Feb 03 00:00:00 1970 PST
+ 434 | 4 | 00434 | Wed Feb 04 00:00:00 1970 PST
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST
+ 438 | 8 | 00438 | Sun Feb 08 00:00:00 1970 PST
+ 439 | 509 | 00439_update9 | Mon Feb 09 00:00:00 1970 PST
+ 440 | 0 | 00440 | Tue Feb 10 00:00:00 1970 PST
+ 441 | 1 | 00441 | Wed Feb 11 00:00:00 1970 PST
+ 443 | 303 | 00443_update3 | Fri Feb 13 00:00:00 1970 PST
+ 444 | 4 | 00444 | Sat Feb 14 00:00:00 1970 PST
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST
+ 448 | 8 | 00448 | Wed Feb 18 00:00:00 1970 PST
+ 449 | 509 | 00449_update9 | Thu Feb 19 00:00:00 1970 PST
+ 450 | 0 | 00450 | Fri Feb 20 00:00:00 1970 PST
+ 451 | 1 | 00451 | Sat Feb 21 00:00:00 1970 PST
+ 453 | 303 | 00453_update3 | Mon Feb 23 00:00:00 1970 PST
+ 454 | 4 | 00454 | Tue Feb 24 00:00:00 1970 PST
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST
+ 458 | 8 | 00458 | Sat Feb 28 00:00:00 1970 PST
+ 459 | 509 | 00459_update9 | Sun Mar 01 00:00:00 1970 PST
+ 460 | 0 | 00460 | Mon Mar 02 00:00:00 1970 PST
+ 461 | 1 | 00461 | Tue Mar 03 00:00:00 1970 PST
+ 463 | 303 | 00463_update3 | Thu Mar 05 00:00:00 1970 PST
+ 464 | 4 | 00464 | Fri Mar 06 00:00:00 1970 PST
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST
+ 468 | 8 | 00468 | Tue Mar 10 00:00:00 1970 PST
+ 469 | 509 | 00469_update9 | Wed Mar 11 00:00:00 1970 PST
+ 470 | 0 | 00470 | Thu Mar 12 00:00:00 1970 PST
+ 471 | 1 | 00471 | Fri Mar 13 00:00:00 1970 PST
+ 473 | 303 | 00473_update3 | Sun Mar 15 00:00:00 1970 PST
+ 474 | 4 | 00474 | Mon Mar 16 00:00:00 1970 PST
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST
+ 478 | 8 | 00478 | Fri Mar 20 00:00:00 1970 PST
+ 479 | 509 | 00479_update9 | Sat Mar 21 00:00:00 1970 PST
+ 480 | 0 | 00480 | Sun Mar 22 00:00:00 1970 PST
+ 481 | 1 | 00481 | Mon Mar 23 00:00:00 1970 PST
+ 483 | 303 | 00483_update3 | Wed Mar 25 00:00:00 1970 PST
+ 484 | 4 | 00484 | Thu Mar 26 00:00:00 1970 PST
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST
+ 488 | 8 | 00488 | Mon Mar 30 00:00:00 1970 PST
+ 489 | 509 | 00489_update9 | Tue Mar 31 00:00:00 1970 PST
+ 490 | 0 | 00490 | Wed Apr 01 00:00:00 1970 PST
+ 491 | 1 | 00491 | Thu Apr 02 00:00:00 1970 PST
+ 493 | 303 | 00493_update3 | Sat Apr 04 00:00:00 1970 PST
+ 494 | 4 | 00494 | Sun Apr 05 00:00:00 1970 PST
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST
+ 498 | 8 | 00498 | Thu Apr 09 00:00:00 1970 PST
+ 499 | 509 | 00499_update9 | Fri Apr 10 00:00:00 1970 PST
+ 500 | 0 | 00500 | Thu Jan 01 00:00:00 1970 PST
+ 501 | 1 | 00501 | Fri Jan 02 00:00:00 1970 PST
+ 503 | 303 | 00503_update3 | Sun Jan 04 00:00:00 1970 PST
+ 504 | 4 | 00504 | Mon Jan 05 00:00:00 1970 PST
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST
+ 508 | 8 | 00508 | Fri Jan 09 00:00:00 1970 PST
+ 509 | 509 | 00509_update9 | Sat Jan 10 00:00:00 1970 PST
+ 510 | 0 | 00510 | Sun Jan 11 00:00:00 1970 PST
+ 511 | 1 | 00511 | Mon Jan 12 00:00:00 1970 PST
+ 513 | 303 | 00513_update3 | Wed Jan 14 00:00:00 1970 PST
+ 514 | 4 | 00514 | Thu Jan 15 00:00:00 1970 PST
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST
+ 518 | 8 | 00518 | Mon Jan 19 00:00:00 1970 PST
+ 519 | 509 | 00519_update9 | Tue Jan 20 00:00:00 1970 PST
+ 520 | 0 | 00520 | Wed Jan 21 00:00:00 1970 PST
+ 521 | 1 | 00521 | Thu Jan 22 00:00:00 1970 PST
+ 523 | 303 | 00523_update3 | Sat Jan 24 00:00:00 1970 PST
+ 524 | 4 | 00524 | Sun Jan 25 00:00:00 1970 PST
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST
+ 528 | 8 | 00528 | Thu Jan 29 00:00:00 1970 PST
+ 529 | 509 | 00529_update9 | Fri Jan 30 00:00:00 1970 PST
+ 530 | 0 | 00530 | Sat Jan 31 00:00:00 1970 PST
+ 531 | 1 | 00531 | Sun Feb 01 00:00:00 1970 PST
+ 533 | 303 | 00533_update3 | Tue Feb 03 00:00:00 1970 PST
+ 534 | 4 | 00534 | Wed Feb 04 00:00:00 1970 PST
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST
+ 538 | 8 | 00538 | Sun Feb 08 00:00:00 1970 PST
+ 539 | 509 | 00539_update9 | Mon Feb 09 00:00:00 1970 PST
+ 540 | 0 | 00540 | Tue Feb 10 00:00:00 1970 PST
+ 541 | 1 | 00541 | Wed Feb 11 00:00:00 1970 PST
+ 543 | 303 | 00543_update3 | Fri Feb 13 00:00:00 1970 PST
+ 544 | 4 | 00544 | Sat Feb 14 00:00:00 1970 PST
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST
+ 548 | 8 | 00548 | Wed Feb 18 00:00:00 1970 PST
+ 549 | 509 | 00549_update9 | Thu Feb 19 00:00:00 1970 PST
+ 550 | 0 | 00550 | Fri Feb 20 00:00:00 1970 PST
+ 551 | 1 | 00551 | Sat Feb 21 00:00:00 1970 PST
+ 553 | 303 | 00553_update3 | Mon Feb 23 00:00:00 1970 PST
+ 554 | 4 | 00554 | Tue Feb 24 00:00:00 1970 PST
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST
+ 558 | 8 | 00558 | Sat Feb 28 00:00:00 1970 PST
+ 559 | 509 | 00559_update9 | Sun Mar 01 00:00:00 1970 PST
+ 560 | 0 | 00560 | Mon Mar 02 00:00:00 1970 PST
+ 561 | 1 | 00561 | Tue Mar 03 00:00:00 1970 PST
+ 563 | 303 | 00563_update3 | Thu Mar 05 00:00:00 1970 PST
+ 564 | 4 | 00564 | Fri Mar 06 00:00:00 1970 PST
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST
+ 568 | 8 | 00568 | Tue Mar 10 00:00:00 1970 PST
+ 569 | 509 | 00569_update9 | Wed Mar 11 00:00:00 1970 PST
+ 570 | 0 | 00570 | Thu Mar 12 00:00:00 1970 PST
+ 571 | 1 | 00571 | Fri Mar 13 00:00:00 1970 PST
+ 573 | 303 | 00573_update3 | Sun Mar 15 00:00:00 1970 PST
+ 574 | 4 | 00574 | Mon Mar 16 00:00:00 1970 PST
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST
+ 578 | 8 | 00578 | Fri Mar 20 00:00:00 1970 PST
+ 579 | 509 | 00579_update9 | Sat Mar 21 00:00:00 1970 PST
+ 580 | 0 | 00580 | Sun Mar 22 00:00:00 1970 PST
+ 581 | 1 | 00581 | Mon Mar 23 00:00:00 1970 PST
+ 583 | 303 | 00583_update3 | Wed Mar 25 00:00:00 1970 PST
+ 584 | 4 | 00584 | Thu Mar 26 00:00:00 1970 PST
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST
+ 588 | 8 | 00588 | Mon Mar 30 00:00:00 1970 PST
+ 589 | 509 | 00589_update9 | Tue Mar 31 00:00:00 1970 PST
+ 590 | 0 | 00590 | Wed Apr 01 00:00:00 1970 PST
+ 591 | 1 | 00591 | Thu Apr 02 00:00:00 1970 PST
+ 593 | 303 | 00593_update3 | Sat Apr 04 00:00:00 1970 PST
+ 594 | 4 | 00594 | Sun Apr 05 00:00:00 1970 PST
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST
+ 598 | 8 | 00598 | Thu Apr 09 00:00:00 1970 PST
+ 599 | 509 | 00599_update9 | Fri Apr 10 00:00:00 1970 PST
+ 600 | 0 | 00600 | Thu Jan 01 00:00:00 1970 PST
+ 601 | 1 | 00601 | Fri Jan 02 00:00:00 1970 PST
+ 603 | 303 | 00603_update3 | Sun Jan 04 00:00:00 1970 PST
+ 604 | 4 | 00604 | Mon Jan 05 00:00:00 1970 PST
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST
+ 608 | 8 | 00608 | Fri Jan 09 00:00:00 1970 PST
+ 609 | 509 | 00609_update9 | Sat Jan 10 00:00:00 1970 PST
+ 610 | 0 | 00610 | Sun Jan 11 00:00:00 1970 PST
+ 611 | 1 | 00611 | Mon Jan 12 00:00:00 1970 PST
+ 613 | 303 | 00613_update3 | Wed Jan 14 00:00:00 1970 PST
+ 614 | 4 | 00614 | Thu Jan 15 00:00:00 1970 PST
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST
+ 618 | 8 | 00618 | Mon Jan 19 00:00:00 1970 PST
+ 619 | 509 | 00619_update9 | Tue Jan 20 00:00:00 1970 PST
+ 620 | 0 | 00620 | Wed Jan 21 00:00:00 1970 PST
+ 621 | 1 | 00621 | Thu Jan 22 00:00:00 1970 PST
+ 623 | 303 | 00623_update3 | Sat Jan 24 00:00:00 1970 PST
+ 624 | 4 | 00624 | Sun Jan 25 00:00:00 1970 PST
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST
+ 628 | 8 | 00628 | Thu Jan 29 00:00:00 1970 PST
+ 629 | 509 | 00629_update9 | Fri Jan 30 00:00:00 1970 PST
+ 630 | 0 | 00630 | Sat Jan 31 00:00:00 1970 PST
+ 631 | 1 | 00631 | Sun Feb 01 00:00:00 1970 PST
+ 633 | 303 | 00633_update3 | Tue Feb 03 00:00:00 1970 PST
+ 634 | 4 | 00634 | Wed Feb 04 00:00:00 1970 PST
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST
+ 638 | 8 | 00638 | Sun Feb 08 00:00:00 1970 PST
+ 639 | 509 | 00639_update9 | Mon Feb 09 00:00:00 1970 PST
+ 640 | 0 | 00640 | Tue Feb 10 00:00:00 1970 PST
+ 641 | 1 | 00641 | Wed Feb 11 00:00:00 1970 PST
+ 643 | 303 | 00643_update3 | Fri Feb 13 00:00:00 1970 PST
+ 644 | 4 | 00644 | Sat Feb 14 00:00:00 1970 PST
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST
+ 648 | 8 | 00648 | Wed Feb 18 00:00:00 1970 PST
+ 649 | 509 | 00649_update9 | Thu Feb 19 00:00:00 1970 PST
+ 650 | 0 | 00650 | Fri Feb 20 00:00:00 1970 PST
+ 651 | 1 | 00651 | Sat Feb 21 00:00:00 1970 PST
+ 653 | 303 | 00653_update3 | Mon Feb 23 00:00:00 1970 PST
+ 654 | 4 | 00654 | Tue Feb 24 00:00:00 1970 PST
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST
+ 658 | 8 | 00658 | Sat Feb 28 00:00:00 1970 PST
+ 659 | 509 | 00659_update9 | Sun Mar 01 00:00:00 1970 PST
+ 660 | 0 | 00660 | Mon Mar 02 00:00:00 1970 PST
+ 661 | 1 | 00661 | Tue Mar 03 00:00:00 1970 PST
+ 663 | 303 | 00663_update3 | Thu Mar 05 00:00:00 1970 PST
+ 664 | 4 | 00664 | Fri Mar 06 00:00:00 1970 PST
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST
+ 668 | 8 | 00668 | Tue Mar 10 00:00:00 1970 PST
+ 669 | 509 | 00669_update9 | Wed Mar 11 00:00:00 1970 PST
+ 670 | 0 | 00670 | Thu Mar 12 00:00:00 1970 PST
+ 671 | 1 | 00671 | Fri Mar 13 00:00:00 1970 PST
+ 673 | 303 | 00673_update3 | Sun Mar 15 00:00:00 1970 PST
+ 674 | 4 | 00674 | Mon Mar 16 00:00:00 1970 PST
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST
+ 678 | 8 | 00678 | Fri Mar 20 00:00:00 1970 PST
+ 679 | 509 | 00679_update9 | Sat Mar 21 00:00:00 1970 PST
+ 680 | 0 | 00680 | Sun Mar 22 00:00:00 1970 PST
+ 681 | 1 | 00681 | Mon Mar 23 00:00:00 1970 PST
+ 683 | 303 | 00683_update3 | Wed Mar 25 00:00:00 1970 PST
+ 684 | 4 | 00684 | Thu Mar 26 00:00:00 1970 PST
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST
+ 688 | 8 | 00688 | Mon Mar 30 00:00:00 1970 PST
+ 689 | 509 | 00689_update9 | Tue Mar 31 00:00:00 1970 PST
+ 690 | 0 | 00690 | Wed Apr 01 00:00:00 1970 PST
+ 691 | 1 | 00691 | Thu Apr 02 00:00:00 1970 PST
+ 693 | 303 | 00693_update3 | Sat Apr 04 00:00:00 1970 PST
+ 694 | 4 | 00694 | Sun Apr 05 00:00:00 1970 PST
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST
+ 698 | 8 | 00698 | Thu Apr 09 00:00:00 1970 PST
+ 699 | 509 | 00699_update9 | Fri Apr 10 00:00:00 1970 PST
+ 700 | 0 | 00700 | Thu Jan 01 00:00:00 1970 PST
+ 701 | 1 | 00701 | Fri Jan 02 00:00:00 1970 PST
+ 703 | 303 | 00703_update3 | Sun Jan 04 00:00:00 1970 PST
+ 704 | 4 | 00704 | Mon Jan 05 00:00:00 1970 PST
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST
+ 708 | 8 | 00708 | Fri Jan 09 00:00:00 1970 PST
+ 709 | 509 | 00709_update9 | Sat Jan 10 00:00:00 1970 PST
+ 710 | 0 | 00710 | Sun Jan 11 00:00:00 1970 PST
+ 711 | 1 | 00711 | Mon Jan 12 00:00:00 1970 PST
+ 713 | 303 | 00713_update3 | Wed Jan 14 00:00:00 1970 PST
+ 714 | 4 | 00714 | Thu Jan 15 00:00:00 1970 PST
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST
+ 718 | 8 | 00718 | Mon Jan 19 00:00:00 1970 PST
+ 719 | 509 | 00719_update9 | Tue Jan 20 00:00:00 1970 PST
+ 720 | 0 | 00720 | Wed Jan 21 00:00:00 1970 PST
+ 721 | 1 | 00721 | Thu Jan 22 00:00:00 1970 PST
+ 723 | 303 | 00723_update3 | Sat Jan 24 00:00:00 1970 PST
+ 724 | 4 | 00724 | Sun Jan 25 00:00:00 1970 PST
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST
+ 728 | 8 | 00728 | Thu Jan 29 00:00:00 1970 PST
+ 729 | 509 | 00729_update9 | Fri Jan 30 00:00:00 1970 PST
+ 730 | 0 | 00730 | Sat Jan 31 00:00:00 1970 PST
+ 731 | 1 | 00731 | Sun Feb 01 00:00:00 1970 PST
+ 733 | 303 | 00733_update3 | Tue Feb 03 00:00:00 1970 PST
+ 734 | 4 | 00734 | Wed Feb 04 00:00:00 1970 PST
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST
+ 738 | 8 | 00738 | Sun Feb 08 00:00:00 1970 PST
+ 739 | 509 | 00739_update9 | Mon Feb 09 00:00:00 1970 PST
+ 740 | 0 | 00740 | Tue Feb 10 00:00:00 1970 PST
+ 741 | 1 | 00741 | Wed Feb 11 00:00:00 1970 PST
+ 743 | 303 | 00743_update3 | Fri Feb 13 00:00:00 1970 PST
+ 744 | 4 | 00744 | Sat Feb 14 00:00:00 1970 PST
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST
+ 748 | 8 | 00748 | Wed Feb 18 00:00:00 1970 PST
+ 749 | 509 | 00749_update9 | Thu Feb 19 00:00:00 1970 PST
+ 750 | 0 | 00750 | Fri Feb 20 00:00:00 1970 PST
+ 751 | 1 | 00751 | Sat Feb 21 00:00:00 1970 PST
+ 753 | 303 | 00753_update3 | Mon Feb 23 00:00:00 1970 PST
+ 754 | 4 | 00754 | Tue Feb 24 00:00:00 1970 PST
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST
+ 758 | 8 | 00758 | Sat Feb 28 00:00:00 1970 PST
+ 759 | 509 | 00759_update9 | Sun Mar 01 00:00:00 1970 PST
+ 760 | 0 | 00760 | Mon Mar 02 00:00:00 1970 PST
+ 761 | 1 | 00761 | Tue Mar 03 00:00:00 1970 PST
+ 763 | 303 | 00763_update3 | Thu Mar 05 00:00:00 1970 PST
+ 764 | 4 | 00764 | Fri Mar 06 00:00:00 1970 PST
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST
+ 768 | 8 | 00768 | Tue Mar 10 00:00:00 1970 PST
+ 769 | 509 | 00769_update9 | Wed Mar 11 00:00:00 1970 PST
+ 770 | 0 | 00770 | Thu Mar 12 00:00:00 1970 PST
+ 771 | 1 | 00771 | Fri Mar 13 00:00:00 1970 PST
+ 773 | 303 | 00773_update3 | Sun Mar 15 00:00:00 1970 PST
+ 774 | 4 | 00774 | Mon Mar 16 00:00:00 1970 PST
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST
+ 778 | 8 | 00778 | Fri Mar 20 00:00:00 1970 PST
+ 779 | 509 | 00779_update9 | Sat Mar 21 00:00:00 1970 PST
+ 780 | 0 | 00780 | Sun Mar 22 00:00:00 1970 PST
+ 781 | 1 | 00781 | Mon Mar 23 00:00:00 1970 PST
+ 783 | 303 | 00783_update3 | Wed Mar 25 00:00:00 1970 PST
+ 784 | 4 | 00784 | Thu Mar 26 00:00:00 1970 PST
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST
+ 788 | 8 | 00788 | Mon Mar 30 00:00:00 1970 PST
+ 789 | 509 | 00789_update9 | Tue Mar 31 00:00:00 1970 PST
+ 790 | 0 | 00790 | Wed Apr 01 00:00:00 1970 PST
+ 791 | 1 | 00791 | Thu Apr 02 00:00:00 1970 PST
+ 793 | 303 | 00793_update3 | Sat Apr 04 00:00:00 1970 PST
+ 794 | 4 | 00794 | Sun Apr 05 00:00:00 1970 PST
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST
+ 798 | 8 | 00798 | Thu Apr 09 00:00:00 1970 PST
+ 799 | 509 | 00799_update9 | Fri Apr 10 00:00:00 1970 PST
+ 800 | 0 | 00800 | Thu Jan 01 00:00:00 1970 PST
+ 801 | 1 | 00801 | Fri Jan 02 00:00:00 1970 PST
+ 803 | 303 | 00803_update3 | Sun Jan 04 00:00:00 1970 PST
+ 804 | 4 | 00804 | Mon Jan 05 00:00:00 1970 PST
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST
+ 808 | 8 | 00808 | Fri Jan 09 00:00:00 1970 PST
+ 809 | 509 | 00809_update9 | Sat Jan 10 00:00:00 1970 PST
+ 810 | 0 | 00810 | Sun Jan 11 00:00:00 1970 PST
+ 811 | 1 | 00811 | Mon Jan 12 00:00:00 1970 PST
+ 813 | 303 | 00813_update3 | Wed Jan 14 00:00:00 1970 PST
+ 814 | 4 | 00814 | Thu Jan 15 00:00:00 1970 PST
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST
+ 818 | 8 | 00818 | Mon Jan 19 00:00:00 1970 PST
+ 819 | 509 | 00819_update9 | Tue Jan 20 00:00:00 1970 PST
+ 820 | 0 | 00820 | Wed Jan 21 00:00:00 1970 PST
+ 821 | 1 | 00821 | Thu Jan 22 00:00:00 1970 PST
+ 823 | 303 | 00823_update3 | Sat Jan 24 00:00:00 1970 PST
+ 824 | 4 | 00824 | Sun Jan 25 00:00:00 1970 PST
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST
+ 828 | 8 | 00828 | Thu Jan 29 00:00:00 1970 PST
+ 829 | 509 | 00829_update9 | Fri Jan 30 00:00:00 1970 PST
+ 830 | 0 | 00830 | Sat Jan 31 00:00:00 1970 PST
+ 831 | 1 | 00831 | Sun Feb 01 00:00:00 1970 PST
+ 833 | 303 | 00833_update3 | Tue Feb 03 00:00:00 1970 PST
+ 834 | 4 | 00834 | Wed Feb 04 00:00:00 1970 PST
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST
+ 838 | 8 | 00838 | Sun Feb 08 00:00:00 1970 PST
+ 839 | 509 | 00839_update9 | Mon Feb 09 00:00:00 1970 PST
+ 840 | 0 | 00840 | Tue Feb 10 00:00:00 1970 PST
+ 841 | 1 | 00841 | Wed Feb 11 00:00:00 1970 PST
+ 843 | 303 | 00843_update3 | Fri Feb 13 00:00:00 1970 PST
+ 844 | 4 | 00844 | Sat Feb 14 00:00:00 1970 PST
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST
+ 848 | 8 | 00848 | Wed Feb 18 00:00:00 1970 PST
+ 849 | 509 | 00849_update9 | Thu Feb 19 00:00:00 1970 PST
+ 850 | 0 | 00850 | Fri Feb 20 00:00:00 1970 PST
+ 851 | 1 | 00851 | Sat Feb 21 00:00:00 1970 PST
+ 853 | 303 | 00853_update3 | Mon Feb 23 00:00:00 1970 PST
+ 854 | 4 | 00854 | Tue Feb 24 00:00:00 1970 PST
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST
+ 858 | 8 | 00858 | Sat Feb 28 00:00:00 1970 PST
+ 859 | 509 | 00859_update9 | Sun Mar 01 00:00:00 1970 PST
+ 860 | 0 | 00860 | Mon Mar 02 00:00:00 1970 PST
+ 861 | 1 | 00861 | Tue Mar 03 00:00:00 1970 PST
+ 863 | 303 | 00863_update3 | Thu Mar 05 00:00:00 1970 PST
+ 864 | 4 | 00864 | Fri Mar 06 00:00:00 1970 PST
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST
+ 868 | 8 | 00868 | Tue Mar 10 00:00:00 1970 PST
+ 869 | 509 | 00869_update9 | Wed Mar 11 00:00:00 1970 PST
+ 870 | 0 | 00870 | Thu Mar 12 00:00:00 1970 PST
+ 871 | 1 | 00871 | Fri Mar 13 00:00:00 1970 PST
+ 873 | 303 | 00873_update3 | Sun Mar 15 00:00:00 1970 PST
+ 874 | 4 | 00874 | Mon Mar 16 00:00:00 1970 PST
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST
+ 878 | 8 | 00878 | Fri Mar 20 00:00:00 1970 PST
+ 879 | 509 | 00879_update9 | Sat Mar 21 00:00:00 1970 PST
+ 880 | 0 | 00880 | Sun Mar 22 00:00:00 1970 PST
+ 881 | 1 | 00881 | Mon Mar 23 00:00:00 1970 PST
+ 883 | 303 | 00883_update3 | Wed Mar 25 00:00:00 1970 PST
+ 884 | 4 | 00884 | Thu Mar 26 00:00:00 1970 PST
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST
+ 888 | 8 | 00888 | Mon Mar 30 00:00:00 1970 PST
+ 889 | 509 | 00889_update9 | Tue Mar 31 00:00:00 1970 PST
+ 890 | 0 | 00890 | Wed Apr 01 00:00:00 1970 PST
+ 891 | 1 | 00891 | Thu Apr 02 00:00:00 1970 PST
+ 893 | 303 | 00893_update3 | Sat Apr 04 00:00:00 1970 PST
+ 894 | 4 | 00894 | Sun Apr 05 00:00:00 1970 PST
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST
+ 898 | 8 | 00898 | Thu Apr 09 00:00:00 1970 PST
+ 899 | 509 | 00899_update9 | Fri Apr 10 00:00:00 1970 PST
+ 900 | 0 | 00900 | Thu Jan 01 00:00:00 1970 PST
+ 901 | 1 | 00901 | Fri Jan 02 00:00:00 1970 PST
+ 903 | 303 | 00903_update3 | Sun Jan 04 00:00:00 1970 PST
+ 904 | 4 | 00904 | Mon Jan 05 00:00:00 1970 PST
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST
+ 908 | 8 | 00908 | Fri Jan 09 00:00:00 1970 PST
+ 909 | 509 | 00909_update9 | Sat Jan 10 00:00:00 1970 PST
+ 910 | 0 | 00910 | Sun Jan 11 00:00:00 1970 PST
+ 911 | 1 | 00911 | Mon Jan 12 00:00:00 1970 PST
+ 913 | 303 | 00913_update3 | Wed Jan 14 00:00:00 1970 PST
+ 914 | 4 | 00914 | Thu Jan 15 00:00:00 1970 PST
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST
+ 918 | 8 | 00918 | Mon Jan 19 00:00:00 1970 PST
+ 919 | 509 | 00919_update9 | Tue Jan 20 00:00:00 1970 PST
+ 920 | 0 | 00920 | Wed Jan 21 00:00:00 1970 PST
+ 921 | 1 | 00921 | Thu Jan 22 00:00:00 1970 PST
+ 923 | 303 | 00923_update3 | Sat Jan 24 00:00:00 1970 PST
+ 924 | 4 | 00924 | Sun Jan 25 00:00:00 1970 PST
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST
+ 928 | 8 | 00928 | Thu Jan 29 00:00:00 1970 PST
+ 929 | 509 | 00929_update9 | Fri Jan 30 00:00:00 1970 PST
+ 930 | 0 | 00930 | Sat Jan 31 00:00:00 1970 PST
+ 931 | 1 | 00931 | Sun Feb 01 00:00:00 1970 PST
+ 933 | 303 | 00933_update3 | Tue Feb 03 00:00:00 1970 PST
+ 934 | 4 | 00934 | Wed Feb 04 00:00:00 1970 PST
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST
+ 938 | 8 | 00938 | Sun Feb 08 00:00:00 1970 PST
+ 939 | 509 | 00939_update9 | Mon Feb 09 00:00:00 1970 PST
+ 940 | 0 | 00940 | Tue Feb 10 00:00:00 1970 PST
+ 941 | 1 | 00941 | Wed Feb 11 00:00:00 1970 PST
+ 943 | 303 | 00943_update3 | Fri Feb 13 00:00:00 1970 PST
+ 944 | 4 | 00944 | Sat Feb 14 00:00:00 1970 PST
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST
+ 948 | 8 | 00948 | Wed Feb 18 00:00:00 1970 PST
+ 949 | 509 | 00949_update9 | Thu Feb 19 00:00:00 1970 PST
+ 950 | 0 | 00950 | Fri Feb 20 00:00:00 1970 PST
+ 951 | 1 | 00951 | Sat Feb 21 00:00:00 1970 PST
+ 953 | 303 | 00953_update3 | Mon Feb 23 00:00:00 1970 PST
+ 954 | 4 | 00954 | Tue Feb 24 00:00:00 1970 PST
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST
+ 958 | 8 | 00958 | Sat Feb 28 00:00:00 1970 PST
+ 959 | 509 | 00959_update9 | Sun Mar 01 00:00:00 1970 PST
+ 960 | 0 | 00960 | Mon Mar 02 00:00:00 1970 PST
+ 961 | 1 | 00961 | Tue Mar 03 00:00:00 1970 PST
+ 963 | 303 | 00963_update3 | Thu Mar 05 00:00:00 1970 PST
+ 964 | 4 | 00964 | Fri Mar 06 00:00:00 1970 PST
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST
+ 968 | 8 | 00968 | Tue Mar 10 00:00:00 1970 PST
+ 969 | 509 | 00969_update9 | Wed Mar 11 00:00:00 1970 PST
+ 970 | 0 | 00970 | Thu Mar 12 00:00:00 1970 PST
+ 971 | 1 | 00971 | Fri Mar 13 00:00:00 1970 PST
+ 973 | 303 | 00973_update3 | Sun Mar 15 00:00:00 1970 PST
+ 974 | 4 | 00974 | Mon Mar 16 00:00:00 1970 PST
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST
+ 978 | 8 | 00978 | Fri Mar 20 00:00:00 1970 PST
+ 979 | 509 | 00979_update9 | Sat Mar 21 00:00:00 1970 PST
+ 980 | 0 | 00980 | Sun Mar 22 00:00:00 1970 PST
+ 981 | 1 | 00981 | Mon Mar 23 00:00:00 1970 PST
+ 983 | 303 | 00983_update3 | Wed Mar 25 00:00:00 1970 PST
+ 984 | 4 | 00984 | Thu Mar 26 00:00:00 1970 PST
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST
+ 988 | 8 | 00988 | Mon Mar 30 00:00:00 1970 PST
+ 989 | 509 | 00989_update9 | Tue Mar 31 00:00:00 1970 PST
+ 990 | 0 | 00990 | Wed Apr 01 00:00:00 1970 PST
+ 991 | 1 | 00991 | Thu Apr 02 00:00:00 1970 PST
+ 993 | 303 | 00993_update3 | Sat Apr 04 00:00:00 1970 PST
+ 994 | 4 | 00994 | Sun Apr 05 00:00:00 1970 PST
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST
+ 998 | 8 | 00998 | Thu Apr 09 00:00:00 1970 PST
+ 999 | 509 | 00999_update9 | Fri Apr 10 00:00:00 1970 PST
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST
+ 1001 | 101 | 0000100001 |
+ 1003 | 403 | 0000300003_update3 |
+ 1004 | 104 | 0000400004 |
+ 1006 | 106 | 0000600006 |
+ 1007 | 507 | 0000700007_update7 |
+ 1008 | 108 | 0000800008 |
+ 1009 | 609 | 0000900009_update9 |
+ 1010 | 100 | 0001000010 |
+ 1011 | 101 | 0001100011 |
+ 1013 | 403 | 0001300013_update3 |
+ 1014 | 104 | 0001400014 |
+ 1016 | 106 | 0001600016 |
+ 1017 | 507 | 0001700017_update7 |
+ 1018 | 108 | 0001800018 |
+ 1019 | 609 | 0001900019_update9 |
+ 1020 | 100 | 0002000020 |
+ 1101 | 201 | aaa |
+ 1103 | 503 | ccc_update3 |
+ 1104 | 204 | ddd |
+(819 rows)
+
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Output: (ft2.tableoid)::regclass
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: 1200, 999, NULL::integer, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+(6 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = 'bar'::text WHERE (("C 1" = 1200))
+(4 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------
+ Delete on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE (("C 1" = 1200))
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+-- Test UPDATE/DELETE with RETURNING on a three-table join
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id - 1200, to_char(id, 'FM00000') FROM generate_series(1201, 1300) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.*, ft4.c1, ft4.c2, ft4.c3
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c3 = 'foo'::text FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (TRUE)) WHERE ((r2.c1 = r3.c1)) AND ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) RETURNING r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3
+(4 rows)
+
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*;
+ ft2 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | ft4 | c1 | c2 | c3
+--------------------------------+------+----+-----+----+----+----+------------+----+----------------+----+----+--------
+ (1206,6,foo,,,,"ft2 ",) | 1206 | 6 | foo | | | | ft2 | | (6,7,AAA006) | 6 | 7 | AAA006
+ (1212,12,foo,,,,"ft2 ",) | 1212 | 12 | foo | | | | ft2 | | (12,13,AAA012) | 12 | 13 | AAA012
+ (1218,18,foo,,,,"ft2 ",) | 1218 | 18 | foo | | | | ft2 | | (18,19,AAA018) | 18 | 19 | AAA018
+ (1224,24,foo,,,,"ft2 ",) | 1224 | 24 | foo | | | | ft2 | | (24,25,AAA024) | 24 | 25 | AAA024
+ (1230,30,foo,,,,"ft2 ",) | 1230 | 30 | foo | | | | ft2 | | (30,31,AAA030) | 30 | 31 | AAA030
+ (1236,36,foo,,,,"ft2 ",) | 1236 | 36 | foo | | | | ft2 | | (36,37,AAA036) | 36 | 37 | AAA036
+ (1242,42,foo,,,,"ft2 ",) | 1242 | 42 | foo | | | | ft2 | | (42,43,AAA042) | 42 | 43 | AAA042
+ (1248,48,foo,,,,"ft2 ",) | 1248 | 48 | foo | | | | ft2 | | (48,49,AAA048) | 48 | 49 | AAA048
+ (1254,54,foo,,,,"ft2 ",) | 1254 | 54 | foo | | | | ft2 | | (54,55,AAA054) | 54 | 55 | AAA054
+ (1260,60,foo,,,,"ft2 ",) | 1260 | 60 | foo | | | | ft2 | | (60,61,AAA060) | 60 | 61 | AAA060
+ (1266,66,foo,,,,"ft2 ",) | 1266 | 66 | foo | | | | ft2 | | (66,67,AAA066) | 66 | 67 | AAA066
+ (1272,72,foo,,,,"ft2 ",) | 1272 | 72 | foo | | | | ft2 | | (72,73,AAA072) | 72 | 73 | AAA072
+ (1278,78,foo,,,,"ft2 ",) | 1278 | 78 | foo | | | | ft2 | | (78,79,AAA078) | 78 | 79 | AAA078
+ (1284,84,foo,,,,"ft2 ",) | 1284 | 84 | foo | | | | ft2 | | (84,85,AAA084) | 84 | 85 | AAA084
+ (1290,90,foo,,,,"ft2 ",) | 1290 | 90 | foo | | | | ft2 | | (90,91,AAA090) | 90 | 91 | AAA090
+ (1296,96,foo,,,,"ft2 ",) | 1296 | 96 | foo | | | | ft2 | | (96,97,AAA096) | 96 | 97 | AAA096
+(16 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: 100
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1)))) WHERE ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) AND (((r1."C 1" % 10) = 0))
+(4 rows)
+
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100;
+ ?column?
+----------
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+(10 rows)
+
+DELETE FROM ft2 WHERE ft2.c1 > 1200;
+-- Test UPDATE with a MULTIEXPR sub-select
+-- (maybe someday this'll be remotely executable, but not today)
+EXPLAIN (verbose, costs off)
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 target
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2, c7 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.ft2 target
+ Output: $1, $2, (SubPlan 1 (returns $1,$2)), target.ctid, target.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1100)) FOR UPDATE
+ SubPlan 1 (returns $1,$2)
+ -> Foreign Scan on public.ft2 src
+ Output: (src.c2 * 10), src.c7
+ Remote SQL: SELECT c2, c7 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(9 rows)
+
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+UPDATE ft2 AS target SET (c2) = (
+ SELECT c2 / 10
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+-- Test UPDATE involving a join that can be pushed down,
+-- but a SET clause that can't be
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 d
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2 WHERE ctid = $1
+ -> Foreign Scan
+ Output: CASE WHEN (random() >= '0'::double precision) THEN d.c2 ELSE 0 END, d.ctid, d.*, t.*
+ Relations: (public.ft2 d) INNER JOIN (public.ft2 t)
+ Remote SQL: SELECT r1.c2, r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r1."C 1" > 1000)))) FOR UPDATE OF r1
+ -> Hash Join
+ Output: d.c2, d.ctid, d.*, t.*
+ Hash Cond: (d.c1 = t.c1)
+ -> Foreign Scan on public.ft2 d
+ Output: d.c2, d.ctid, d.*, d.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1000)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Hash
+ Output: t.*, t.c1
+ -> Foreign Scan on public.ft2 t
+ Output: t.*, t.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(17 rows)
+
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+-- Test UPDATE/DELETE with WHERE or JOIN/ON conditions containing
+-- user-defined operators/functions
+ALTER SERVER loopback OPTIONS (DROP extensions);
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id % 10, to_char(id, 'FM00000') FROM generate_series(2001, 2010) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft2
+ Output: 'bar'::text, ctid, ft2.*
+ Filter: (postgres_fdw_abs(ft2.c1) > 2000)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" FOR UPDATE
+(7 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-----+----+----+----+------------+----
+ 2001 | 1 | bar | | | | ft2 |
+ 2002 | 2 | bar | | | | ft2 |
+ 2003 | 3 | bar | | | | ft2 |
+ 2004 | 4 | bar | | | | ft2 |
+ 2005 | 5 | bar | | | | ft2 |
+ 2006 | 6 | bar | | | | ft2 |
+ 2007 | 7 | bar | | | | ft2 |
+ 2008 | 8 | bar | | | | ft2 |
+ 2009 | 9 | bar | | | | ft2 |
+ 2010 | 0 | bar | | | | ft2 |
+(10 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Nested Loop
+ Output: 'baz'::text, ft2.ctid, ft2.*, ft4.*, ft5.*, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Join Filter: (ft2.c2 === ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.*, ft2.c2
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Relations: (public.ft4) INNER JOIN (public.ft5)
+ Remote SQL: SELECT CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r3.c1, r3.c2, r3.c3 FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1))))
+ -> Hash Join
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(24 rows)
+
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3
+------+----+-----+----+----+----+------------+----+----+----+--------+----+----+--------
+ 2006 | 6 | baz | | | | ft2 | | 6 | 7 | AAA006 | 6 | 7 | AAA006
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ctid = $1 RETURNING "C 1", c2, c3
+ -> Foreign Scan
+ Output: ft2.ctid, ft4.*, ft5.*
+ Filter: (ft4.c1 === ft5.c1)
+ Relations: ((public.ft2) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r2.c1, r3.c1 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c2 = r2.c1)) AND ((r1."C 1" > 2000)))) INNER JOIN "S 1"."T 4" r3 ON (TRUE)) FOR UPDATE OF r1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft5.*, ft4.c1, ft5.c1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft4.c1
+ Join Filter: (ft2.c2 = ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.c2
+ Remote SQL: SELECT c2, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(22 rows)
+
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3;
+ c1 | c2 | c3
+------+----+-----
+ 2006 | 6 | baz
+(1 row)
+
+DELETE FROM ft2 WHERE ft2.c1 > 2000;
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- Test that trigger on remote table works as expected
+CREATE OR REPLACE FUNCTION "S 1".F_BRTRIG() RETURNS trigger AS $$
+BEGIN
+ NEW.c3 = NEW.c3 || '_trig_update';
+ RETURN NEW;
+END;
+$$ LANGUAGE plpgsql;
+CREATE TRIGGER t1_br_insert BEFORE INSERT OR UPDATE
+ ON "S 1"."T 1" FOR EACH ROW EXECUTE PROCEDURE "S 1".F_BRTRIG();
+INSERT INTO ft2 (c1,c2,c3) VALUES (1208, 818, 'fff') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+----+------------+----
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+(1 row)
+
+INSERT INTO ft2 (c1,c2,c3,c6) VALUES (1218, 818, 'ggg', '(--;') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+------+------------+----
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+(1 row)
+
+UPDATE ft2 SET c2 = c2 + 600 WHERE c1 % 10 = 8 AND c1 < 1200 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+------------------------+------------------------------+--------------------------+----+------------+-----
+ 8 | 608 | 00008_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 18 | 608 | 00018_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 28 | 608 | 00028_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 38 | 608 | 00038_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 48 | 608 | 00048_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 58 | 608 | 00058_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 68 | 608 | 00068_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 78 | 608 | 00078_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 88 | 608 | 00088_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 98 | 608 | 00098_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 108 | 608 | 00108_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 118 | 608 | 00118_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 128 | 608 | 00128_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 138 | 608 | 00138_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 148 | 608 | 00148_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 158 | 608 | 00158_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 168 | 608 | 00168_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 178 | 608 | 00178_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 188 | 608 | 00188_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 198 | 608 | 00198_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 208 | 608 | 00208_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 218 | 608 | 00218_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 228 | 608 | 00228_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 238 | 608 | 00238_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 248 | 608 | 00248_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 258 | 608 | 00258_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 268 | 608 | 00268_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 278 | 608 | 00278_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 288 | 608 | 00288_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 298 | 608 | 00298_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 308 | 608 | 00308_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 318 | 608 | 00318_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 328 | 608 | 00328_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 338 | 608 | 00338_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 348 | 608 | 00348_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 358 | 608 | 00358_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 368 | 608 | 00368_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 378 | 608 | 00378_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 388 | 608 | 00388_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 398 | 608 | 00398_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 408 | 608 | 00408_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 418 | 608 | 00418_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 428 | 608 | 00428_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 438 | 608 | 00438_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 448 | 608 | 00448_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 458 | 608 | 00458_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 468 | 608 | 00468_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 478 | 608 | 00478_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 488 | 608 | 00488_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 498 | 608 | 00498_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 508 | 608 | 00508_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 518 | 608 | 00518_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 528 | 608 | 00528_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 538 | 608 | 00538_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 548 | 608 | 00548_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 558 | 608 | 00558_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 568 | 608 | 00568_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 578 | 608 | 00578_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 588 | 608 | 00588_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 598 | 608 | 00598_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 608 | 608 | 00608_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 618 | 608 | 00618_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 628 | 608 | 00628_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 638 | 608 | 00638_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 648 | 608 | 00648_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 658 | 608 | 00658_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 668 | 608 | 00668_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 678 | 608 | 00678_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 688 | 608 | 00688_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 698 | 608 | 00698_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 708 | 608 | 00708_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 718 | 608 | 00718_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 728 | 608 | 00728_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 738 | 608 | 00738_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 748 | 608 | 00748_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 758 | 608 | 00758_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 768 | 608 | 00768_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 778 | 608 | 00778_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 788 | 608 | 00788_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 798 | 608 | 00798_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 808 | 608 | 00808_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 818 | 608 | 00818_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 828 | 608 | 00828_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 838 | 608 | 00838_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 848 | 608 | 00848_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 858 | 608 | 00858_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 868 | 608 | 00868_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 878 | 608 | 00878_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 888 | 608 | 00888_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 898 | 608 | 00898_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 908 | 608 | 00908_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 918 | 608 | 00918_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 928 | 608 | 00928_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 938 | 608 | 00938_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 948 | 608 | 00948_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 958 | 608 | 00958_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 968 | 608 | 00968_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 978 | 608 | 00978_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 988 | 608 | 00988_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 998 | 608 | 00998_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 1008 | 708 | 0000800008_trig_update | | | | ft2 |
+ 1018 | 708 | 0001800018_trig_update | | | | ft2 |
+(102 rows)
+
+-- Test errors thrown on remote side during update
+ALTER TABLE "S 1"."T 1" ADD CONSTRAINT c2positive CHECK (c2 >= 0);
+INSERT INTO ft1(c1, c2) VALUES(11, 12); -- duplicate key
+ERROR: duplicate key value violates unique constraint "t1_pkey"
+DETAIL: Key ("C 1")=(11) already exists.
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT DO NOTHING; -- works
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO NOTHING; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO UPDATE SET c3 = 'ffg'; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+-- Test savepoint/rollback behavior
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+begin;
+update ft2 set c2 = 42 where c2 = 0;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 42 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s1;
+update ft2 set c2 = 44 where c2 = 4;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s1;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s2;
+update ft2 set c2 = 46 where c2 = 6;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 42 | 100
+ 44 | 100
+ 46 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+rollback to savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s3;
+update ft2 set c2 = -2 where c2 = 42 and c1 = 10; -- fail on remote side
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (10, -2, 00010_trig_update_trig_update, 1970-01-11 08:00:00+00, 1970-01-11 00:00:00, 0, 0 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (-2) WHERE ((c2 = 42)) AND (("C 1" = 10))
+rollback to savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+-- none of the above is committed yet remotely
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+commit;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+VACUUM ANALYZE "S 1"."T 1";
+-- Above DMLs add data with c6 as NULL in ft1, so test ORDER BY NULLS LAST and NULLs
+-- FIRST behavior here.
+-- ORDER BY DESC NULLS LAST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 795::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+------+------------+-----
+ 960 | 42 | 00960_trig_update | Mon Mar 02 00:00:00 1970 PST | Mon Mar 02 00:00:00 1970 | 0 | 0 | foo
+ 970 | 42 | 00970_trig_update | Thu Mar 12 00:00:00 1970 PST | Thu Mar 12 00:00:00 1970 | 0 | 0 | foo
+ 980 | 42 | 00980_trig_update | Sun Mar 22 00:00:00 1970 PST | Sun Mar 22 00:00:00 1970 | 0 | 0 | foo
+ 990 | 42 | 00990_trig_update | Wed Apr 01 00:00:00 1970 PST | Wed Apr 01 00:00:00 1970 | 0 | 0 | foo
+ 1000 | 42 | 01000_trig_update | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 1001 | 101 | 0000100001 | | | | ft2 |
+ 1003 | 403 | 0000300003_update3 | | | | ft2 |
+ 1004 | 104 | 0000400004 | | | | ft2 |
+ 1006 | 106 | 0000600006 | | | | ft2 |
+(10 rows)
+
+-- ORDER BY DESC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+------------------------------+--------------------------+----+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | ft2 | foo
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST | Tue Jan 20 00:00:00 1970 | 9 | ft2 | foo
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST | Fri Jan 30 00:00:00 1970 | 9 | ft2 | foo
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST | Mon Feb 09 00:00:00 1970 | 9 | ft2 | foo
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST | Thu Feb 19 00:00:00 1970 | 9 | ft2 | foo
+(10 rows)
+
+-- ORDER BY ASC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 ASC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-------------------+------------------------------+--------------------------+------+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 10 | 42 | 00010_trig_update | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+ 20 | 42 | 00020_trig_update | Wed Jan 21 00:00:00 1970 PST | Wed Jan 21 00:00:00 1970 | 0 | 0 | foo
+ 30 | 42 | 00030_trig_update | Sat Jan 31 00:00:00 1970 PST | Sat Jan 31 00:00:00 1970 | 0 | 0 | foo
+ 40 | 42 | 00040_trig_update | Tue Feb 10 00:00:00 1970 PST | Tue Feb 10 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- ===================================================================
+-- test check constraints
+-- ===================================================================
+-- Consistent check constraints provide consistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- check constraint is enforced on the remote side, not locally
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
+-- But inconsistent check constraints provide inconsistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 821
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- local check constraint is not actually enforced
+INSERT INTO ft1(c1, c2) VALUES(1111, 2);
+UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
+-- ===================================================================
+-- test WITH CHECK OPTION constraints
+-- ===================================================================
+CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
+CREATE TABLE base_tbl (a int, b int);
+ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE VIEW rw_view AS SELECT * FROM foreign_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT foreign_tbl.a,
+ foreign_tbl.b
+ FROM foreign_tbl
+ WHERE foreign_tbl.a < foreign_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 5
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 15
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 5), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 15), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP TRIGGER row_before_insupd_trigger ON base_tbl;
+DROP TABLE base_tbl;
+-- test WCO for partitions
+CREATE TABLE child_tbl (a int, b int);
+ALTER TABLE child_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON child_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'child_tbl');
+CREATE TABLE parent_tbl (a int, b int) PARTITION BY RANGE(a);
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+-- Detach and re-attach once, to stress the concurrent detach case.
+ALTER TABLE parent_tbl DETACH PARTITION foreign_tbl CONCURRENTLY;
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+CREATE VIEW rw_view AS SELECT * FROM parent_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT parent_tbl.a,
+ parent_tbl.b
+ FROM parent_tbl
+ WHERE parent_tbl.a < parent_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 5
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 15
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 5), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 15), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------
+ Insert on public.parent_tbl
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+DROP TRIGGER row_before_insupd_trigger ON child_tbl;
+DROP TABLE parent_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP FUNCTION row_before_insupd_trigfunc;
+-- ===================================================================
+-- test serial columns (ie, sequence-based defaults)
+-- ===================================================================
+create table loc1 (f1 serial, f2 text);
+alter table loc1 set (autovacuum_enabled = 'false');
+create foreign table rem1 (f1 serial, f2 text)
+ server loopback options(table_name 'loc1');
+select pg_catalog.setval('rem1_f1_seq', 10, false);
+ setval
+--------
+ 10
+(1 row)
+
+insert into loc1(f2) values('hi');
+insert into rem1(f2) values('hi remote');
+insert into loc1(f2) values('bye');
+insert into rem1(f2) values('bye remote');
+select * from loc1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+select * from rem1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+-- ===================================================================
+-- test generated columns
+-- ===================================================================
+create table gloc1 (
+ a int,
+ b int generated always as (a * 2) stored);
+alter table gloc1 set (autovacuum_enabled = 'false');
+create foreign table grem1 (
+ a int,
+ b int generated always as (a * 2) stored)
+ server loopback options(table_name 'gloc1');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+explain (verbose, costs off)
+update grem1 set a = 22 where a = 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.grem1
+ Remote SQL: UPDATE public.gloc1 SET a = $2, b = DEFAULT WHERE ctid = $1
+ -> Foreign Scan on public.grem1
+ Output: 22, ctid, grem1.*
+ Remote SQL: SELECT a, b, ctid FROM public.gloc1 WHERE ((a = 2)) FOR UPDATE
+(5 rows)
+
+update grem1 set a = 22 where a = 2;
+select * from gloc1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+select * from grem1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+delete from grem1;
+-- test copy from
+copy grem1 from stdin;
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+-- test batch insert
+alter server loopback options (add batch_size '10');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 10
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test local triggers
+-- ===================================================================
+-- Trigger functions "borrowed" from triggers regress test.
+CREATE FUNCTION trigger_func() RETURNS trigger LANGUAGE plpgsql AS $$
+BEGIN
+ RAISE NOTICE 'trigger_func(%) called: action = %, when = %, level = %',
+ TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN NULL;
+END;$$;
+CREATE TRIGGER trig_stmt_before BEFORE DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE TRIGGER trig_stmt_after AFTER DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE OR REPLACE FUNCTION trigger_data() RETURNS trigger
+LANGUAGE plpgsql AS $$
+
+declare
+ oldnew text[];
+ relid text;
+ argstr text;
+begin
+
+ relid := TG_relid::regclass;
+ argstr := '';
+ for i in 0 .. TG_nargs - 1 loop
+ if i > 0 then
+ argstr := argstr || ', ';
+ end if;
+ argstr := argstr || TG_argv[i];
+ end loop;
+
+ RAISE NOTICE '%(%) % % % ON %',
+ tg_name, argstr, TG_when, TG_level, TG_OP, relid;
+ oldnew := '{}'::text[];
+ if TG_OP != 'INSERT' then
+ oldnew := array_append(oldnew, format('OLD: %s', OLD));
+ end if;
+
+ if TG_OP != 'DELETE' then
+ oldnew := array_append(oldnew, format('NEW: %s', NEW));
+ end if;
+
+ RAISE NOTICE '%', array_to_string(oldnew, ',');
+
+ if TG_OP = 'DELETE' then
+ return OLD;
+ else
+ return NEW;
+ end if;
+end;
+$$;
+-- Test basic functionality
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+delete from rem1;
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = AFTER, level = STATEMENT
+insert into rem1 values(1,'insert');
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+update rem1 set f2 = f2 || f2;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+truncate rem1;
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = BEFORE, level = STATEMENT
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = AFTER, level = STATEMENT
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_stmt_before ON rem1;
+DROP TRIGGER trig_stmt_after ON rem1;
+DELETE from rem1;
+-- Test multiple AFTER ROW triggers on a foreign table
+CREATE TRIGGER trig_row_after1
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after2
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+insert into rem1 values(1,'insert');
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+update rem1 set f2 = f2 || f2;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+delete from rem1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+-- cleanup
+DROP TRIGGER trig_row_after1 ON rem1;
+DROP TRIGGER trig_row_after2 ON rem1;
+-- Test WHEN conditions
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_insupd
+AFTER INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Insert or update not matching: nothing happens
+INSERT INTO rem1 values(1, 'insert');
+UPDATE rem1 set f2 = 'test';
+-- Insert or update matching: triggers are fired
+INSERT INTO rem1 values(2, 'update');
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+UPDATE rem1 set f2 = 'update update' where f1 = '2';
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Trigger is fired for f1=2, not for f1=1
+DELETE FROM rem1;
+NOTICE: trig_row_before_delete(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+NOTICE: trig_row_after_delete(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+-- cleanup
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_after_insupd ON rem1;
+DROP TRIGGER trig_row_before_delete ON rem1;
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- Test various RETURN statements in BEFORE triggers.
+CREATE FUNCTION trig_row_before_insupdate() RETURNS TRIGGER AS $$
+ BEGIN
+ NEW.f2 := NEW.f2 || ' triggered !';
+ RETURN NEW;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+-- The new values should have 'triggered' appended
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------
+ insert triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+ 2 | insert triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------
+ 1 | triggered !
+ 2 | triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------
+ skidoo triggered !
+ skidoo triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | skidoo triggered !
+ 2 | skidoo triggered !
+(2 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f1 = 10; -- all columns should be transmitted
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: 10, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+UPDATE rem1 set f1 = 10;
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 10 | skidoo triggered ! triggered !
+ 10 | skidoo triggered ! triggered !
+(2 rows)
+
+DELETE FROM rem1;
+-- Add a second trigger, to check that the changes are propagated correctly
+-- from trigger to trigger
+CREATE TRIGGER trig_row_before_insupd2
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------------------
+ insert triggered ! triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+ 2 | insert triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------
+ 1 | triggered ! triggered !
+ 2 | triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------------------
+ skidoo triggered ! triggered !
+ skidoo triggered ! triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | skidoo triggered ! triggered !
+ 2 | skidoo triggered ! triggered !
+(2 rows)
+
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_before_insupd2 ON rem1;
+DELETE from rem1;
+INSERT INTO rem1 VALUES (1, 'test');
+-- Test with a trigger returning NULL
+CREATE FUNCTION trig_null() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_null
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_null();
+-- Nothing should have changed.
+INSERT INTO rem1 VALUES (2, 'test2');
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+UPDATE rem1 SET f2 = 'test2';
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DELETE from rem1;
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DROP TRIGGER trig_null ON rem1;
+DELETE from rem1;
+-- Test a combination of local and remote triggers
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_local_before BEFORE INSERT OR UPDATE ON loc1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1(f2) VALUES ('test');
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (12,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (12,"test triggered !")
+UPDATE rem1 SET f2 = 'testo';
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,testo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,"testo triggered !")
+-- Test returning a system attribute
+INSERT INTO rem1(f2) VALUES ('test') RETURNING ctid;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (13,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (13,"test triggered !")
+ ctid
+--------
+ (0,25)
+(1 row)
+
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_local_before ON loc1;
+-- Test direct foreign table modification functionality
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1 WHERE false; -- currently can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Result
+ Output: ctid
+ One-Time Filter: false
+(5 rows)
+
+-- Test with statement-level triggers
+CREATE TRIGGER trig_stmt_before
+ BEFORE DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_before ON rem1;
+CREATE TRIGGER trig_stmt_after
+ AFTER DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_after ON rem1;
+-- Test with row-level ON INSERT triggers
+CREATE TRIGGER trig_row_before_insert
+BEFORE INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_insert ON rem1;
+CREATE TRIGGER trig_row_after_insert
+AFTER INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_insert ON rem1;
+-- Test with row-level ON UPDATE triggers
+CREATE TRIGGER trig_row_before_update
+BEFORE UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_update ON rem1;
+CREATE TRIGGER trig_row_after_update
+AFTER UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = $2 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_update ON rem1;
+-- Test with row-level ON DELETE triggers
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_before_delete ON rem1;
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- ===================================================================
+-- test inheritance features
+-- ===================================================================
+CREATE TABLE a (aa TEXT);
+CREATE TABLE loct (aa TEXT, bb TEXT);
+ALTER TABLE a SET (autovacuum_enabled = 'false');
+ALTER TABLE loct SET (autovacuum_enabled = 'false');
+CREATE FOREIGN TABLE b (bb TEXT) INHERITS (a)
+ SERVER loopback OPTIONS (table_name 'loct');
+INSERT INTO a(aa) VALUES('aaa');
+INSERT INTO a(aa) VALUES('aaaa');
+INSERT INTO a(aa) VALUES('aaaaa');
+INSERT INTO b(aa) VALUES('bbb');
+INSERT INTO b(aa) VALUES('bbbb');
+INSERT INTO b(aa) VALUES('bbbbb');
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+(3 rows)
+
+UPDATE a SET aa = 'zzzzzz' WHERE aa LIKE 'aaaa%';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE b SET aa = 'new';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | new
+ b | new
+ b | new
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-----+----
+ b | new |
+ b | new |
+ b | new |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE a SET aa = 'newtoo';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+ b | newtoo
+ b | newtoo
+ b | newtoo
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+--------+----
+ b | newtoo |
+ b | newtoo |
+ b | newtoo |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+(3 rows)
+
+DELETE FROM a;
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+----+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+DROP TABLE a CASCADE;
+NOTICE: drop cascades to foreign table b
+DROP TABLE loct;
+-- Check SELECT FOR UPDATE/SHARE with an inherited source table
+create table loct1 (f1 int, f2 int, f3 int);
+create table loct2 (f1 int, f2 int, f3 int);
+alter table loct1 set (autovacuum_enabled = 'false');
+alter table loct2 set (autovacuum_enabled = 'false');
+create table foo (f1 int, f2 int);
+create foreign table foo2 (f3 int) inherits (foo)
+ server loopback options (table_name 'loct1');
+create table bar (f1 int, f2 int);
+create foreign table bar2 (f3 int) inherits (bar)
+ server loopback options (table_name 'loct2');
+alter table foo set (autovacuum_enabled = 'false');
+alter table bar set (autovacuum_enabled = 'false');
+insert into foo values(1,1);
+insert into foo values(3,3);
+insert into foo2 values(2,2,2);
+insert into foo2 values(4,4,4);
+insert into bar values(1,11);
+insert into bar values(2,22);
+insert into bar values(6,66);
+insert into bar2 values(3,33,33);
+insert into bar2 values(4,44,44);
+insert into bar2 values(7,77,77);
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for update;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for update;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for share;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for share;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+-- Now check SELECT FOR UPDATE/SHARE with an inherited source table,
+-- where the parent is itself a foreign table
+create table loct4 (f1 int, f2 int, f3 int);
+create foreign table foo2child (f3 int) inherits (foo2)
+ server loopback options (table_name 'loct4');
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct1
+ -> Foreign Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct4
+(24 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop foreign table foo2child;
+-- And with a local child relation of the foreign table parent
+create table foo2child (f3 int) inherits (foo2);
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.ctid, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+ -> Seq Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.ctid, foo2_2.tableoid
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop table foo2child;
+-- Check UPDATE with inherited target and an inherited source table
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Hash Join
+ Output: (bar.f2 + 100), foo.ctid, bar.tableoid, bar.ctid, (NULL::record), foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(25 rows)
+
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 111
+ bar | 2 | 122
+ bar | 6 | 66
+ bar2 | 3 | 133
+ bar2 | 4 | 144
+ bar2 | 7 | 77
+(6 rows)
+
+-- Check UPDATE with inherited target and an appendrel subquery
+explain (verbose, costs off)
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Merge Join
+ Output: (bar.f2 + 100), (ROW(foo.f1)), bar.tableoid, bar.ctid, (NULL::record)
+ Merge Cond: (bar.f1 = foo.f1)
+ -> Sort
+ Output: bar.f2, bar.f1, bar.tableoid, bar.ctid, (NULL::record)
+ Sort Key: bar.f1
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Sort
+ Output: (ROW(foo.f1)), foo.f1
+ Sort Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: ROW(foo.f1), foo.f1
+ -> Foreign Scan on public.foo2 foo_1
+ Output: ROW(foo_1.f1), foo_1.f1
+ Remote SQL: SELECT f1 FROM public.loct1
+ -> Seq Scan on public.foo foo_2
+ Output: ROW((foo_2.f1 + 3)), (foo_2.f1 + 3)
+ -> Foreign Scan on public.foo2 foo_3
+ Output: ROW((foo_3.f1 + 3)), (foo_3.f1 + 3)
+ Remote SQL: SELECT f1 FROM public.loct1
+(30 rows)
+
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 211
+ bar | 2 | 222
+ bar | 6 | 166
+ bar2 | 3 | 233
+ bar2 | 4 | 244
+ bar2 | 7 | 177
+(6 rows)
+
+-- Test forcing the remote server to produce sorted data for a merge join,
+-- but the foreign table is an inheritance child.
+truncate table loct1;
+truncate table only foo;
+\set num_rows_foo 2000
+insert into loct1 select generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2);
+insert into foo select generate_series(1, :num_rows_foo, 2), generate_series(1, :num_rows_foo, 2);
+SET enable_hashjoin to false;
+SET enable_nestloop to false;
+alter foreign table foo2 options (use_remote_estimate 'true');
+create index i_loct1_f1 on loct1(f1);
+create index i_foo_f1 on foo(f1);
+analyze foo;
+analyze loct1;
+-- inner join; expressions in the clauses appear in the equivalence class list
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 20 | 20
+ 22 | 22
+ 24 | 24
+ 26 | 26
+ 28 | 28
+ 30 | 30
+ 32 | 32
+ 34 | 34
+ 36 | 36
+ 38 | 38
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Left Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 10 | 10
+ 11 |
+ 12 | 12
+ 13 |
+ 14 | 14
+ 15 |
+ 16 | 16
+ 17 |
+ 18 | 18
+ 19 |
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test that WHERE CURRENT OF is not supported
+begin;
+declare c cursor for select * from bar where f1 = 7;
+fetch from c;
+ f1 | f2
+----+-----
+ 7 | 177
+(1 row)
+
+update bar set f2 = null where current of c;
+ERROR: WHERE CURRENT OF is not supported for this table type
+rollback;
+explain (verbose, costs off)
+delete from foo where f1 < 5 returning *;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Delete on public.foo
+ Output: foo_1.f1, foo_1.f2
+ Delete on public.foo foo_1
+ Foreign Delete on public.foo2 foo_2
+ -> Append
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.tableoid, foo_1.ctid
+ Index Cond: (foo_1.f1 < 5)
+ -> Foreign Delete on public.foo2 foo_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ((f1 < 5)) RETURNING f1, f2
+(10 rows)
+
+delete from foo where f1 < 5 returning *;
+ f1 | f2
+----+----
+ 1 | 1
+ 3 | 3
+ 0 | 0
+ 2 | 2
+ 4 | 4
+(5 rows)
+
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Update on public.bar
+ Output: bar_1.f1, bar_1.f2
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = (f2 + 100) RETURNING f1, f2
+(11 rows)
+
+update bar set f2 = f2 + 100 returning *;
+ f1 | f2
+----+-----
+ 1 | 311
+ 2 | 322
+ 6 | 266
+ 3 | 333
+ 4 | 344
+ 7 | 277
+(6 rows)
+
+-- Test that UPDATE/DELETE with inherited target works with row-level triggers
+CREATE TRIGGER trig_row_before
+BEFORE UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+explain (verbose, costs off)
+update bar set f2 = f2 + 100;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f1 = $2, f2 = $3, f3 = $4 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+(12 rows)
+
+update bar set f2 = f2 + 100;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+explain (verbose, costs off)
+delete from bar where f2 < 400;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Delete on public.bar
+ Delete on public.bar bar_1
+ Foreign Delete on public.bar2 bar_2
+ Remote SQL: DELETE FROM public.loct2 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.tableoid, bar_1.ctid, NULL::record
+ Filter: (bar_1.f2 < 400)
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 WHERE ((f2 < 400)) FOR UPDATE
+(11 rows)
+
+delete from bar where f2 < 400;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+-- cleanup
+drop table foo cascade;
+NOTICE: drop cascades to foreign table foo2
+drop table bar cascade;
+NOTICE: drop cascades to foreign table bar2
+drop table loct1;
+drop table loct2;
+-- Test pushing down UPDATE/DELETE joins to the remote server
+create table parent (a int, b text);
+create table loct1 (a int, b text);
+create table loct2 (a int, b text);
+create foreign table remt1 (a int, b text)
+ server loopback options (table_name 'loct1');
+create foreign table remt2 (a int, b text)
+ server loopback options (table_name 'loct2');
+alter foreign table remt1 inherit parent;
+insert into remt1 values (1, 'foo');
+insert into remt1 values (2, 'bar');
+insert into remt2 values (1, 'foo');
+insert into remt2 values (2, 'bar');
+analyze remt1;
+analyze remt2;
+explain (verbose, costs off)
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.parent
+ Output: parent_1.a, parent_1.b, remt2.a, remt2.b
+ Update on public.parent parent_1
+ Foreign Update on public.remt1 parent_2
+ Remote SQL: UPDATE public.loct1 SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: (parent.b || remt2.b), remt2.*, remt2.a, remt2.b, parent.tableoid, parent.ctid, (NULL::record)
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.b, parent_1.a, parent_1.tableoid, parent_1.ctid, NULL::record
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.b, parent_2.a, parent_2.tableoid, parent_2.ctid, parent_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.b, remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.b, remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ a | b | a | b
+---+--------+---+-----
+ 1 | foofoo | 1 | foo
+ 2 | barbar | 2 | bar
+(2 rows)
+
+explain (verbose, costs off)
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Delete on public.parent
+ Output: parent_1.*
+ Delete on public.parent parent_1
+ Foreign Delete on public.remt1 parent_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: remt2.*, parent.tableoid, parent.ctid
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.a, parent_1.tableoid, parent_1.ctid
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.a, parent_2.tableoid, parent_2.ctid
+ Remote SQL: SELECT a, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ parent
+------------
+ (1,foofoo)
+ (2,barbar)
+(2 rows)
+
+-- cleanup
+drop foreign table remt1;
+drop foreign table remt2;
+drop table loct1;
+drop table loct2;
+drop table parent;
+-- ===================================================================
+-- test tuple routing for foreign-table partitions
+-- ===================================================================
+-- Test insert tuple routing
+create table itrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table itrtest attach partition remp1 for values in (1);
+alter table itrtest attach partition remp2 for values in (2);
+insert into itrtest values (1, 'foo');
+insert into itrtest values (1, 'bar') returning *;
+ a | b
+---+-----
+ 1 | bar
+(1 row)
+
+insert into itrtest values (2, 'baz');
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----
+ 2 | qux
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------
+ 1 | test1
+ 2 | test2
+(2 rows)
+
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from itrtest;
+-- MERGE ought to fail cleanly
+merge into itrtest using (select 1, 'foo') as source on (true)
+ when matched then do nothing;
+ERROR: cannot execute MERGE on relation "remp1"
+DETAIL: This operation is not supported for foreign tables.
+create unique index loct1_idx on loct1 (a);
+-- DO NOTHING without an inference specification is supported
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+-----
+ 1 | foo
+(1 row)
+
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+---
+(0 rows)
+
+-- But other cases are not supported
+insert into itrtest values (1, 'bar') on conflict (a) do nothing;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+insert into itrtest values (1, 'bar') on conflict (a) do update set b = excluded.b;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+delete from itrtest;
+drop index loct1_idx;
+-- Test that remote triggers work with insert tuple routing
+create function br_insert_trigfunc() returns trigger as $$
+begin
+ new.b := new.b || ' triggered !';
+ return new;
+end
+$$ language plpgsql;
+create trigger loct1_br_insert_trigger before insert on loct1
+ for each row execute procedure br_insert_trigfunc();
+create trigger loct2_br_insert_trigger before insert on loct2
+ for each row execute procedure br_insert_trigfunc();
+-- The new values are concatenated with ' triggered !'
+insert into itrtest values (1, 'foo') returning *;
+ a | b
+---+-----------------
+ 1 | foo triggered !
+(1 row)
+
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----------------
+ 2 | qux triggered !
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+with result as (insert into itrtest values (1, 'test1'), (2, 'test2') returning *) select * from result;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+drop trigger loct1_br_insert_trigger on loct1;
+drop trigger loct2_br_insert_trigger on loct2;
+drop table itrtest;
+drop table loct1;
+drop table loct2;
+-- Test update tuple routing
+create table utrtest (a int, b text) partition by list (a);
+create table loct (a int check (a in (1)), b text);
+create foreign table remp (a int check (a in (1)), b text) server loopback options (table_name 'loct');
+create table locp (a int check (a in (2)), b text);
+alter table utrtest attach partition remp for values in (1);
+alter table utrtest attach partition locp for values in (2);
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- It's not allowed to move a row from a partition that is foreign to another
+update utrtest set a = 2 where b = 'foo' returning *;
+ERROR: new row for relation "loct" violates check constraint "loct_a_check"
+DETAIL: Failing row contains (2, foo).
+CONTEXT: remote SQL command: UPDATE public.loct SET a = 2 WHERE ((b = 'foo')) RETURNING a, b
+-- But the reverse is allowed
+update utrtest set a = 1 where b = 'qux' returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- The executor should not let unexercised FDWs shut down
+update utrtest set a = 1 where b = 'foo';
+-- Test that remote triggers work with update tuple routing
+create trigger loct_br_insert_trigger before insert on loct
+ for each row execute procedure br_insert_trigfunc();
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition is a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 WHERE (((a = 1) OR (a = 2))) RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ Filter: ((utrtest_2.a = 1) OR (utrtest_2.a = 2))
+(10 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition isn't a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 2 returning *;
+ QUERY PLAN
+-------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ -> Seq Scan on public.locp utrtest_1
+ Output: 1, utrtest_1.tableoid, utrtest_1.ctid
+ Filter: (utrtest_1.a = 2)
+(6 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 2 returning *;
+ a | b
+---+-----------------
+ 1 | qux triggered !
+(1 row)
+
+drop trigger loct_br_insert_trigger on loct;
+-- We can move rows to a foreign partition that has been updated already,
+-- but can't move rows to a foreign partition that hasn't been updated yet
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- Test the former case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+(9 rows)
+
+update utrtest set a = 1 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ Update on public.locp utrtest_2
+ -> Hash Join
+ Output: 1, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, utrtest.*
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Foreign Scan on public.remp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, utrtest_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Seq Scan on public.locp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- Change the definition of utrtest so that the foreign partition get updated
+-- after the local partition
+delete from utrtest;
+alter table utrtest detach partition remp;
+drop foreign table remp;
+alter table loct drop constraint loct_a_check;
+alter table loct add check (a in (3));
+create foreign table remp (a int check (a in (3)), b text) server loopback options (table_name 'loct');
+alter table utrtest attach partition remp for values in (3);
+insert into utrtest values (2, 'qux');
+insert into utrtest values (3, 'xyzzy');
+-- Test the latter case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: 3, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = 3 RETURNING a, b
+(9 rows)
+
+update utrtest set a = 3 returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ -> Hash Join
+ Output: 3, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, (NULL::record)
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Scan on public.remp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, utrtest_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+drop table utrtest;
+drop table loct;
+-- Test copy tuple routing
+create table ctrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table ctrtest attach partition remp1 for values in (1);
+alter table ctrtest attach partition remp2 for values in (2);
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp2 | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-----+---
+ remp2 | qux | 2
+(1 row)
+
+-- Copying into foreign partitions directly should work as well
+copy remp1 from stdin;
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+(2 rows)
+
+delete from ctrtest;
+-- Test copy tuple routing with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from ctrtest;
+alter server loopback options (drop batch_size);
+drop table ctrtest;
+drop table loct1;
+drop table loct2;
+-- ===================================================================
+-- test COPY FROM
+-- ===================================================================
+create table loc2 (f1 int, f2 text);
+alter table loc2 set (autovacuum_enabled = 'false');
+create foreign table rem2 (f1 int, f2 text) server loopback options(table_name 'loc2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2, line 1: "-1 xyzzy"
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test local triggers
+create trigger trig_stmt_before before insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_stmt_after after insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+copy rem2 from stdin;
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop trigger trig_row_before on rem2;
+drop trigger trig_row_after on rem2;
+drop trigger trig_stmt_before on rem2;
+drop trigger trig_stmt_after on rem2;
+delete from rem2;
+create trigger trig_row_before_insert before insert on rem2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on rem2;
+delete from rem2;
+create trigger trig_null before insert on rem2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on rem2;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Test a combination of local and remote triggers
+create trigger rem2_trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger rem2_trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger loc2_trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+copy rem2 from stdin;
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,"foo triggered !")
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,"bar triggered !")
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger rem2_trig_row_before on rem2;
+drop trigger rem2_trig_row_after on rem2;
+drop trigger loc2_trig_row_before_insert on loc2;
+delete from rem2;
+-- test COPY FROM with foreign table created in the same transaction
+create table loc3 (f1 int, f2 text);
+begin;
+create foreign table rem3 (f1 int, f2 text)
+ server loopback options(table_name 'loc3');
+copy rem3 from stdin;
+commit;
+select * from rem3;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop foreign table rem3;
+drop table loc3;
+-- Test COPY FROM with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+ 3 | baz triggered !
+(3 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Check with zero-column foreign table; batch insert will be disabled
+alter table loc2 drop column f1;
+alter table loc2 drop column f2;
+alter table rem2 drop column f1;
+alter table rem2 drop column f2;
+copy rem2 from stdin;
+select * from rem2;
+--
+(3 rows)
+
+delete from rem2;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test for TRUNCATE
+-- ===================================================================
+CREATE TABLE tru_rtable0 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable0');
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(1,10) x);
+CREATE TABLE tru_ptable (id int) PARTITION BY HASH(id);
+CREATE TABLE tru_ptable__p0 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tru_rtable1 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable__p1 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback OPTIONS (table_name 'tru_rtable1');
+INSERT INTO tru_ptable (SELECT x FROM generate_series(11,20) x);
+CREATE TABLE tru_pk_table(id int primary key);
+CREATE TABLE tru_fk_table(fkey int references tru_pk_table(id));
+INSERT INTO tru_pk_table (SELECT x FROM generate_series(1,10) x);
+INSERT INTO tru_fk_table (SELECT x % 10 + 1 FROM generate_series(5,25) x);
+CREATE FOREIGN TABLE tru_pk_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_pk_table');
+CREATE TABLE tru_rtable_parent (id int);
+CREATE TABLE tru_rtable_child (id int);
+CREATE FOREIGN TABLE tru_ftable_parent (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_parent');
+CREATE FOREIGN TABLE tru_ftable_child () INHERITS (tru_ftable_parent)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_child');
+INSERT INTO tru_rtable_parent (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_rtable_child (SELECT x FROM generate_series(10, 18) x);
+-- normal truncate
+SELECT sum(id) FROM tru_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_ftable;
+SELECT count(*) FROM tru_rtable0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'truncatable' option
+ALTER SERVER loopback OPTIONS (ADD truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (ADD truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER SERVER loopback OPTIONS (DROP truncatable);
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+-- partitioned table with both local and foreign tables as partitions
+SELECT sum(id) FROM tru_ptable; -- 155
+ sum
+-----
+ 155
+(1 row)
+
+TRUNCATE tru_ptable;
+SELECT count(*) FROM tru_ptable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ptable__p0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable__p1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_rtable1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'CASCADE' option
+SELECT sum(id) FROM tru_pk_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_pk_ftable; -- failed by FK reference
+ERROR: cannot truncate a table referenced in a foreign key constraint
+DETAIL: Table "tru_fk_table" references "tru_pk_table".
+HINT: Truncate table "tru_fk_table" at the same time, or use TRUNCATE ... CASCADE.
+CONTEXT: remote SQL command: TRUNCATE public.tru_pk_table CONTINUE IDENTITY RESTRICT
+TRUNCATE tru_pk_ftable CASCADE;
+SELECT count(*) FROM tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_fk_table; -- also truncated,0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate two tables at a command
+INSERT INTO tru_ftable (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_pk_ftable (SELECT x FROM generate_series(3,10) x);
+SELECT count(*) from tru_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+TRUNCATE tru_ftable, tru_pk_ftable CASCADE;
+SELECT count(*) from tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate with ONLY clause
+-- Since ONLY is specified, the table tru_ftable_child that inherits
+-- tru_ftable_parent locally is not truncated.
+TRUNCATE ONLY tru_ftable_parent;
+SELECT sum(id) FROM tru_ftable_parent; -- 126
+ sum
+-----
+ 126
+(1 row)
+
+TRUNCATE tru_ftable_parent;
+SELECT count(*) FROM tru_ftable_parent; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- in case when remote table has inherited children
+CREATE TABLE tru_rtable0_child () INHERITS (tru_rtable0);
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(5,9) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(10,14) x);
+SELECT sum(id) FROM tru_ftable; -- 95
+ sum
+-----
+ 95
+(1 row)
+
+-- Both parent and child tables in the foreign server are truncated
+-- even though ONLY is specified because ONLY has no effect
+-- when truncating a foreign table.
+TRUNCATE ONLY tru_ftable;
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(21,25) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(26,30) x);
+SELECT sum(id) FROM tru_ftable; -- 255
+ sum
+-----
+ 255
+(1 row)
+
+TRUNCATE tru_ftable; -- truncate both of parent and child
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- cleanup
+DROP FOREIGN TABLE tru_ftable_parent, tru_ftable_child, tru_pk_ftable,tru_ftable__p1,tru_ftable;
+DROP TABLE tru_rtable0, tru_rtable1, tru_ptable, tru_ptable__p0, tru_pk_table, tru_fk_table,
+tru_rtable_parent,tru_rtable_child, tru_rtable0_child;
+-- ===================================================================
+-- test IMPORT FOREIGN SCHEMA
+-- ===================================================================
+CREATE SCHEMA import_source;
+CREATE TABLE import_source.t1 (c1 int, c2 varchar NOT NULL);
+CREATE TABLE import_source.t2 (c1 int default 42, c2 varchar NULL, c3 text collate "POSIX");
+CREATE TYPE typ1 AS (m1 int, m2 varchar);
+CREATE TABLE import_source.t3 (c1 timestamptz default now(), c2 typ1);
+CREATE TABLE import_source."x 4" (c1 float8, "C 2" text, c3 varchar(42));
+CREATE TABLE import_source."x 5" (c1 float8);
+ALTER TABLE import_source."x 5" DROP COLUMN c1;
+CREATE TABLE import_source."x 6" (c1 int, c2 int generated always as (c1 * 2) stored);
+CREATE TABLE import_source.t4 (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE import_source.t4_part PARTITION OF import_source.t4
+ FOR VALUES FROM (1) TO (100);
+CREATE TABLE import_source.t4_part2 PARTITION OF import_source.t4
+ FOR VALUES FROM (100) TO (200);
+CREATE SCHEMA import_dest1;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest1;
+\det+ import_dest1.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest1 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest1 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest1 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest1 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest1 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest1 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest1 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest1.*
+ Foreign table "import_dest1.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest1.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest1.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest1.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest1.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest1.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest1.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Options
+CREATE SCHEMA import_dest2;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest2
+ OPTIONS (import_default 'true');
+\det+ import_dest2.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest2 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest2 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest2 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest2 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest2 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest2 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest2 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest2.*
+ Foreign table "import_dest2.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest2.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | 42 | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest2.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | now() | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest2.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest2.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest2.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest2.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+CREATE SCHEMA import_dest3;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest3
+ OPTIONS (import_collate 'false', import_generated 'false', import_not_null 'false');
+\det+ import_dest3.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest3 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest3 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest3 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest3 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest3 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest3 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest3 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest3.*
+ Foreign table "import_dest3.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest3.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest3.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest3.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest3.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest3.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest3.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Check LIMIT TO and EXCEPT
+CREATE SCHEMA import_dest4;
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t1, nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+(2 rows)
+
+IMPORT FOREIGN SCHEMA import_source EXCEPT (t1, "x 4", nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest4 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest4 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+ import_dest4 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest4 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+-- Assorted error cases
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest4;
+ERROR: relation "t1" already exists
+CONTEXT: importing foreign table "t1"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO import_dest4;
+ERROR: schema "nonesuch" is not present on foreign server "loopback"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO notthere;
+ERROR: schema "notthere" does not exist
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER nowhere INTO notthere;
+ERROR: server "nowhere" does not exist
+-- Check case of a type present only on the remote server.
+-- We can fake this by dropping the type locally in our transaction.
+CREATE TYPE "Colors" AS ENUM ('red', 'green', 'blue');
+CREATE TABLE import_source.t5 (c1 int, c2 text collate "C", "Col" "Colors");
+CREATE SCHEMA import_dest5;
+BEGIN;
+DROP TYPE "Colors" CASCADE;
+NOTICE: drop cascades to column Col of table import_source.t5
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t5)
+ FROM SERVER loopback INTO import_dest5; -- ERROR
+ERROR: type "public.Colors" does not exist
+LINE 4: "Col" public."Colors" OPTIONS (column_name 'Col')
+ ^
+QUERY: CREATE FOREIGN TABLE t5 (
+ c1 integer OPTIONS (column_name 'c1'),
+ c2 text OPTIONS (column_name 'c2') COLLATE pg_catalog."C",
+ "Col" public."Colors" OPTIONS (column_name 'Col')
+) SERVER loopback
+OPTIONS (schema_name 'import_source', table_name 't5');
+CONTEXT: importing foreign table "t5"
+ROLLBACK;
+BEGIN;
+CREATE SERVER fetch101 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( fetch_size '101' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER fetch101 OPTIONS( SET fetch_size '202' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=202'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30000 ( x int ) SERVER fetch101 OPTIONS ( fetch_size '30000' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '60000');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=60000'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- ===================================================================
+-- test partitionwise joins
+-- ===================================================================
+SET enable_partitionwise_join=on;
+CREATE TABLE fprt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE fprt1_p1 (LIKE fprt1);
+CREATE TABLE fprt1_p2 (LIKE fprt1);
+ALTER TABLE fprt1_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt1_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt1_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 2) i;
+INSERT INTO fprt1_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 2) i;
+CREATE FOREIGN TABLE ftprt1_p1 PARTITION OF fprt1 FOR VALUES FROM (0) TO (250)
+ SERVER loopback OPTIONS (table_name 'fprt1_p1', use_remote_estimate 'true');
+CREATE FOREIGN TABLE ftprt1_p2 PARTITION OF fprt1 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (TABLE_NAME 'fprt1_p2');
+ANALYZE fprt1;
+ANALYZE fprt1_p1;
+ANALYZE fprt1_p2;
+CREATE TABLE fprt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE fprt2_p1 (LIKE fprt2);
+CREATE TABLE fprt2_p2 (LIKE fprt2);
+ALTER TABLE fprt2_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt2_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt2_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 3) i;
+INSERT INTO fprt2_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 3) i;
+CREATE FOREIGN TABLE ftprt2_p1 (b int, c varchar, a int)
+ SERVER loopback OPTIONS (table_name 'fprt2_p1', use_remote_estimate 'true');
+ALTER TABLE fprt2 ATTACH PARTITION ftprt2_p1 FOR VALUES FROM (0) TO (250);
+CREATE FOREIGN TABLE ftprt2_p2 PARTITION OF fprt2 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (table_name 'fprt2_p2', use_remote_estimate 'true');
+ANALYZE fprt2;
+ANALYZE fprt2_p1;
+ANALYZE fprt2_p2;
+-- inner join three tables
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t3.c
+ -> Append
+ -> Foreign Scan
+ Relations: ((ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)) INNER JOIN (ftprt1_p1 t3_1)
+ -> Foreign Scan
+ Relations: ((ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)) INNER JOIN (ftprt1_p2 t3_2)
+(7 rows)
+
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0003
+ 250 | 250 | 0005
+ 400 | 400 | 0008
+(4 rows)
+
+-- left outer join + nullable clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.a, fprt2.b, fprt2.c
+ Relations: (public.ftprt1_p1 t1) LEFT JOIN (public.ftprt2_p1 fprt2)
+ Remote SQL: SELECT r5.a, r6.b, r6.c FROM (public.fprt1_p1 r5 LEFT JOIN public.fprt2_p1 r6 ON (((r5.a = r6.b)) AND ((r5.b = r6.a)) AND ((r6.a < 10)))) WHERE ((r5.a < 10)) ORDER BY r5.a ASC NULLS LAST, r6.b ASC NULLS LAST, r6.c ASC NULLS LAST
+(4 rows)
+
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ a | b | c
+---+---+------
+ 0 | 0 | 0000
+ 2 | |
+ 4 | |
+ 6 | 6 | 0000
+ 8 | |
+(5 rows)
+
+-- with whole-row reference; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ QUERY PLAN
+--------------------------------------------------------
+ Sort
+ Sort Key: ((t1.*)::fprt1), ((t2.*)::fprt2)
+ -> Hash Full Join
+ Hash Cond: (t1.a = t2.b)
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+(11 rows)
+
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ wr | wr
+----------------+----------------
+ (0,0,0000) | (0,0,0000)
+ (50,50,0001) |
+ (100,100,0002) |
+ (150,150,0003) | (150,150,0003)
+ (200,200,0004) |
+ (250,250,0005) | (250,250,0005)
+ (300,300,0006) |
+ (350,350,0007) |
+ (400,400,0008) | (400,400,0008)
+ (450,450,0009) |
+ | (75,75,0001)
+ | (225,225,0004)
+ | (325,325,0006)
+ | (475,475,0009)
+(14 rows)
+
+-- join with lateral reference
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t1.b
+ -> Append
+ -> Foreign Scan
+ Relations: (ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)
+ -> Foreign Scan
+ Relations: (ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)
+(7 rows)
+
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+-- with PHVs, partitionwise join selected but no join pushdown
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: fprt1.a, fprt2.b
+ -> Append
+ -> Hash Full Join
+ Hash Cond: (fprt1_1.a = fprt2_1.b)
+ -> Foreign Scan on ftprt1_p1 fprt1_1
+ -> Hash
+ -> Foreign Scan on ftprt2_p1 fprt2_1
+ -> Hash Full Join
+ Hash Cond: (fprt1_2.a = fprt2_2.b)
+ -> Foreign Scan on ftprt1_p2 fprt1_2
+ -> Hash
+ -> Foreign Scan on ftprt2_p2 fprt2_2
+(13 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | phv | b | phv
+-----+--------+-----+--------
+ 0 | t1_phv | 0 | t2_phv
+ 50 | t1_phv | |
+ 100 | t1_phv | |
+ 150 | t1_phv | 150 | t2_phv
+ 200 | t1_phv | |
+ 250 | t1_phv | 250 | t2_phv
+ 300 | t1_phv | |
+ 350 | t1_phv | |
+ 400 | t1_phv | 400 | t2_phv
+ 450 | t1_phv | |
+ | | 75 | t2_phv
+ | | 225 | t2_phv
+ | | 325 | t2_phv
+ | | 475 | t2_phv
+(14 rows)
+
+-- test FOR UPDATE; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ QUERY PLAN
+--------------------------------------------------------------
+ LockRows
+ -> Sort
+ Sort Key: t1.a
+ -> Hash Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+(12 rows)
+
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+RESET enable_partitionwise_join;
+-- ===================================================================
+-- test partitionwise aggregates
+-- ===================================================================
+CREATE TABLE pagg_tab (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE pagg_tab_p1 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p2 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p3 (LIKE pagg_tab);
+INSERT INTO pagg_tab_p1 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 10;
+INSERT INTO pagg_tab_p2 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 20 and (i % 30) >= 10;
+INSERT INTO pagg_tab_p3 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 30 and (i % 30) >= 20;
+-- Create foreign partitions
+CREATE FOREIGN TABLE fpagg_tab_p1 PARTITION OF pagg_tab FOR VALUES FROM (0) TO (10) SERVER loopback OPTIONS (table_name 'pagg_tab_p1');
+CREATE FOREIGN TABLE fpagg_tab_p2 PARTITION OF pagg_tab FOR VALUES FROM (10) TO (20) SERVER loopback OPTIONS (table_name 'pagg_tab_p2');
+CREATE FOREIGN TABLE fpagg_tab_p3 PARTITION OF pagg_tab FOR VALUES FROM (20) TO (30) SERVER loopback OPTIONS (table_name 'pagg_tab_p3');
+ANALYZE pagg_tab;
+ANALYZE fpagg_tab_p1;
+ANALYZE fpagg_tab_p2;
+ANALYZE fpagg_tab_p3;
+-- When GROUP BY clause matches with PARTITION KEY.
+-- Plan with partitionwise aggregates is disabled
+SET enable_partitionwise_aggregate TO false;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> HashAggregate
+ Group Key: pagg_tab.a
+ Filter: (avg(pagg_tab.b) < '22'::numeric)
+ -> Append
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab_1
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_2
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_3
+(9 rows)
+
+-- Plan with partitionwise aggregates is enabled
+SET enable_partitionwise_aggregate TO true;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> Append
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p1 pagg_tab)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p2 pagg_tab_1)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p3 pagg_tab_2)
+(9 rows)
+
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | sum | min | count
+----+------+-----+-------
+ 0 | 2000 | 0 | 100
+ 1 | 2100 | 1 | 100
+ 10 | 2000 | 0 | 100
+ 11 | 2100 | 1 | 100
+ 20 | 2000 | 0 | 100
+ 21 | 2100 | 1 | 100
+(6 rows)
+
+-- Check with whole-row reference
+-- Should have all the columns in the target list for the given relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, (count(((t1.*)::pagg_tab)))
+ Sort Key: t1.a
+ -> Append
+ -> HashAggregate
+ Output: t1.a, count(((t1.*)::pagg_tab))
+ Group Key: t1.a
+ Filter: (avg(t1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p1 t1
+ Output: t1.a, t1.*, t1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p1
+ -> HashAggregate
+ Output: t1_1.a, count(((t1_1.*)::pagg_tab))
+ Group Key: t1_1.a
+ Filter: (avg(t1_1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p2 t1_1
+ Output: t1_1.a, t1_1.*, t1_1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p2
+ -> HashAggregate
+ Output: t1_2.a, count(((t1_2.*)::pagg_tab))
+ Group Key: t1_2.a
+ Filter: (avg(t1_2.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p3 t1_2
+ Output: t1_2.a, t1_2.*, t1_2.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p3
+(25 rows)
+
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | count
+----+-------
+ 0 | 100
+ 1 | 100
+ 10 | 100
+ 11 | 100
+ 20 | 100
+ 21 | 100
+(6 rows)
+
+-- When GROUP BY clause does not match with PARTITION KEY.
+EXPLAIN (COSTS OFF)
+SELECT b, avg(a), max(a), count(*) FROM pagg_tab GROUP BY b HAVING sum(a) < 700 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.b
+ -> Finalize HashAggregate
+ Group Key: pagg_tab.b
+ Filter: (sum(pagg_tab.a) < 700)
+ -> Append
+ -> Partial HashAggregate
+ Group Key: pagg_tab.b
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab
+ -> Partial HashAggregate
+ Group Key: pagg_tab_1.b
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_1
+ -> Partial HashAggregate
+ Group Key: pagg_tab_2.b
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_2
+(15 rows)
+
+-- ===================================================================
+-- access rights and superuser
+-- ===================================================================
+-- Non-superuser cannot create a FDW without a password in the connstr
+CREATE ROLE regress_nosuper NOSUPERUSER;
+GRANT USAGE ON FOREIGN DATA WRAPPER postgres_fdw TO regress_nosuper;
+SET ROLE regress_nosuper;
+SHOW is_superuser;
+ is_superuser
+--------------
+ off
+(1 row)
+
+-- This will be OK, we can create the FDW
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback_nopw FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+-- But creation of user mappings for non-superusers should fail
+CREATE USER MAPPING FOR public SERVER loopback_nopw;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+CREATE FOREIGN TABLE pg_temp.ft1_nopw (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback_nopw OPTIONS (schema_name 'public', table_name 'ft1');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+-- If we add a password to the connstr it'll fail, because we don't allow passwords
+-- in connstrs only in user mappings.
+ALTER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+ERROR: invalid option "password"
+HINT: Perhaps you meant the option "passfile".
+-- If we add a password for our user mapping instead, we should get a different
+-- error because the password wasn't actually *used* when we run with trust auth.
+--
+-- This won't work with installcheck, but neither will most of the FDW checks.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+-- Unpriv user cannot make the mapping passwordless
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+ERROR: password_required=false is superuser-only
+HINT: User mappings with the password_required option set to false may only be created or modified by the superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+RESET ROLE;
+-- But the superuser can
+ALTER USER MAPPING FOR regress_nosuper SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+SET ROLE regress_nosuper;
+-- Should finally work now
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- unpriv user also cannot set sslcert / sslkey on the user mapping
+-- first set password_required so we see the right error messages
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (SET password_required 'true');
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslcert 'foo.crt');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslkey 'foo.key');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+-- We're done with the role named after a specific user and need to check the
+-- changes to the public mapping.
+DROP USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+-- This will fail again as it'll resolve the user mapping for public, which
+-- lacks password_required=false
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+RESET ROLE;
+-- The user mapping for public is passwordless and lacks the password_required=false
+-- mapping option, but will work because the current user is a superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- cleanup
+DROP USER MAPPING FOR public SERVER loopback_nopw;
+DROP OWNED BY regress_nosuper;
+DROP ROLE regress_nosuper;
+-- Clean-up
+RESET enable_partitionwise_aggregate;
+-- Two-phase transactions are not supported.
+BEGIN;
+SELECT count(*) FROM ft1;
+ count
+-------
+ 822
+(1 row)
+
+-- error here
+PREPARE TRANSACTION 'fdw_tpc';
+ERROR: cannot PREPARE a transaction that has operated on postgres_fdw foreign tables
+ROLLBACK;
+WARNING: there is no transaction in progress
+-- ===================================================================
+-- reestablish new connection
+-- ===================================================================
+-- Change application_name of remote connection to special one
+-- so that we can easily terminate the connection later.
+ALTER SERVER loopback OPTIONS (application_name 'fdw_retry_check');
+-- If debug_discard_caches is active, it results in
+-- dropping remote connections after every transaction, making it
+-- impossible to test termination meaningfully. So turn that off
+-- for this test.
+SET debug_discard_caches = 0;
+-- Make sure we have a remote connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- This query should detect the broken connection when starting new remote
+-- transaction, reestablish new connection, and then succeed.
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- If we detect the broken connection when starting a new remote
+-- subtransaction, we should fail instead of establishing a new connection.
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+SAVEPOINT s;
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT 1 FROM ft1 LIMIT 1; -- should fail
+ERROR: 08006
+\set VERBOSITY default
+COMMIT;
+RESET debug_discard_caches;
+-- =============================================================================
+-- test connection invalidation cases and postgres_fdw_get_connections function
+-- =============================================================================
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- This test case is for closing the connection in pgfdw_xact_callback
+BEGIN;
+-- Connection xact depth becomes 1 i.e. the connection is in midst of the xact.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT 1 FROM ft7 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback3 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback3
+(2 rows)
+
+-- Connections are not closed at the end of the alter and drop statements.
+-- That's because the connections are in midst of this xact,
+-- they are just marked as invalid in pgfdw_inval_callback.
+ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
+DROP SERVER loopback3 CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to user mapping for public on server loopback3
+drop cascades to foreign table ft7
+-- List all the existing cached connections. loopback and loopback3
+-- should be output as invalid connections. Also the server name for
+-- loopback3 should be NULL because the server was dropped.
+SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | valid
+-------------+-------
+ loopback | f
+ | f
+(2 rows)
+
+-- The invalid connections get closed in pgfdw_xact_callback during commit.
+COMMIT;
+-- All cached connections were closed while committing above xact, so no
+-- records should be output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+(0 rows)
+
+-- =======================================================================
+-- test postgres_fdw_disconnect and postgres_fdw_disconnect_all functions
+-- =======================================================================
+BEGIN;
+-- Ensure to cache loopback connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Ensure to cache loopback2 connection.
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Issue a warning and return false as loopback connection is still in use and
+-- can not be closed.
+SELECT postgres_fdw_disconnect('loopback');
+WARNING: cannot close connection for server "loopback" because it is still in use
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Return false as connections are still in use, warnings are issued.
+-- But disable warnings temporarily because the order of them is not stable.
+SET client_min_messages = 'ERROR';
+SELECT postgres_fdw_disconnect_all();
+ postgres_fdw_disconnect_all
+-----------------------------
+ f
+(1 row)
+
+RESET client_min_messages;
+COMMIT;
+-- Ensure that loopback2 connection is closed.
+SELECT 1 FROM postgres_fdw_disconnect('loopback2');
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT server_name FROM postgres_fdw_get_connections() WHERE server_name = 'loopback2';
+ server_name
+-------------
+(0 rows)
+
+-- Return false as loopback2 connection is closed already.
+SELECT postgres_fdw_disconnect('loopback2');
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- Return an error as there is no foreign server with given name.
+SELECT postgres_fdw_disconnect('unknownserver');
+ERROR: server "unknownserver" does not exist
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- =============================================================================
+-- test case for having multiple cached connections for a foreign server
+-- =============================================================================
+CREATE ROLE regress_multi_conn_user1 SUPERUSER;
+CREATE ROLE regress_multi_conn_user2 SUPERUSER;
+CREATE USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+CREATE USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+BEGIN;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user1
+SET ROLE regress_multi_conn_user1;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user2
+SET ROLE regress_multi_conn_user2;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Should output two connections for loopback server
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback
+(2 rows)
+
+COMMIT;
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- Clean up
+DROP USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+DROP USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+DROP ROLE regress_multi_conn_user1;
+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
+-- ===================================================================
+BEGIN;
+CREATE SERVER batch10 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( batch_size '10' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER batch10 OPTIONS( SET batch_size '20' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=20'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30 ( x int ) SERVER batch10 OPTIONS ( batch_size '30' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30 OPTIONS ( SET batch_size '40');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=40'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+CREATE TABLE batch_table ( x int );
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '10' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 10
+ -> Function Scan on pg_catalog.generate_series i
+ Output: i.i
+ Function Call: generate_series(1, 10)
+(6 rows)
+
+INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+INSERT INTO ftable SELECT * FROM generate_series(11, 31) i;
+INSERT INTO ftable VALUES (32);
+INSERT INTO ftable VALUES (33), (34);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 34
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- try if large batches exceed max number of bind parameters
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '100000' );
+INSERT INTO ftable SELECT * FROM generate_series(1, 70000) i;
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 70000
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- Disable batch insert
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '1' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (1), (2);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 2
+(1 row)
+
+-- Disable batch inserting into foreign tables with BEFORE ROW INSERT triggers
+-- even if the batch_size option is enabled.
+ALTER FOREIGN TABLE ftable OPTIONS ( SET batch_size '10' );
+CREATE TRIGGER trig_row_before BEFORE INSERT ON ftable
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (3), (4);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (3), (4);
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (3)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (4)
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 4
+(1 row)
+
+-- Clean up
+DROP TRIGGER trig_row_before ON ftable;
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+-- Use partitioning
+CREATE TABLE batch_table ( x int ) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0', batch_size '10');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1', batch_size '1');
+CREATE TABLE batch_table_p2
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 2);
+INSERT INTO batch_table SELECT * FROM generate_series(1, 66) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 66
+(1 row)
+
+-- Check that enabling batched inserts doesn't interfere with cross-partition
+-- updates
+CREATE TABLE batch_cp_upd_test (a int) PARTITION BY LIST (a);
+CREATE TABLE batch_cp_upd_test1 (LIKE batch_cp_upd_test);
+CREATE FOREIGN TABLE batch_cp_upd_test1_f
+ PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_cp_upd_test1', batch_size '10');
+CREATE TABLE batch_cp_up_test1 PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (2);
+INSERT INTO batch_cp_upd_test VALUES (1), (2);
+-- The following moves a row from the local partition to the foreign one
+UPDATE batch_cp_upd_test t SET a = 1 FROM (VALUES (1), (2)) s(a) WHERE t.a = s.a;
+ERROR: cannot route tuples into foreign table to be updated "batch_cp_upd_test1_f"
+SELECT tableoid::regclass, * FROM batch_cp_upd_test;
+ tableoid | a
+----------------------+---
+ batch_cp_upd_test1_f | 1
+ batch_cp_up_test1 | 2
+(2 rows)
+
+-- Clean up
+DROP TABLE batch_table, batch_cp_upd_test, batch_table_p0, batch_table_p1 CASCADE;
+-- Use partitioning
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+CREATE TABLE batch_table ( x int, field1 text, field2 text) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+ALTER TABLE batch_table_p0 ADD CONSTRAINT p0_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+ALTER TABLE batch_table_p1 ADD CONSTRAINT p1_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1');
+INSERT INTO batch_table SELECT i, 'test'||i, 'test'|| i FROM generate_series(1, 50) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 50
+(1 row)
+
+SELECT * FROM batch_table ORDER BY x;
+ x | field1 | field2
+----+--------+--------
+ 1 | test1 | test1
+ 2 | test2 | test2
+ 3 | test3 | test3
+ 4 | test4 | test4
+ 5 | test5 | test5
+ 6 | test6 | test6
+ 7 | test7 | test7
+ 8 | test8 | test8
+ 9 | test9 | test9
+ 10 | test10 | test10
+ 11 | test11 | test11
+ 12 | test12 | test12
+ 13 | test13 | test13
+ 14 | test14 | test14
+ 15 | test15 | test15
+ 16 | test16 | test16
+ 17 | test17 | test17
+ 18 | test18 | test18
+ 19 | test19 | test19
+ 20 | test20 | test20
+ 21 | test21 | test21
+ 22 | test22 | test22
+ 23 | test23 | test23
+ 24 | test24 | test24
+ 25 | test25 | test25
+ 26 | test26 | test26
+ 27 | test27 | test27
+ 28 | test28 | test28
+ 29 | test29 | test29
+ 30 | test30 | test30
+ 31 | test31 | test31
+ 32 | test32 | test32
+ 33 | test33 | test33
+ 34 | test34 | test34
+ 35 | test35 | test35
+ 36 | test36 | test36
+ 37 | test37 | test37
+ 38 | test38 | test38
+ 39 | test39 | test39
+ 40 | test40 | test40
+ 41 | test41 | test41
+ 42 | test42 | test42
+ 43 | test43 | test43
+ 44 | test44 | test44
+ 45 | test45 | test45
+ 46 | test46 | test46
+ 47 | test47 | test47
+ 48 | test48 | test48
+ 49 | test49 | test49
+ 50 | test50 | test50
+(50 rows)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+-- ===================================================================
+-- test asynchronous execution
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD async_capable 'true');
+ALTER SERVER loopback2 OPTIONS (ADD async_capable 'true');
+CREATE TABLE async_pt (a int, b int, c text) PARTITION BY RANGE (a);
+CREATE TABLE base_tbl1 (a int, b int, c text);
+CREATE TABLE base_tbl2 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p1 PARTITION OF async_pt FOR VALUES FROM (1000) TO (2000)
+ SERVER loopback OPTIONS (table_name 'base_tbl1');
+CREATE FOREIGN TABLE async_p2 PARTITION OF async_pt FOR VALUES FROM (2000) TO (3000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl2');
+INSERT INTO async_p1 SELECT 1000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+INSERT INTO async_p2 SELECT 2000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+-- simple queries
+CREATE TABLE result_tbl (a int, b int, c text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE (((b % 100) = 0))
+(8 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1000 | 0 | 0000
+ 1100 | 100 | 0100
+ 1200 | 200 | 0200
+ 1300 | 300 | 0300
+ 1400 | 400 | 0400
+ 1500 | 500 | 0500
+ 1600 | 600 | 0600
+ 1700 | 700 | 0700
+ 1800 | 800 | 0800
+ 1900 | 900 | 0900
+ 2000 | 0 | 0000
+ 2100 | 100 | 0100
+ 2200 | 200 | 0200
+ 2300 | 300 | 0300
+ 2400 | 400 | 0400
+ 2500 | 500 | 0500
+ 2600 | 600 | 0600
+ 2700 | 700 | 0700
+ 2800 | 800 | 0800
+ 2900 | 900 | 0900
+(20 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, ('AAA'::text || async_pt_1.c)
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, ('AAA'::text || async_pt_2.c)
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+---------
+ 1505 | 505 | AAA0505
+ 2505 | 505 | AAA0505
+(2 rows)
+
+DELETE FROM result_tbl;
+-- Check case where multiple partitions use the same connection
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl3');
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Async Foreign Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(14 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+DROP FOREIGN TABLE async_p3;
+DROP TABLE base_tbl3;
+-- Check case where the partitioned table has local/remote partitions
+CREATE TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000);
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+(13 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+-- partitionwise joins
+SET enable_partitionwise_join TO true;
+CREATE TABLE join_tbl (a1 int, b1 int, c1 text, a2 int, b2 int, c2 text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t2_1.b, t2_1.c
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t2_2.b, t2_2.c
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, t1_3.c, t2_3.a, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+ 2000 | 0 | 0000 | 2000 | 0 | 0000
+ 2100 | 100 | 0100 | 2100 | 100 | 0100
+ 2200 | 200 | 0200 | 2200 | 200 | 0200
+ 2300 | 300 | 0300 | 2300 | 300 | 0300
+ 2400 | 400 | 0400 | 2400 | 400 | 0400
+ 2500 | 500 | 0500 | 2500 | 500 | 0500
+ 2600 | 600 | 0600 | 2600 | 600 | 0600
+ 2700 | 700 | 0700 | 2700 | 700 | 0700
+ 2800 | 800 | 0800 | 2800 | 800 | 0800
+ 2900 | 900 | 0900 | 2900 | 900 | 0900
+ 3000 | 0 | 0000 | 3000 | 0 | 0000
+ 3100 | 100 | 0100 | 3100 | 100 | 0100
+ 3200 | 200 | 0200 | 3200 | 200 | 0200
+ 3300 | 300 | 0300 | 3300 | 300 | 0300
+ 3400 | 400 | 0400 | 3400 | 400 | 0400
+ 3500 | 500 | 0500 | 3500 | 500 | 0500
+ 3600 | 600 | 0600 | 3600 | 600 | 0600
+ 3700 | 700 | 0700 | 3700 | 700 | 0700
+ 3800 | 800 | 0800 | 3800 | 800 | 0800
+ 3900 | 900 | 0900 | 3900 | 900 | 0900
+(30 rows)
+
+DELETE FROM join_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, ('AAA'::text || t1_1.c), t2_1.a, t2_1.b, ('AAA'::text || t2_1.c)
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, ('AAA'::text || t1_2.c), t2_2.a, t2_2.b, ('AAA'::text || t2_2.c)
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, ('AAA'::text || t1_3.c), t2_3.a, t2_3.b, ('AAA'::text || t2_3.c)
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+---------+------+-----+---------
+ 1000 | 0 | AAA0000 | 1000 | 0 | AAA0000
+ 1100 | 100 | AAA0100 | 1100 | 100 | AAA0100
+ 1200 | 200 | AAA0200 | 1200 | 200 | AAA0200
+ 1300 | 300 | AAA0300 | 1300 | 300 | AAA0300
+ 1400 | 400 | AAA0400 | 1400 | 400 | AAA0400
+ 1500 | 500 | AAA0500 | 1500 | 500 | AAA0500
+ 1600 | 600 | AAA0600 | 1600 | 600 | AAA0600
+ 1700 | 700 | AAA0700 | 1700 | 700 | AAA0700
+ 1800 | 800 | AAA0800 | 1800 | 800 | AAA0800
+ 1900 | 900 | AAA0900 | 1900 | 900 | AAA0900
+ 2000 | 0 | AAA0000 | 2000 | 0 | AAA0000
+ 2100 | 100 | AAA0100 | 2100 | 100 | AAA0100
+ 2200 | 200 | AAA0200 | 2200 | 200 | AAA0200
+ 2300 | 300 | AAA0300 | 2300 | 300 | AAA0300
+ 2400 | 400 | AAA0400 | 2400 | 400 | AAA0400
+ 2500 | 500 | AAA0500 | 2500 | 500 | AAA0500
+ 2600 | 600 | AAA0600 | 2600 | 600 | AAA0600
+ 2700 | 700 | AAA0700 | 2700 | 700 | AAA0700
+ 2800 | 800 | AAA0800 | 2800 | 800 | AAA0800
+ 2900 | 900 | AAA0900 | 2900 | 900 | AAA0900
+ 3000 | 0 | AAA0000 | 3000 | 0 | AAA0000
+ 3100 | 100 | AAA0100 | 3100 | 100 | AAA0100
+ 3200 | 200 | AAA0200 | 3200 | 200 | AAA0200
+ 3300 | 300 | AAA0300 | 3300 | 300 | AAA0300
+ 3400 | 400 | AAA0400 | 3400 | 400 | AAA0400
+ 3500 | 500 | AAA0500 | 3500 | 500 | AAA0500
+ 3600 | 600 | AAA0600 | 3600 | 600 | AAA0600
+ 3700 | 700 | AAA0700 | 3700 | 700 | AAA0700
+ 3800 | 800 | AAA0800 | 3800 | 800 | AAA0800
+ 3900 | 900 | AAA0900 | 3900 | 900 | AAA0900
+(30 rows)
+
+DELETE FROM join_tbl;
+RESET enable_partitionwise_join;
+-- Test rescan of an async Append node with do_exec_prune=false
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: ((t1.a = t2.a) AND (t1.b = t2.b))
+ -> Foreign Scan on public.async_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t2_1
+ Output: t2_1.a, t2_1.b, t2_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t2_2
+ Output: t2_2.a, t2_2.b, t2_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+(16 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+(10 rows)
+
+DELETE FROM join_tbl;
+RESET enable_hashjoin;
+-- Test interaction of async execution with plan-time partition pruning
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 3000;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(7 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 2000;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Foreign Scan on public.async_p1 async_pt
+ Output: async_pt.a, async_pt.b, async_pt.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 2000))
+(3 rows)
+
+-- Test interaction of async execution with run-time partition pruning
+SET plan_cache_mode TO force_generic_plan;
+PREPARE async_pt_query (int, int) AS
+ INSERT INTO result_tbl SELECT * FROM async_pt WHERE a < $1 AND b === $2;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (3000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 1
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < $1::integer))
+(11 rows)
+
+EXECUTE async_pt_query (3000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (2000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 2
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+(7 rows)
+
+EXECUTE async_pt_query (2000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+(1 row)
+
+DELETE FROM result_tbl;
+RESET plan_cache_mode;
+CREATE TABLE local_tbl(a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo'), (2505, 505, 'bar');
+ANALYZE local_tbl;
+CREATE INDEX base_tbl1_idx ON base_tbl1 (a);
+CREATE INDEX base_tbl2_idx ON base_tbl2 (a);
+CREATE INDEX async_p3_idx ON async_p3 (a);
+ANALYZE base_tbl1;
+ANALYZE base_tbl2;
+ANALYZE async_p3;
+ALTER FOREIGN TABLE async_p1 OPTIONS (use_remote_estimate 'true');
+ALTER FOREIGN TABLE async_p2 OPTIONS (use_remote_estimate 'true');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: local_tbl.a, local_tbl.b, local_tbl.c, async_pt.a, async_pt.b, async_pt.c
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ Filter: (local_tbl.c = 'bar'::text)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a = $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a = $1::integer))
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.a = local_tbl.a)
+(15 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Nested Loop (actual rows=1 loops=1)
+ -> Seq Scan on local_tbl (actual rows=1 loops=1)
+ Filter: (c = 'bar'::text)
+ Rows Removed by Filter: 1
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (never executed)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=1 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (never executed)
+ Filter: (a = local_tbl.a)
+(9 rows)
+
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ a | b | c | a | b | c
+------+-----+-----+------+-----+------
+ 2505 | 505 | bar | 2505 | 505 | 0505
+(1 row)
+
+ALTER FOREIGN TABLE async_p1 OPTIONS (DROP use_remote_estimate);
+ALTER FOREIGN TABLE async_p2 OPTIONS (DROP use_remote_estimate);
+DROP TABLE local_tbl;
+DROP INDEX base_tbl1_idx;
+DROP INDEX base_tbl2_idx;
+DROP INDEX async_p3_idx;
+-- UNION queries
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> HashAggregate
+ Output: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ Group Key: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(11 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(8 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+-- Disable async execution if we use gating Result nodes for pseudoconstant
+-- quals
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Result
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+(18 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+(SELECT * FROM async_p1 WHERE CURRENT_USER = SESSION_USER)
+UNION ALL
+(SELECT * FROM async_p2 WHERE CURRENT_USER = SESSION_USER);
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(13 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ((SELECT * FROM async_p1 WHERE b < 10) UNION ALL (SELECT * FROM async_p2 WHERE b < 10)) s WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((b < 10))
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(13 rows)
+
+-- Test that pending requests are processed properly
+SET enable_mergejoin TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: (t1.a = t2.a)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+ -> Materialize
+ Output: t2.a, t2.b, t2.c
+ -> Foreign Scan on public.async_p2 t2
+ Output: t2.a, t2.b, t2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(20 rows)
+
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ a | b | c | a | b | c
+------+-----+------+------+-----+------
+ 2505 | 505 | 0505 | 2505 | 505 | 0505
+(1 row)
+
+CREATE TABLE local_tbl (a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo');
+ANALYZE local_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, async_pt.a, async_pt.b, async_pt.c, ($0)
+ Join Filter: (t1.a = async_pt.a)
+ InitPlan 1 (returns $0)
+ -> Aggregate
+ Output: count(*)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_4
+ Remote SQL: SELECT NULL FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_5
+ Remote SQL: SELECT NULL FROM public.base_tbl2 WHERE ((a < 3000))
+ -> Seq Scan on public.local_tbl t1
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(20 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Nested Loop Left Join (actual rows=1 loops=1)
+ Join Filter: (t1.a = async_pt.a)
+ Rows Removed by Join Filter: 399
+ InitPlan 1 (returns $0)
+ -> Aggregate (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_4 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_5 (actual rows=200 loops=1)
+ -> Seq Scan on local_tbl t1 (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=200 loops=1)
+(12 rows)
+
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ a | b | c | a | b | c | count
+------+-----+-----+------+-----+------+-------
+ 1505 | 505 | foo | 1505 | 505 | 0505 | 400
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+----------------------------------------------------------------
+ Limit
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+(14 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit (actual rows=1 loops=1)
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 t1_1 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Async Foreign Scan on async_p2 t1_2 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Seq Scan on async_p3 t1_3 (actual rows=1 loops=1)
+ Filter: (b === 505)
+ Rows Removed by Filter: 101
+(9 rows)
+
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ a | b | c
+------+-----+------
+ 3505 | 505 | 0505
+(1 row)
+
+-- Check with foreign modify
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE remote_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl3');
+INSERT INTO remote_tbl VALUES (2505, 505, 'bar');
+CREATE TABLE base_tbl4 (a int, b int, c text);
+CREATE FOREIGN TABLE insert_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl4');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Insert on public.insert_tbl
+ Remote SQL: INSERT INTO public.base_tbl4(a, b, c) VALUES ($1, $2, $3)
+ Batch Size: 1
+ -> Append
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ -> Async Foreign Scan on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(9 rows)
+
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+SELECT * FROM insert_tbl ORDER BY a;
+ a | b | c
+------+-----+-----
+ 1505 | 505 | foo
+ 2505 | 505 | bar
+(2 rows)
+
+-- Check with direct modify
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ CTE t
+ -> Update on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ -> Foreign Update on public.remote_tbl
+ Remote SQL: UPDATE public.base_tbl3 SET c = (c || c) RETURNING a, b, c
+ -> Nested Loop Left Join
+ Output: async_pt.a, async_pt.b, async_pt.c, t.a, t.b, t.c
+ Join Filter: ((async_pt.a = t.a) AND (async_pt.b = t.b))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ -> CTE Scan on t
+ Output: t.a, t.b, t.c
+(23 rows)
+
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+--------
+ 1505 | 505 | 0505 | | |
+ 2505 | 505 | 0505 | 2505 | 505 | barbar
+ 3505 | 505 | 0505 | | |
+(3 rows)
+
+DELETE FROM join_tbl;
+DROP TABLE local_tbl;
+DROP FOREIGN TABLE remote_tbl;
+DROP FOREIGN TABLE insert_tbl;
+DROP TABLE base_tbl3;
+DROP TABLE base_tbl4;
+RESET enable_mergejoin;
+RESET enable_hashjoin;
+-- Test that UPDATE/DELETE with inherited target works with async_capable enabled
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Update on public.async_p1 async_pt_1
+ Foreign Update on public.async_p2 async_pt_2
+ Update on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Update on public.async_p1 async_pt_1
+ Remote SQL: UPDATE public.base_tbl1 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Update on public.async_p2 async_pt_2
+ Remote SQL: UPDATE public.base_tbl2 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: (async_pt_3.c || async_pt_3.c), async_pt_3.tableoid, async_pt_3.ctid, NULL::record
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Delete on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Delete on public.async_p1 async_pt_1
+ Foreign Delete on public.async_p2 async_pt_2
+ Delete on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Delete on public.async_p1 async_pt_1
+ Remote SQL: DELETE FROM public.base_tbl1 WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Delete on public.async_p2 async_pt_2
+ Remote SQL: DELETE FROM public.base_tbl2 WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.tableoid, async_pt_3.ctid
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+-- Check EXPLAIN ANALYZE for a query that scans empty partitions asynchronously
+DELETE FROM async_p1;
+DELETE FROM async_p2;
+DELETE FROM async_p3;
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Append (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=0 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (actual rows=0 loops=1)
+(4 rows)
+
+-- Clean up
+DROP TABLE async_pt;
+DROP TABLE base_tbl1;
+DROP TABLE base_tbl2;
+DROP TABLE result_tbl;
+DROP TABLE join_tbl;
+-- Test that an asynchronous fetch is processed before restarting the scan in
+-- ReScanForeignScan
+CREATE TABLE base_tbl (a int, b int);
+INSERT INTO base_tbl VALUES (1, 11), (2, 22), (3, 33);
+CREATE FOREIGN TABLE foreign_tbl (b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE FOREIGN TABLE foreign_tbl2 () INHERITS (foreign_tbl)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Seq Scan on public.base_tbl
+ Output: base_tbl.a
+ Filter: (SubPlan 1)
+ SubPlan 1
+ -> Result
+ Output: base_tbl.a
+ -> Append
+ -> Async Foreign Scan on public.foreign_tbl foreign_tbl_1
+ Remote SQL: SELECT NULL FROM public.base_tbl
+ -> Async Foreign Scan on public.foreign_tbl2 foreign_tbl_2
+ Remote SQL: SELECT NULL FROM public.base_tbl
+(11 rows)
+
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ a
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+-- Clean up
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to foreign table foreign_tbl2
+DROP TABLE base_tbl;
+ALTER SERVER loopback OPTIONS (DROP async_capable);
+ALTER SERVER loopback2 OPTIONS (DROP async_capable);
+-- ===================================================================
+-- test invalid server, foreign table and foreign data wrapper options
+-- ===================================================================
+-- Invalid fdw_startup_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_startup_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_startup_cost": 100$%$#$#
+-- Invalid fdw_tuple_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_tuple_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_tuple_cost": 100$%$#$#
+-- Invalid fetch_size option
+CREATE FOREIGN TABLE inv_fsz (c1 int )
+ SERVER loopback OPTIONS (fetch_size '100$%$#$#');
+ERROR: invalid value for integer option "fetch_size": 100$%$#$#
+-- Invalid batch_size option
+CREATE FOREIGN TABLE inv_bsz (c1 int )
+ SERVER loopback OPTIONS (batch_size '100$%$#$#');
+ERROR: invalid value for integer option "batch_size": 100$%$#$#
+-- No option is allowed to be specified at foreign data wrapper level
+ALTER FOREIGN DATA WRAPPER postgres_fdw OPTIONS (nonexistent 'fdw');
+ERROR: invalid option "nonexistent"
+HINT: There are no valid options in this context.
+-- ===================================================================
+-- test postgres_fdw.application_name GUC
+-- ===================================================================
+--- Turn debug_discard_caches off for this test to make sure that
+--- the remote connection is alive when checking its application_name.
+SET debug_discard_caches = 0;
+-- Specify escape sequences in application_name option of a server
+-- object so as to test that they are replaced with status information
+-- expectedly.
+--
+-- Since pg_stat_activity.application_name may be truncated to less than
+-- NAMEDATALEN characters, note that substring() needs to be used
+-- at the condition of test query to make sure that the string consisting
+-- of database name and process ID is also less than that.
+ALTER SERVER loopback2 OPTIONS (application_name 'fdw_%d%p');
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_database() || pg_backend_pid() for
+ current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- postgres_fdw.application_name overrides application_name option
+-- of a server object if both settings are present.
+SET postgres_fdw.application_name TO 'fdw_%a%u%%';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('application_name') ||
+ CURRENT_USER || '%' for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- Test %c (session ID) and %C (cluster name) escape sequences.
+SET postgres_fdw.application_name TO 'fdw_%C%c';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('cluster_name') ||
+ to_hex(trunc(EXTRACT(EPOCH FROM (SELECT backend_start FROM
+ pg_stat_get_activity(pg_backend_pid()))))::integer) || '.' ||
+ to_hex(pg_backend_pid())
+ for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+--Clean up
+RESET postgres_fdw.application_name;
+RESET debug_discard_caches;
+-- ===================================================================
+-- test parallel commit
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (ADD parallel_commit 'true');
+ALTER SERVER loopback2 OPTIONS (ADD parallel_commit 'true');
+CREATE TABLE ploc1 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem1 (f1 int, f2 text)
+ SERVER loopback OPTIONS (table_name 'ploc1');
+CREATE TABLE ploc2 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem2 (f1 int, f2 text)
+ SERVER loopback2 OPTIONS (table_name 'ploc2');
+BEGIN;
+INSERT INTO prem1 VALUES (101, 'foo');
+INSERT INTO prem2 VALUES (201, 'bar');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+-----
+ 101 | foo
+(1 row)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+-----
+ 201 | bar
+(1 row)
+
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (102, 'foofoo');
+INSERT INTO prem2 VALUES (202, 'barbar');
+RELEASE SAVEPOINT s;
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+(2 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+(2 rows)
+
+-- This tests executing DEALLOCATE ALL against foreign servers in parallel
+-- during pre-commit
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (103, 'baz');
+INSERT INTO prem2 VALUES (203, 'qux');
+ROLLBACK TO SAVEPOINT s;
+RELEASE SAVEPOINT s;
+INSERT INTO prem1 VALUES (104, 'bazbaz');
+INSERT INTO prem2 VALUES (204, 'quxqux');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+ 104 | bazbaz
+(3 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+ 204 | quxqux
+(3 rows)
+
+ALTER SERVER loopback OPTIONS (DROP parallel_commit);
+ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT postgres_fdw_verify_foreign_servers(false); -- should fail on supported platform
+WARNING: 08006
+ERROR: 08006
+\set VERBOSITY default
+COMMIT;
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/expected/postgres_fdw_2.out b/contrib/postgres_fdw/expected/postgres_fdw_2.out
new file mode 100644
index 0000000000..96576d09f5
--- /dev/null
+++ b/contrib/postgres_fdw/expected/postgres_fdw_2.out
@@ -0,0 +1,11622 @@
+-- ===================================================================
+-- create FDW objects
+-- ===================================================================
+CREATE EXTENSION postgres_fdw;
+CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw;
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback2 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback3 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+CREATE USER MAPPING FOR public SERVER testserver1
+ OPTIONS (user 'value', password 'value');
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback2;
+CREATE USER MAPPING FOR public SERVER loopback3;
+-- ===================================================================
+-- create objects used through FDW loopback server
+-- ===================================================================
+CREATE TYPE user_enum AS ENUM ('foo', 'bar', 'buz');
+CREATE SCHEMA "S 1";
+CREATE TABLE "S 1"."T 1" (
+ "C 1" int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10),
+ c8 user_enum,
+ CONSTRAINT t1_pkey PRIMARY KEY ("C 1")
+);
+CREATE TABLE "S 1"."T 2" (
+ c1 int NOT NULL,
+ c2 text,
+ CONSTRAINT t2_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 3" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t3_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 4" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t4_pkey PRIMARY KEY (c1)
+);
+-- Disable autovacuum for these tables to avoid unexpected effects of that
+ALTER TABLE "S 1"."T 1" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 2" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 3" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 4" SET (autovacuum_enabled = 'false');
+INSERT INTO "S 1"."T 1"
+ SELECT id,
+ id % 10,
+ to_char(id, 'FM00000'),
+ '1970-01-01'::timestamptz + ((id % 100) || ' days')::interval,
+ '1970-01-01'::timestamp + ((id % 100) || ' days')::interval,
+ id % 10,
+ id % 10,
+ 'foo'::user_enum
+ FROM generate_series(1, 1000) id;
+INSERT INTO "S 1"."T 2"
+ SELECT id,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+INSERT INTO "S 1"."T 3"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 3" WHERE c1 % 2 != 0; -- delete for outer join tests
+INSERT INTO "S 1"."T 4"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests
+ANALYZE "S 1"."T 1";
+ANALYZE "S 1"."T 2";
+ANALYZE "S 1"."T 3";
+ANALYZE "S 1"."T 4";
+-- ===================================================================
+-- create foreign tables
+-- ===================================================================
+CREATE FOREIGN TABLE ft1 (
+ c0 int,
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft1 DROP COLUMN c0;
+CREATE FOREIGN TABLE ft2 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ cx int,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft2',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft2 DROP COLUMN cx;
+CREATE FOREIGN TABLE ft4 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 3');
+CREATE FOREIGN TABLE ft5 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft6 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback2 OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft7 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback3 OPTIONS (schema_name 'S 1', table_name 'T 4');
+-- ===================================================================
+-- tests for validator
+-- ===================================================================
+-- requiressl and some other parameters are omitted because
+-- valid values for them depend on configure options
+ALTER SERVER testserver1 OPTIONS (
+ use_remote_estimate 'false',
+ updatable 'true',
+ fdw_startup_cost '123.456',
+ fdw_tuple_cost '0.123',
+ service 'value',
+ connect_timeout 'value',
+ dbname 'value',
+ host 'value',
+ hostaddr 'value',
+ port 'value',
+ --client_encoding 'value',
+ application_name 'value',
+ --fallback_application_name 'value',
+ keepalives 'value',
+ keepalives_idle 'value',
+ keepalives_interval 'value',
+ tcp_user_timeout 'value',
+ -- requiressl 'value',
+ sslcompression 'value',
+ sslmode 'value',
+ sslcert 'value',
+ sslkey 'value',
+ sslrootcert 'value',
+ sslcrl 'value',
+ --requirepeer 'value',
+ krbsrvname 'value',
+ gsslib 'value'
+ --replication 'value'
+);
+-- Error, invalid list syntax
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo; bar');
+ERROR: parameter "extensions" must be a list of extension names
+-- OK but gets a warning
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo, bar');
+WARNING: extension "foo" is not installed
+WARNING: extension "bar" is not installed
+ALTER SERVER testserver1 OPTIONS (DROP extensions);
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (DROP user, DROP password);
+-- Attempt to add a valid option that's not allowed in a user mapping
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslmode 'require');
+ERROR: invalid option "sslmode"
+-- But we can add valid ones fine
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslpassword 'dummy');
+-- Ensure valid options we haven't used in a user mapping yet are
+-- permitted to check validation.
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslkey 'value', ADD sslcert 'value');
+ALTER FOREIGN TABLE ft1 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft2 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+ALTER FOREIGN TABLE ft2 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+\det+
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------+-------+-----------+---------------------------------------+-------------
+ public | ft1 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft2 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft4 | loopback | (schema_name 'S 1', table_name 'T 3') |
+ public | ft5 | loopback | (schema_name 'S 1', table_name 'T 4') |
+ public | ft6 | loopback2 | (schema_name 'S 1', table_name 'T 4') |
+ public | ft7 | loopback3 | (schema_name 'S 1', table_name 'T 4') |
+(6 rows)
+
+-- Test that alteration of server options causes reconnection
+-- Remote's errors might be non-English, so hide them to ensure stable results
+\set VERBOSITY terse
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET dbname 'no such database');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+DO $d$
+ BEGIN
+ EXECUTE $$ALTER SERVER loopback
+ OPTIONS (SET dbname '$$||current_database()||$$')$$;
+ END;
+$d$;
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+-- Test that alteration of user mapping options causes reconnection
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (ADD user 'no such user');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (DROP user);
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+\set VERBOSITY default
+-- Now we should be able to run ANALYZE.
+-- To exercise multiple code paths, we use local stats on ft1
+-- and remote-estimate mode on ft2.
+ANALYZE ft1;
+ALTER FOREIGN TABLE ft2 OPTIONS (use_remote_estimate 'true');
+-- ===================================================================
+-- test error case for create publication on foreign table
+-- ===================================================================
+CREATE PUBLICATION testpub_ftbl FOR TABLE ft1; -- should fail
+ERROR: cannot add relation "ft1" to publication
+DETAIL: This operation is not supported for foreign tables.
+-- ===================================================================
+-- simple queries
+-- ===================================================================
+-- single table without alias
+EXPLAIN (COSTS OFF) SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------
+ Foreign Scan on ft1
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- single table with alias - also test that tableoid sort is not pushed to remote side
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ -> Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Sort Key: t1.c3, t1.c1, t1.tableoid
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(8 rows)
+
+SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF) SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: t1.*, c3, c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c3 ASC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(3 rows)
+
+SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ t1
+--------------------------------------------------------------------------------------------
+ (101,1,00101,"Fri Jan 02 00:00:00 1970 PST","Fri Jan 02 00:00:00 1970",1,"1 ",foo)
+ (102,2,00102,"Sat Jan 03 00:00:00 1970 PST","Sat Jan 03 00:00:00 1970",2,"2 ",foo)
+ (103,3,00103,"Sun Jan 04 00:00:00 1970 PST","Sun Jan 04 00:00:00 1970",3,"3 ",foo)
+ (104,4,00104,"Mon Jan 05 00:00:00 1970 PST","Mon Jan 05 00:00:00 1970",4,"4 ",foo)
+ (105,5,00105,"Tue Jan 06 00:00:00 1970 PST","Tue Jan 06 00:00:00 1970",5,"5 ",foo)
+ (106,6,00106,"Wed Jan 07 00:00:00 1970 PST","Wed Jan 07 00:00:00 1970",6,"6 ",foo)
+ (107,7,00107,"Thu Jan 08 00:00:00 1970 PST","Thu Jan 08 00:00:00 1970",7,"7 ",foo)
+ (108,8,00108,"Fri Jan 09 00:00:00 1970 PST","Fri Jan 09 00:00:00 1970",8,"8 ",foo)
+ (109,9,00109,"Sat Jan 10 00:00:00 1970 PST","Sat Jan 10 00:00:00 1970",9,"9 ",foo)
+ (110,0,00110,"Sun Jan 11 00:00:00 1970 PST","Sun Jan 11 00:00:00 1970",0,"0 ",foo)
+(10 rows)
+
+-- empty result
+SELECT * FROM ft1 WHERE false;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- with WHERE clause
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c7 >= '1')) AND (("C 1" = 101)) AND ((c6 = '1'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- with FOR UPDATE/SHARE
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 101)) FOR UPDATE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 102)) FOR SHARE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+-- aggregate
+SELECT COUNT(*) FROM ft1 t1;
+ count
+-------
+ 1000
+(1 row)
+
+-- subquery
+SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- subquery+MAX
+SELECT * FROM ft1 t1 WHERE t1.c3 = (SELECT MAX(c3) FROM ft2 t2) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+(1 row)
+
+-- used in CTE
+WITH t1 AS (SELECT * FROM ft1 WHERE c1 <= 10) SELECT t2.c1, t2.c2, t2.c3, t2.c4 FROM t1, ft2 t2 WHERE t1.c1 = t2.c1 ORDER BY t1.c1;
+ c1 | c2 | c3 | c4
+----+----+-------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+(10 rows)
+
+-- fixed values
+SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1;
+ ?column? | ?column?
+----------+----------
+ fixed |
+(1 row)
+
+-- Test forcing the remote server to produce sorted data for a merge join.
+SET enable_hashjoin TO false;
+SET enable_nestloop TO false;
+-- inner join; expressions in the clauses appear in the equivalence class list
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Left Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- A join between local table and foreign join. ORDER BY clause is added to the
+-- foreign join so that the local table can be joined using merge join strategy.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Merge Right Join
+ Output: t1."C 1"
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r3."C 1" FROM ("S 1"."T 1" r2 INNER JOIN "S 1"."T 1" r3 ON (((r3."C 1" = r2."C 1")))) ORDER BY r2."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- Test similar to above, except that the full join prevents any equivalence
+-- classes from being merged. This produces single relation equivalence classes
+-- included in join restrictions.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Right Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1, t2.c1
+ Relations: (public.ft2 t3) LEFT JOIN (public.ft1 t2)
+ Remote SQL: SELECT r3."C 1", r2."C 1" FROM ("S 1"."T 1" r3 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+-- Test similar to above with all full outer joins
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Full Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) FULL JOIN (public.ft2 t3)
+ Remote SQL: SELECT r2."C 1", r3."C 1" FROM ("S 1"."T 1" r2 FULL JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test executing assertion in estimate_path_cost_size() that makes sure that
+-- retrieved_rows for foreign rel re-used to cost pre-sorted foreign paths is
+-- a sensible value even when the rel has tuples=0
+CREATE TABLE loct_empty (c1 int NOT NULL, c2 text);
+CREATE FOREIGN TABLE ft_empty (c1 int NOT NULL, c2 text)
+ SERVER loopback OPTIONS (table_name 'loct_empty');
+INSERT INTO loct_empty
+ SELECT id, 'AAA' || to_char(id, 'FM000') FROM generate_series(1, 100) id;
+DELETE FROM loct_empty;
+ANALYZE ft_empty;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Foreign Scan on public.ft_empty
+ Output: c1, c2
+ Remote SQL: SELECT c1, c2 FROM public.loct_empty ORDER BY c1 ASC NULLS LAST
+(3 rows)
+
+-- ===================================================================
+-- WHERE with remotely-executable conditions
+-- ===================================================================
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1; -- Var, OpExpr(b), Const
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL; -- NullTest
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL; -- NullTest
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((round(abs("C 1"), 0) = 1::numeric))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1; -- OpExpr(l)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = (- "C 1")))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" IS NOT NULL) IS DISTINCT FROM ("C 1" IS NOT NULL)))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]); -- ScalarArrayOpExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ANY (ARRAY[c2, 1, ("C 1" + 0)])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1]; -- SubscriptingRef
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ((ARRAY["C 1", c2, 3])[1])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar'; -- check special chars
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c6 = E'foo''s\\bar'))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c8 = 'foo'; -- can't be sent to remote
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- parameterized remote path for foreign table
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM "S 1"."T 1" a, ft2 b WHERE a."C 1" = 47 AND b.c1 = a.c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Index Scan using t1_pkey on "S 1"."T 1" a
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Index Cond: (a."C 1" = 47)
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(8 rows)
+
+SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 47 | 7 | 00047 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo | 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+(1 row)
+
+-- check both safe and unsafe join conditions
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 a, ft2 b
+ WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Foreign Scan on public.ft2 a
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Filter: (a.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c2 = 6))
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Filter: ((b.c7)::text = upper((a.c7)::text))
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(10 rows)
+
+SELECT * FROM ft2 a, ft2 b
+WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+(100 rows)
+
+-- bug before 9.3.5 due to sloppy handling of remote-estimate parameters
+SELECT * FROM ft1 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft2 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+SELECT * FROM ft2 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft1 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+-- we should not push order by clause with volatile expressions or unsafe
+-- collations
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, random();
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, (random())
+ Sort Key: ft2.c1, (random())
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, random()
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, ft2.c3 collate "C";
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, ((c3)::text)
+ Sort Key: ft2.c1, ft2.c3 COLLATE "C"
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- user-defined operator/function
+CREATE FUNCTION postgres_fdw_abs(int) RETURNS int AS $$
+BEGIN
+RETURN abs($1);
+END
+$$ LANGUAGE plpgsql IMMUTABLE;
+CREATE OPERATOR === (
+ LEFTARG = int,
+ RIGHTARG = int,
+ PROCEDURE = int4eq,
+ COMMUTATOR = ===
+);
+-- built-in operators and functions can be shipped for remote execution
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ QUERY PLAN
+----------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- by default, user-defined ones cannot
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 = postgres_fdw_abs(t1.c2))
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- ORDER BY can be shipped, though
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- but let's put them in an extension ...
+ALTER EXTENSION postgres_fdw ADD FUNCTION postgres_fdw_abs(int);
+ALTER EXTENSION postgres_fdw ADD OPERATOR === (int, int);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- ... now they can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- and both ORDER BY and LIMIT can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2)) ORDER BY c2 ASC NULLS LAST LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- Test CASE pushdown
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE WHEN ("C 1" > 990) THEN "C 1" ELSE NULL::integer END) < 1000)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ c1 | c2 | c3
+-----+----+-------
+ 991 | 1 | 00991
+ 992 | 2 | 00992
+ 993 | 3 | 00993
+ 994 | 4 | 00994
+ 995 | 5 | 00995
+ 996 | 6 | 00996
+ 997 | 7 | 00997
+ 998 | 8 | 00998
+ 999 | 9 | 00999
+(9 rows)
+
+-- Nested CASE
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE (CASE WHEN (c2 > 0) THEN c2 ELSE NULL::integer END) WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END) > 600)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ c1 | c2 | c3
+----+----+----
+(0 rows)
+
+-- CASE arg WHEN
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE mod(c1, 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" > (CASE mod("C 1", 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)))
+(3 rows)
+
+-- CASE cannot be pushed down because of unshippable arg clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE random()::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (ft1.c1 > CASE (random())::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- these are shippable
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c6 WHEN 'foo' THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c6 WHEN 'foo'::text THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c3 WHEN c6 THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+-- but this is not because of collation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 COLLATE "C" WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: CASE (ft1.c3)::text WHEN ft1.c6 THEN true ELSE (ft1.c3 < 'bar'::text) END
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- a regconfig constant referring to this text search configuration
+-- is initially unshippable
+CREATE TEXT SEARCH CONFIGURATION public.custom_search
+ (COPY = pg_catalog.english);
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Filter: (length(to_tsvector('custom_search'::regconfig, ft1.c3)) > 0)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642))
+(4 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- but if it's in a shippable extension, it can be shipped
+ALTER EXTENSION postgres_fdw ADD TEXT SEARCH CONFIGURATION public.custom_search;
+-- however, that doesn't flush the shippability cache, so do a quick reconnect
+\c -
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642)) AND ((length(to_tsvector('public.custom_search'::regconfig, c3)) > 0))
+(3 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- ===================================================================
+-- JOIN queries
+-- ===================================================================
+-- Analyze ft4 and ft5 so that we have better statistics. These tables do not
+-- have use_remote_estimate set.
+ANALYZE ft4;
+ANALYZE ft5;
+-- join two tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3, t1.c3
+ Relations: ((public.ft1 t1) INNER JOIN (public.ft2 t2)) INNER JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3, r1.c3 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) INNER JOIN "S 1"."T 3" r4 ON (((r1."C 1" = r4.c1)))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 22 |
+ 24 | 24
+ 26 |
+ 28 |
+ 30 | 30
+ 32 |
+ 34 |
+ 36 | 36
+ 38 |
+ 40 |
+(10 rows)
+
+-- left outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + placement of clauses.
+-- clauses within the nullable side are not pulled up, but top level clause on
+-- non-nullable side is pushed into non-nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- clauses within the nullable side are not pulled up, but the top level clause
+-- on nullable side is not pushed down into nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE (((r4.c1 < 10) OR (r4.c1 IS NULL))) AND ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t2) LEFT JOIN (public.ft5 t1)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r1 ON (((r1.c1 = r2.c1)))) ORDER BY r2.c1 ASC NULLS LAST, r1.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ | 22
+ 24 | 24
+ | 26
+ | 28
+ 30 | 30
+ | 32
+ | 34
+ 36 | 36
+ | 38
+ | 40
+(10 rows)
+
+-- right outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 45::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ c1 | c1
+-----+----
+ 92 |
+ 94 |
+ 96 | 96
+ 98 |
+ 100 |
+ | 3
+ | 9
+ | 15
+ | 21
+ | 27
+(10 rows)
+
+-- full outer join with restrictions on the joining relations
+-- a. the joining relations are both base relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s4.c1, s5.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s5.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ c1 | c1
+----+----
+ 50 |
+ 52 |
+ 54 | 54
+ 56 |
+ 58 |
+ 60 | 60
+ | 51
+ | 57
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: 1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT NULL FROM ((SELECT NULL FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4 FULL JOIN (SELECT NULL FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5 ON (TRUE)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ ?column?
+----------
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- b. one of the joining relations is a base relation and the other is a join
+-- relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c1, t3.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 t2) LEFT JOIN (public.ft5 t3))
+ Remote SQL: SELECT s4.c1, s8.c1, s8.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT r5.c1, r6.c1 FROM ("S 1"."T 3" r5 LEFT JOIN "S 1"."T 4" r6 ON (((r5.c1 = r6.c1)))) WHERE ((r5.c1 >= 50)) AND ((r5.c1 <= 60))) s8(c1, c2) ON (((s4.c1 = s8.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s8.c1 ASC NULLS LAST, s8.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+(6 rows)
+
+-- c. test deparsing the remote query as nested subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft4_1.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 ft4_1) FULL JOIN (public.ft5))
+ Remote SQL: SELECT s4.c1, s10.c1, s10.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT s8.c1, s9.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL)))) s10(c1, c2) ON (((s4.c1 = s10.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s10.c1 ASC NULLS LAST, s10.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+ | | 51
+ | | 57
+(8 rows)
+
+-- d. test deparsing rowmarked relations as subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Nested Loop
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Foreign Scan
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s8.c1, s8.c2, s9.c1, s9.c2 FROM ((SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1, c2) FULL JOIN (SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1, c2) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL))) ORDER BY s8.c1 ASC NULLS LAST, s9.c1 ASC NULLS LAST
+ -> Sort
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Full Join
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Hash Cond: (ft4.c1 = ft5.c1)
+ Filter: ((ft4.c1 IS NULL) OR (ft4.c1 IS NOT NULL))
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Hash
+ Output: ft5.c1, ft5.*
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Materialize
+ Output: "T 3".c1, "T 3".ctid
+ -> Seq Scan on "S 1"."T 3"
+ Output: "T 3".c1, "T 3".ctid
+ Filter: ("T 3".c1 = 50)
+(28 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 50 | 52 |
+ 50 | 54 | 54
+ 50 | 56 |
+ 50 | 58 |
+ 50 | 60 | 60
+ 50 | | 51
+ 50 | | 57
+(8 rows)
+
+-- full outer join + inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t3.c1
+ Relations: ((public.ft4 t1) INNER JOIN (public.ft5 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1.c1, r2.c1, r4.c1 FROM (("S 1"."T 3" r1 INNER JOIN "S 1"."T 4" r2 ON (((r1.c1 = (r2.c1 + 1))) AND ((r1.c1 >= 50)) AND ((r1.c1 <= 60)))) FULL JOIN "S 1"."T 3" r4 ON (((r2.c1 = r4.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST, r4.c1 ASC NULLS LAST LIMIT 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ c1 | c1 | c1
+----+----+----
+ 52 | 51 |
+ 58 | 57 |
+ | | 2
+ | | 4
+ | | 6
+ | | 8
+ | | 10
+ | | 12
+ | | 14
+ | | 16
+(10 rows)
+
+-- full outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- right outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+SET enable_memoize TO off;
+-- right outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+RESET enable_memoize;
+-- left outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: (public.ft4 t3) LEFT JOIN ((public.ft2 t1) INNER JOIN (public.ft2 t2))
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM ("S 1"."T 3" r4 LEFT JOIN ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join + WHERE clause, only matched rows
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 = r2.c1) OR (r1.c1 IS NULL)))
+(9 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 66 | 66
+ 72 | 72
+ 78 | 78
+ 84 | 84
+ 90 | 90
+ 96 | 96
+ | 3
+ | 9
+ | 15
+ | 21
+(10 rows)
+
+-- full outer join + WHERE clause with shippable extensions set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) WHERE ((public.postgres_fdw_abs(r1."C 1") > 0)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+-- full outer join + WHERE clause with shippable extensions not set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c2, t1.c3
+ -> Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Filter: (postgres_fdw_abs(t1.c1) > 0)
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- join two tables with FOR UPDATE clause
+-- tests whole-row reference for row marks
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1 FOR UPDATE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join two tables with FOR SHARE clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1 FOR SHARE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join in CTE
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t.c1_1, t.c2_1, t.c1_3
+ CTE t
+ -> Foreign Scan
+ Output: t1.c1, t1.c3, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r1.c3, r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+ -> Sort
+ Output: t.c1_1, t.c2_1, t.c1_3
+ Sort Key: t.c1_3, t.c1_1
+ -> CTE Scan on t
+ Output: t.c1_1, t.c2_1, t.c1_3
+(12 rows)
+
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ c1_1 | c2_1
+------+------
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- ctid with whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.ctid, t1.*, t2.*, t1.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r1."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+-- SEMI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Semi Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c1)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- ANTI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Anti Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c2)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 110
+ 111
+ 112
+ 113
+ 114
+ 115
+ 116
+ 117
+ 118
+ 119
+(10 rows)
+
+-- CROSS JOIN can be pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (TRUE)) ORDER BY r1."C 1" ASC NULLS LAST, r2."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- different server, not pushed down. No result expected.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Merge Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft6 t2
+ Output: t2.c1, t2.c2, t2.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+ -> Materialize
+ Output: t1.c1, t1.c2, t1.c3
+ -> Foreign Scan on public.ft5 t1
+ Output: t1.c1, t1.c2, t1.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+(13 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+----
+(0 rows)
+
+-- unsafe join conditions (c8 has a UDT), not pushed down. Practically a CROSS
+-- JOIN since c8 in both tables has same value.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Merge Left Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t1.c8 = t2.c8)
+ -> Sort
+ Output: t1.c1, t1.c8
+ Sort Key: t1.c8
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+ -> Sort
+ Output: t2.c1, t2.c8
+ Sort Key: t2.c8
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1, t2.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+(20 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- unsafe conditions on one side (c8 has a UDT), not pushed down.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Hash Right Join
+ Output: t1.c1, t2.c1, t1.c3
+ Hash Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+ -> Hash
+ Output: t1.c1, t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c3
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c3, c8 FROM "S 1"."T 1"
+(17 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join where unsafe to pushdown condition in WHERE clause has a column not
+-- in the SELECT clause. In this test unsafe clause needs to have column
+-- references from both joining sides so that the clause is not pushed down
+-- into one of the joining sides.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Filter: (t1.c8 = t2.c8)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, r1.c8, r2.c8 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(10 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- Aggregate after UNION, for testing setrefs
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ -> Sort
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ Sort Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, avg((t1.c1 + t2.c1))
+ Group Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, t2.c1
+ Group Key: t1.c1, t2.c1
+ -> Append
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+ -> Foreign Scan
+ Output: t1_1.c1, t2_1.c1
+ Relations: (public.ft1 t1_1) INNER JOIN (public.ft2 t2_1)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(20 rows)
+
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ t1c1 | avg
+------+----------------------
+ 101 | 202.0000000000000000
+ 102 | 204.0000000000000000
+ 103 | 206.0000000000000000
+ 104 | 208.0000000000000000
+ 105 | 210.0000000000000000
+ 106 | 212.0000000000000000
+ 107 | 214.0000000000000000
+ 108 | 216.0000000000000000
+ 109 | 218.0000000000000000
+ 110 | 220.0000000000000000
+(10 rows)
+
+-- join with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Nested Loop
+ Output: t1."C 1"
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ -> Memoize
+ Cache Key: t1.c2
+ Cache Mode: binary
+ -> Subquery Scan on q
+ -> HashAggregate
+ Output: t2.c1, t3.c1
+ Group Key: t2.c1, t3.c1
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")) AND ((r1.c2 = $1::integer))))
+(17 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ C 1
+-----
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- non-Var items in targetlist of the nullable rel of a join preventing
+-- push-down in some cases
+-- unable to push {ft1, ft2}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: (13), ft2.c1
+ Join Filter: (13 = ft2.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" WHERE (("C 1" >= 10)) AND (("C 1" <= 15)) ORDER BY "C 1" ASC NULLS LAST
+ -> Materialize
+ Output: (13)
+ -> Foreign Scan on public.ft1
+ Output: 13
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 13))
+(11 rows)
+
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ a | c1
+----+----
+ | 10
+ | 11
+ | 12
+ 13 | 13
+ | 14
+ | 15
+(6 rows)
+
+-- ok to push {ft1, ft2} but not {ft1, ft2, ft4}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: ft4.c1, (13), ft1.c1, ft2.c1
+ Join Filter: (ft4.c1 = ft1.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
+ -> Materialize
+ Output: ft1.c1, ft2.c1, (13)
+ -> Foreign Scan
+ Output: ft1.c1, ft2.c1, 13
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r5."C 1" FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = 12)) AND ((r4."C 1" = 12)))) ORDER BY r4."C 1" ASC NULLS LAST
+(12 rows)
+
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ c1 | a | b | c
+----+----+----+----
+ 10 | | |
+ 12 | 13 | 12 | 12
+ 14 | | |
+(3 rows)
+
+-- join with nullable side with some columns with null values
+UPDATE ft5 SET c3 = null where c1 % 9 = 0;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2
+ Relations: (public.ft5) INNER JOIN (public.ft4)
+ Remote SQL: SELECT CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1.c1, r1.c2, r1.c3) END, r1.c1, r1.c2, r1.c3, r2.c1, r2.c2 FROM ("S 1"."T 4" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c1 = r2.c1)) AND ((r2.c1 >= 10)) AND ((r2.c1 <= 30)))) ORDER BY r1.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ ft5 | c1 | c2 | c3 | c1 | c2
+----------------+----+----+--------+----+----
+ (12,13,AAA012) | 12 | 13 | AAA012 | 12 | 13
+ (18,19,) | 18 | 19 | | 18 | 19
+ (24,25,AAA024) | 24 | 25 | AAA024 | 24 | 25
+ (30,31,AAA030) | 30 | 31 | AAA030 | 30 | 31
+(4 rows)
+
+-- multi-way join involving multiple merge joins
+-- (this case used to have EPQ-related planning problems)
+CREATE TABLE local_tbl (c1 int NOT NULL, c2 int NOT NULL, c3 text, CONSTRAINT local_tbl_pkey PRIMARY KEY (c1));
+INSERT INTO local_tbl SELECT id, id % 10, to_char(id, 'FM0000') FROM generate_series(1, 1000) id;
+ANALYZE local_tbl;
+SET enable_nestloop TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ Inner Unique: true
+ Merge Cond: (ft1.c2 = local_tbl.c1)
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Relations: (((public.ft1) INNER JOIN (public.ft2)) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r3.c1, r3.c2, r3.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r4.c1, r4.c2, r4.c3, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4.c1, r4.c2, r4.c3) END FROM ((("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")) AND ((r2."C 1" < 100)) AND ((r1."C 1" < 100)))) INNER JOIN "S 1"."T 3" r3 ON (((r1.c2 = r3.c1)))) INNER JOIN "S 1"."T 4" r4 ON (((r1.c2 = r4.c1)))) ORDER BY r1.c2 ASC NULLS LAST FOR UPDATE OF r1 FOR UPDATE OF r2 FOR UPDATE OF r3 FOR UPDATE OF r4
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Merge Cond: (ft1.c2 = ft5.c1)
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Merge Cond: (ft1.c2 = ft4.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Sort Key: ft1.c2
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Merge Cond: (ft1.c1 = ft2.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) FOR UPDATE
+ -> Materialize
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Sort
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Sort Key: ft4.c1
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" FOR UPDATE
+ -> Sort
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Sort Key: ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" FOR UPDATE
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+(47 rows)
+
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3 | c1 | c2 | c3
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+--------+----+----+--------+----+----+------
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+(10 rows)
+
+RESET enable_nestloop;
+RESET enable_hashjoin;
+-- test that add_paths_with_pathkeys_for_rel() arranges for the epq_path to
+-- return columns needed by the parent ForeignScan node
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.*, COALESCE(ft1.c3 || ft2.c3, 'foobar') FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100)) ss ON (local_tbl.c1 = ss.c1) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ -> Merge Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ Merge Cond: (local_tbl.c1 = ft1.c1)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text))
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c3 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = r4."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4."C 1" ASC NULLS LAST
+ -> Result
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c3
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), ft2.c3
+ Sort Key: ft1.c1
+ -> Hash Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text), ft2.c3
+ Hash Cond: (ft1.c1 = ft2.c1)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Hash
+ Output: ft2.*, ft2.c1, ft2.c3
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(29 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD fdw_startup_cost '10000.0');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.* FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100 AND ft1.c1 = postgres_fdw_abs(ft2.c2))) ss ON (local_tbl.c3 = ss.c3) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ -> Nested Loop Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ Join Filter: (local_tbl.c3 = ft1.c3)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ Filter: (ft1.c1 = postgres_fdw_abs(ft2.c2))
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c2 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = r4."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4.c3 ASC NULLS LAST
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Sort Key: ft1.c3
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Merge Cond: ((ft1.c1 = (postgres_fdw_abs(ft2.c2))) AND (ft1.c1 = ft2.c1))
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Sort
+ Output: ft2.*, ft2.c1, ft2.c2, (postgres_fdw_abs(ft2.c2))
+ Sort Key: (postgres_fdw_abs(ft2.c2)), ft2.c1
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, postgres_fdw_abs(ft2.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(32 rows)
+
+ALTER SERVER loopback OPTIONS (DROP fdw_startup_cost);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+DROP TABLE local_tbl;
+-- check join pushdown in situations where multiple userids are involved
+CREATE ROLE regress_view_owner SUPERUSER;
+CREATE USER MAPPING FOR regress_view_owner SERVER loopback;
+GRANT SELECT ON ft4 TO regress_view_owner;
+GRANT SELECT ON ft5 TO regress_view_owner;
+CREATE VIEW v4 AS SELECT * FROM ft4;
+CREATE VIEW v5 AS SELECT * FROM ft5;
+ALTER VIEW v5 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, different view owners
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, ft5.c2, ft5.c1
+ -> Sort
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Left Join
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.c2, ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c2, ft5.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r6.c1, r9.c2, r9.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r9 ON (((r6.c1 = r9.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r9.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, view owner not current user
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, t2.c2, t2.c1
+ -> Sort
+ Output: ft4.c1, t2.c2, t2.c1
+ Sort Key: ft4.c1, t2.c1
+ -> Hash Left Join
+ Output: ft4.c1, t2.c2, t2.c1
+ Hash Cond: (ft4.c1 = t2.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: t2.c2, t2.c1
+ -> Foreign Scan on public.ft5 t2
+ Output: t2.c2, t2.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO CURRENT_USER;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c2, t2.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r6.c1, r2.c2, r2.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r2 ON (((r6.c1 = r2.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+-- cleanup
+DROP OWNED BY regress_view_owner;
+DROP ROLE regress_view_owner;
+-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+------+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+ 100 | 49700 | 497.0000000000000000 | 2 | 992 | 0 | 49700
+ 100 | 49800 | 498.0000000000000000 | 3 | 993 | 0 | 49800
+ 100 | 49900 | 499.0000000000000000 | 4 | 994 | 0 | 49900
+ 100 | 50500 | 505.0000000000000000 | 0 | 1000 | 0 | 50500
+(5 rows)
+
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST LIMIT 1::bigint
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+-----+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+(1 row)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * (random() <= 1)::int) as sum, avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Aggregate
+ Output: sum((c1 * ((random() <= '1'::double precision))::integer)), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT count(*), sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ count | sum | avg
+-------+---------+----------------------
+ 10000 | 5010000 | 501.0000000000000000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where ((t1.c1 * t2.c1)/(t1.c1 * t2.c1)) * random() <= 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(t1.c1), count(t2.c1)
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Filter: (((((t1.c1 * t2.c1) / (t1.c1 * t2.c1)))::double precision * random()) <= '1'::double precision)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(7 rows)
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY 1 ORDER BY (c2 / 2) ASC NULLS LAST
+(4 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 500
+ 2 | 1800
+ 3 | 3900
+ 4 | 6800
+(5 rows)
+
+-- Aggregates in subquery are pushed down.
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 ORDER BY c2 ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(6 rows)
+
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+------
+ 1000 | 4500
+(1 row)
+
+-- Aggregate is still pushed down by taking unshippable expression out
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer)), ((sum(c1) * c2)), c2
+ Sort Key: ((ft1.c2 * ((random() <= '1'::double precision))::integer)), ((sum(ft1.c1) * ft1.c2))
+ -> Foreign Scan
+ Output: (c2 * ((random() <= '1'::double precision))::integer), ((sum(c1) * c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum("C 1") * c2), c2 FROM "S 1"."T 1" GROUP BY 2
+(7 rows)
+
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ sum1 | sum2
+------+--------
+ 0 | 0
+ 1 | 49600
+ 2 | 99400
+ 3 | 149400
+ 4 | 199600
+ 5 | 250000
+ 6 | 300600
+ 7 | 351400
+ 8 | 402400
+ 9 | 453600
+(10 rows)
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::int order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Sort Key: ((ft2.c2 * ((random() <= '1'::double precision))::integer))
+ -> HashAggregate
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Group Key: (ft2.c2 * ((random() <= '1'::double precision))::integer)
+ -> Foreign Scan on public.ft2
+ Output: (c2 * ((random() <= '1'::double precision))::integer)
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- GROUP BY clause in various forms, cardinal, alias and constant expression
+explain (verbose, costs off)
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), c2, 5, 7.0, 9 FROM "S 1"."T 1" GROUP BY 2, 3, 5
+(7 rows)
+
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ w | x | y | z
+-----+---+---+-----
+ 100 | 0 | 5 | 7.0
+ 100 | 1 | 5 | 7.0
+ 100 | 2 | 5 | 7.0
+ 100 | 3 | 5 | 7.0
+ 100 | 4 | 5 | 7.0
+ 100 | 5 | 5 | 7.0
+ 100 | 6 | 5 | 7.0
+ 100 | 7 | 5 | 7.0
+ 100 | 8 | 5 | 7.0
+ 100 | 9 | 5 | 7.0
+(10 rows)
+
+-- GROUP BY clause referring to same column multiple times
+-- Also, ORDER BY contains an aggregate function
+explain (verbose, costs off)
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, c2, (sum(c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, c2, sum("C 1") FROM "S 1"."T 1" WHERE ((c2 > 6)) GROUP BY 1, 2 ORDER BY sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ c2 | c2
+----+----
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(3 rows)
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 49800)) ORDER BY c2 ASC NULLS LAST
+(4 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ c2 | sum
+----+-------
+ 1 | 49600
+ 2 | 49700
+(2 rows)
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, NULL::bigint, (sqrt((ft1.c2)::double precision))
+ Filter: (((((avg(ft1.c1)) / (avg(ft1.c1))))::double precision * random()) <= '1'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ count
+-------
+ 49
+(1 row)
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * (random() <= 1)::int) > 100 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1)), c2
+ Sort Key: (sum(ft1.c1))
+ -> HashAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Filter: (avg((ft1.c1 * ((random() <= '1'::double precision))::integer)) > '100'::numeric)
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(10 rows)
+
+-- Remote aggregate in combination with a local Param (for the output
+-- of an initplan) can be trouble, per bug #15781
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ QUERY PLAN
+--------------------------------------------------
+ Foreign Scan
+ Output: $0, (sum(ft1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1"
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+(6 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ QUERY PLAN
+---------------------------------------------------
+ GroupAggregate
+ Output: ($0), sum(ft1.c1)
+ Group Key: $0
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+ -> Foreign Scan on public.ft1
+ Output: $0, ft1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(8 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY 2 ORDER BY array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1,11,21,31,41,51,61,71,81,91}
+ {2,12,22,32,42,52,62,72,82,92}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {5,15,25,35,45,55,65,75,85,95}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+(10 rows)
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5)) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY 2 ORDER BY sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))) ASC NULLS LAST
+(4 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+(10 rows)
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3) ORDER BY (("C 1" % 3)) ASC NULLS LAST) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY 3
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft2 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where (c1 / c1) * random() <= 1) from ft1 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((((ft1.c1 / ft1.c1))::double precision * random()) <= '1'::double precision)))
+ -> HashAggregate
+ Output: sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST), percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
+(7 rows)
+
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | rank | percentile_cont
+----+------+-----------------
+ 0 | 101 | 10
+ 1 | 101 | 100
+ 2 | 1 | 200
+ 3 | 1 | 300
+ 4 | 1 | 400
+(5 rows)
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY 1, 3
+(4 rows)
+
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ c1 | rank
+----+------
+ 6 | 1
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Disable hash aggregation for plan stability.
+set enable_hashagg to false;
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY 1
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 0 | 10
+ 1 | 1
+ 2 | 2
+ 3 | 3
+ 4 | 4
+ 5 | 5
+ 6 | 6
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(10 rows)
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Cleanup
+reset enable_hashagg;
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+create operator family my_op_family using btree;
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- This should not be pushed either.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- Update local stats on ft2
+ANALYZE ft2;
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now this will be pushed as sort operator is part of the extension.
+alter server loopback options (add fdw_tuple_cost '0.5');
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY 2
+(4 rows)
+
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+alter server loopback options (drop fdw_tuple_cost);
+-- This should be pushed too.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST
+(3 rows)
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft2 t1 left join ft2 t2 on (t1.c1 = random() * t2.c2);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop Left Join
+ Output: t1.c3
+ Join Filter: ((t1.c1)::double precision = (random() * (t2.c2)::double precision))
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c3, t1.c1
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1"
+ -> Materialize
+ Output: t2.c2
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(13 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Inner Unique: true
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1 ft1_1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1
+(21 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 100 | 49600
+ 100 | 49700
+ 100 | 49800
+ 100 | 49900
+ 100 | 50000
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(10 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY 3 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL))) ORDER BY avg(r1.c1) ASC NULLS LAST, sum(r2.c1) ASC NULLS LAST
+(4 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- Aggregate over FULL join needing to deparse the joining relations as
+-- subqueries.
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(ft4.c1)), (avg(ft5.c1))
+ Relations: Aggregate on ((public.ft4) FULL JOIN (public.ft5))
+ Remote SQL: SELECT count(*), sum(s4.c1), avg(s5.c1) FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ count | sum | avg
+-------+-----+---------------------
+ 8 | 330 | 55.5000000000000000
+(1 row)
+
+-- ORDER BY expression is part of the target list but not pushed down to
+-- foreign server.
+explain (verbose, costs off)
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: (((sum(c2)) * ((random() <= '1'::double precision))::integer))
+ Sort Key: (((sum(ft1.c2)) * ((random() <= '1'::double precision))::integer))
+ -> Foreign Scan
+ Output: ((sum(c2)) * ((random() <= '1'::double precision))::integer)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
+(7 rows)
+
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ sum
+------
+ 4500
+(1 row)
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c2, qry.sum
+ Sort Key: t1.c2
+ -> Nested Loop
+ Output: t1.c2, qry.sum
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Index Cond: (t1."C 1" < 100)
+ Filter: (t1.c2 < 3)
+ -> Subquery Scan on qry
+ Output: qry.sum, t2.c1
+ Filter: ((t1.c2 * 2) = qry.sum)
+ -> Foreign Scan
+ Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY 2
+(16 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ c2 | sum
+----+-----
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+reset enable_hashagg;
+-- bug #15613: bad plan for foreign table scan with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: ref_0.c2, ref_0."C 1", (ref_0.c2), ref_1.c3, ref_0."C 1"
+ -> Nested Loop
+ Output: ref_0.c2, ref_0."C 1", ref_1.c3, (ref_0.c2)
+ -> Index Scan using t1_pkey on "S 1"."T 1" ref_0
+ Output: ref_0."C 1", ref_0.c2, ref_0.c3, ref_0.c4, ref_0.c5, ref_0.c6, ref_0.c7, ref_0.c8
+ Index Cond: (ref_0."C 1" < 10)
+ -> Foreign Scan on public.ft1 ref_1
+ Output: ref_1.c3, ref_0.c2
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+ -> Materialize
+ Output: ref_3.c3
+ -> Foreign Scan on public.ft2 ref_3
+ Output: ref_3.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+(15 rows)
+
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ c2 | c1 | c2 | c3
+----+----+----+-------
+ 1 | 1 | 1 | 00001
+ 2 | 2 | 2 | 00001
+ 3 | 3 | 3 | 00001
+ 4 | 4 | 4 | 00001
+ 5 | 5 | 5 | 00001
+ 6 | 6 | 6 | 00001
+ 7 | 7 | 7 | 00001
+ 8 | 8 | 8 | 00001
+ 9 | 9 | 9 | 00001
+(9 rows)
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(q.a), count(q.b)
+ -> Nested Loop Left Join
+ Output: q.a, q.b
+ Inner Unique: true
+ Join Filter: ((ft4.c1)::numeric <= q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Materialize
+ Output: q.a, q.b
+ -> Subquery Scan on q
+ Output: q.a, q.b
+ -> Foreign Scan
+ Output: 13, (avg(ft1.c1)), NULL::bigint
+ Relations: Aggregate on ((public.ft2) LEFT JOIN (public.ft1))
+ Remote SQL: SELECT 13, avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1"))))
+(17 rows)
+
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ sum | count
+-----+-------
+ 650 | 50
+(1 row)
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: c2, c6, (sum(c1))
+ Sort Key: ft1.c2, ft1.c6
+ -> HashAggregate
+ Output: c2, c6, sum(c1)
+ Hash Key: ft1.c2
+ Hash Key: ft1.c6
+ -> Foreign Scan on public.ft1
+ Output: c2, c6, c1
+ Remote SQL: SELECT "C 1", c2, c6 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 0 | | 50500
+ 1 | | 49600
+ 2 | | 49700
+ | 0 | 50500
+ | 1 | 49600
+ | 2 | 49700
+(6 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1)), (GROUPING(c2))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, sum(c1), GROUPING(c2)
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(9 rows)
+
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 0 | 50500 | 0
+ 1 | 49600 | 0
+ 2 | 49700 | 0
+(3 rows)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((sum(c1) / 1000)), c2
+ -> Sort
+ Output: ((sum(c1) / 1000)), c2
+ Sort Key: ((sum(ft2.c1) / 1000))
+ -> Foreign Scan
+ Output: ((sum(c1) / 1000)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT (sum("C 1") / 1000), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY 2
+(9 rows)
+
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ s
+----
+ 49
+ 50
+(2 rows)
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2)), (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, (sum(c2)), count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ c2 | sum | count
+----+-----+-------
+ 0 | 0 | 5
+ 1 | 100 | 5
+ 2 | 200 | 5
+ 3 | 300 | 5
+ 4 | 400 | 5
+ 5 | 500 | 5
+ 6 | 600 | 5
+ 7 | 700 | 5
+ 8 | 800 | 5
+ 9 | 900 | 5
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2 DESC
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {8,6,4,2,0}
+ 1 | {9,7,5,3,1}
+ 2 | {8,6,4,2}
+ 3 | {9,7,5,3}
+ 4 | {8,6,4}
+ 5 | {9,7,5}
+ 6 | {8,6}
+ 7 | {9,7}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {0,2,4,6,8}
+ 1 | {1,3,5,7,9}
+ 2 | {2,4,6,8}
+ 3 | {3,5,7,9}
+ 4 | {4,6,8}
+ 5 | {5,7,9}
+ 6 | {6,8}
+ 7 | {7,9}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+-- ===================================================================
+-- parameterized queries
+-- ===================================================================
+-- simple join
+PREPARE st1(int, int) AS SELECT t1.c3, t2.c3 FROM ft1 t1, ft2 t2 WHERE t1.c1 = $1 AND t2.c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st1(1, 2);
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c3, t2.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.c3, r2.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 2)) AND ((r1."C 1" = 1))))
+(4 rows)
+
+EXECUTE st1(1, 1);
+ c3 | c3
+-------+-------
+ 00001 | 00001
+(1 row)
+
+EXECUTE st1(101, 101);
+ c3 | c3
+-------+-------
+ 00101 | 00101
+(1 row)
+
+-- subquery using stable function (can't be sent to remote)
+PREPARE st2(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c4) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st2(10, 20);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t2.c3 = t1.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Filter: (date(t2.c4) = '01-17-1970'::date)
+ Remote SQL: SELECT c3, c4 FROM "S 1"."T 1" WHERE (("C 1" > 10))
+(15 rows)
+
+EXECUTE st2(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st2(101, 121);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+-- subquery using immutable function (can be sent to remote)
+PREPARE st3(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c5) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st3(10, 20);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t2.c3 = t1.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" > 10)) AND ((date(c5) = '1970-01-17'::date))
+(14 rows)
+
+EXECUTE st3(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st3(20, 30);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- custom plan should be chosen initially
+PREPARE st4(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 = $1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+-- once we try it enough times, should switch to generic plan
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(3 rows)
+
+-- value of $1 should not be sent to remote
+PREPARE st5(user_enum,int) AS SELECT * FROM ft1 t1 WHERE c8 = $1 and c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = $1)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(4 rows)
+
+EXECUTE st5('foo', 1);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- altering FDW options requires replanning
+PREPARE st6 AS SELECT * FROM ft1 t1 WHERE t1.c1 = t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(3 rows)
+
+PREPARE st7 AS INSERT INTO ft1 (c1,c2,c3) VALUES (1001,101,'foo');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 1" RENAME TO "T 0";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 0');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 0" WHERE (("C 1" = c2))
+(3 rows)
+
+EXECUTE st6;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 0"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 0" RENAME TO "T 1";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 1');
+PREPARE st8 AS SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+EXECUTE st8;
+ count
+-------
+ 9
+(1 row)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- cleanup
+DEALLOCATE st1;
+DEALLOCATE st2;
+DEALLOCATE st3;
+DEALLOCATE st4;
+DEALLOCATE st5;
+DEALLOCATE st6;
+DEALLOCATE st7;
+DEALLOCATE st8;
+-- System columns, except ctid and oid, should not be sent to remote
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'pg_class'::regclass LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.tableoid = '1259'::oid)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'ft1'::regclass LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: (tableoid)::regclass, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ tableoid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ ft1 | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((ctid = '(0,2)'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: ctid, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ ctid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ (0,1) | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- ===================================================================
+-- used in PL/pgSQL function
+-- ===================================================================
+CREATE OR REPLACE FUNCTION f_test(p_c1 int) RETURNS int AS $$
+DECLARE
+ v_c1 int;
+BEGIN
+ SELECT c1 INTO v_c1 FROM ft1 WHERE c1 = p_c1 LIMIT 1;
+ PERFORM c1 FROM ft1 WHERE c1 = p_c1 AND p_c1 = v_c1 LIMIT 1;
+ RETURN v_c1;
+END;
+$$ LANGUAGE plpgsql;
+SELECT f_test(100);
+ f_test
+--------
+ 100
+(1 row)
+
+DROP FUNCTION f_test(int);
+-- ===================================================================
+-- REINDEX
+-- ===================================================================
+-- remote table is not created here
+CREATE FOREIGN TABLE reindex_foreign (c1 int, c2 int)
+ SERVER loopback2 OPTIONS (table_name 'reindex_local');
+REINDEX TABLE reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+REINDEX TABLE CONCURRENTLY reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+DROP FOREIGN TABLE reindex_foreign;
+-- partitions and foreign tables
+CREATE TABLE reind_fdw_parent (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE reind_fdw_0_10 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (0) TO (10);
+CREATE FOREIGN TABLE reind_fdw_10_20 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (10) TO (20)
+ SERVER loopback OPTIONS (table_name 'reind_local_10_20');
+REINDEX TABLE reind_fdw_parent; -- ok
+REINDEX TABLE CONCURRENTLY reind_fdw_parent; -- ok
+DROP TABLE reind_fdw_parent;
+-- ===================================================================
+-- conversion error
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int;
+SELECT * FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8) WHERE x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx.x8 FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: whole-row reference to foreign table "ftx"
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: processing expression at position 2 in select list
+ANALYZE ft1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "c8" of foreign table "ft1"
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- local type can be different from remote type in some cases,
+-- in particular if similarly-named operators do equivalent things
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE text;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 = 'foo')) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (('foo' = c8)) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- we declared c8 to be text locally, but it's still the same type on
+-- the remote which will balk if we try to do anything incompatible
+-- with that remote type
+SELECT * FROM ft1 WHERE c8 LIKE 'foo' LIMIT 1; -- ERROR
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+SELECT * FROM ft1 WHERE c8::text LIKE 'foo' LIMIT 1; -- ERROR; cast not pushed down
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- subtransaction
+-- + local/remote error doesn't break cursor
+-- ===================================================================
+BEGIN;
+DECLARE c CURSOR FOR SELECT * FROM ft1 ORDER BY c1;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+SAVEPOINT s;
+ERROR OUT; -- ERROR
+ERROR: syntax error at or near "ERROR"
+LINE 1: ERROR OUT;
+ ^
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+SAVEPOINT s;
+SELECT * FROM ft1 WHERE 1 / (c1 - 1) > 0; -- ERROR
+ERROR: division by zero
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (((1 / ("C 1" - 1)) > 0))
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c1 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+COMMIT;
+-- ===================================================================
+-- test handling of collations
+-- ===================================================================
+create table loct3 (f1 text collate "C" unique, f2 text, f3 varchar(10) unique);
+create foreign table ft3 (f1 text collate "C", f2 text, f3 varchar(10))
+ server loopback options (table_name 'loct3', use_remote_estimate 'true');
+-- can be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "C" = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f2 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f3 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 and l.f1 = 'foo';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = $1::character varying(10)))
+(8 rows)
+
+-- can't be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "POSIX" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f1)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f1 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 COLLATE "C" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f2)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f2 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 COLLATE "POSIX" and l.f1 = 'foo';
+ QUERY PLAN
+-------------------------------------------------------------
+ Hash Join
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ Inner Unique: true
+ Hash Cond: ((f.f3)::text = (l.f3)::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+ -> Hash
+ Output: l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+(12 rows)
+
+-- ===================================================================
+-- test writable foreign table stuff
+-- ===================================================================
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Subquery Scan on "*SELECT*"
+ Output: "*SELECT*"."?column?", "*SELECT*"."?column?_1", NULL::integer, "*SELECT*"."?column?_2", NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+ -> Foreign Scan on public.ft2 ft2_1
+ Output: (ft2_1.c1 + 1000), (ft2_1.c2 + 100), (ft2_1.c3 || ft2_1.c3)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" LIMIT 20::bigint
+(8 rows)
+
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+INSERT INTO ft2 (c1,c2,c3)
+ VALUES (1101,201,'aaa'), (1102,202,'bbb'), (1103,203,'ccc') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----+----+----+----+------------+----
+ 1101 | 201 | aaa | | | | ft2 |
+ 1102 | 202 | bbb | | | | ft2 |
+ 1103 | 203 | ccc | | | | ft2 |
+(3 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1104,204,'ddd'), (1105,205,'eee');
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 300), c3 = (c3 || '_update3') WHERE ((("C 1" % 10) = 3))
+(3 rows)
+
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 400), c3 = (c3 || '_update7') WHERE ((("C 1" % 10) = 7)) RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+(4 rows)
+
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+----+------------+-----
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 1007 | 507 | 0000700007_update7 | | | | ft2 |
+ 1017 | 507 | 0001700017_update7 | | | | ft2 |
+(102 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9; -- can be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c2 = (r1.c2 + 500), c3 = (r1.c3 || '_update9'), c7 = 'ft2 '::character(10) FROM "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 9))
+(3 rows)
+
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9;
+EXPLAIN (verbose, costs off)
+ DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: c1, c4
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 5)) RETURNING "C 1", c4
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4;
+ c1 | c4
+------+------------------------------
+ 5 | Tue Jan 06 00:00:00 1970 PST
+ 15 | Fri Jan 16 00:00:00 1970 PST
+ 25 | Mon Jan 26 00:00:00 1970 PST
+ 35 | Thu Feb 05 00:00:00 1970 PST
+ 45 | Sun Feb 15 00:00:00 1970 PST
+ 55 | Wed Feb 25 00:00:00 1970 PST
+ 65 | Sat Mar 07 00:00:00 1970 PST
+ 75 | Tue Mar 17 00:00:00 1970 PST
+ 85 | Fri Mar 27 00:00:00 1970 PST
+ 95 | Mon Apr 06 00:00:00 1970 PST
+ 105 | Tue Jan 06 00:00:00 1970 PST
+ 115 | Fri Jan 16 00:00:00 1970 PST
+ 125 | Mon Jan 26 00:00:00 1970 PST
+ 135 | Thu Feb 05 00:00:00 1970 PST
+ 145 | Sun Feb 15 00:00:00 1970 PST
+ 155 | Wed Feb 25 00:00:00 1970 PST
+ 165 | Sat Mar 07 00:00:00 1970 PST
+ 175 | Tue Mar 17 00:00:00 1970 PST
+ 185 | Fri Mar 27 00:00:00 1970 PST
+ 195 | Mon Apr 06 00:00:00 1970 PST
+ 205 | Tue Jan 06 00:00:00 1970 PST
+ 215 | Fri Jan 16 00:00:00 1970 PST
+ 225 | Mon Jan 26 00:00:00 1970 PST
+ 235 | Thu Feb 05 00:00:00 1970 PST
+ 245 | Sun Feb 15 00:00:00 1970 PST
+ 255 | Wed Feb 25 00:00:00 1970 PST
+ 265 | Sat Mar 07 00:00:00 1970 PST
+ 275 | Tue Mar 17 00:00:00 1970 PST
+ 285 | Fri Mar 27 00:00:00 1970 PST
+ 295 | Mon Apr 06 00:00:00 1970 PST
+ 305 | Tue Jan 06 00:00:00 1970 PST
+ 315 | Fri Jan 16 00:00:00 1970 PST
+ 325 | Mon Jan 26 00:00:00 1970 PST
+ 335 | Thu Feb 05 00:00:00 1970 PST
+ 345 | Sun Feb 15 00:00:00 1970 PST
+ 355 | Wed Feb 25 00:00:00 1970 PST
+ 365 | Sat Mar 07 00:00:00 1970 PST
+ 375 | Tue Mar 17 00:00:00 1970 PST
+ 385 | Fri Mar 27 00:00:00 1970 PST
+ 395 | Mon Apr 06 00:00:00 1970 PST
+ 405 | Tue Jan 06 00:00:00 1970 PST
+ 415 | Fri Jan 16 00:00:00 1970 PST
+ 425 | Mon Jan 26 00:00:00 1970 PST
+ 435 | Thu Feb 05 00:00:00 1970 PST
+ 445 | Sun Feb 15 00:00:00 1970 PST
+ 455 | Wed Feb 25 00:00:00 1970 PST
+ 465 | Sat Mar 07 00:00:00 1970 PST
+ 475 | Tue Mar 17 00:00:00 1970 PST
+ 485 | Fri Mar 27 00:00:00 1970 PST
+ 495 | Mon Apr 06 00:00:00 1970 PST
+ 505 | Tue Jan 06 00:00:00 1970 PST
+ 515 | Fri Jan 16 00:00:00 1970 PST
+ 525 | Mon Jan 26 00:00:00 1970 PST
+ 535 | Thu Feb 05 00:00:00 1970 PST
+ 545 | Sun Feb 15 00:00:00 1970 PST
+ 555 | Wed Feb 25 00:00:00 1970 PST
+ 565 | Sat Mar 07 00:00:00 1970 PST
+ 575 | Tue Mar 17 00:00:00 1970 PST
+ 585 | Fri Mar 27 00:00:00 1970 PST
+ 595 | Mon Apr 06 00:00:00 1970 PST
+ 605 | Tue Jan 06 00:00:00 1970 PST
+ 615 | Fri Jan 16 00:00:00 1970 PST
+ 625 | Mon Jan 26 00:00:00 1970 PST
+ 635 | Thu Feb 05 00:00:00 1970 PST
+ 645 | Sun Feb 15 00:00:00 1970 PST
+ 655 | Wed Feb 25 00:00:00 1970 PST
+ 665 | Sat Mar 07 00:00:00 1970 PST
+ 675 | Tue Mar 17 00:00:00 1970 PST
+ 685 | Fri Mar 27 00:00:00 1970 PST
+ 695 | Mon Apr 06 00:00:00 1970 PST
+ 705 | Tue Jan 06 00:00:00 1970 PST
+ 715 | Fri Jan 16 00:00:00 1970 PST
+ 725 | Mon Jan 26 00:00:00 1970 PST
+ 735 | Thu Feb 05 00:00:00 1970 PST
+ 745 | Sun Feb 15 00:00:00 1970 PST
+ 755 | Wed Feb 25 00:00:00 1970 PST
+ 765 | Sat Mar 07 00:00:00 1970 PST
+ 775 | Tue Mar 17 00:00:00 1970 PST
+ 785 | Fri Mar 27 00:00:00 1970 PST
+ 795 | Mon Apr 06 00:00:00 1970 PST
+ 805 | Tue Jan 06 00:00:00 1970 PST
+ 815 | Fri Jan 16 00:00:00 1970 PST
+ 825 | Mon Jan 26 00:00:00 1970 PST
+ 835 | Thu Feb 05 00:00:00 1970 PST
+ 845 | Sun Feb 15 00:00:00 1970 PST
+ 855 | Wed Feb 25 00:00:00 1970 PST
+ 865 | Sat Mar 07 00:00:00 1970 PST
+ 875 | Tue Mar 17 00:00:00 1970 PST
+ 885 | Fri Mar 27 00:00:00 1970 PST
+ 895 | Mon Apr 06 00:00:00 1970 PST
+ 905 | Tue Jan 06 00:00:00 1970 PST
+ 915 | Fri Jan 16 00:00:00 1970 PST
+ 925 | Mon Jan 26 00:00:00 1970 PST
+ 935 | Thu Feb 05 00:00:00 1970 PST
+ 945 | Sun Feb 15 00:00:00 1970 PST
+ 955 | Wed Feb 25 00:00:00 1970 PST
+ 965 | Sat Mar 07 00:00:00 1970 PST
+ 975 | Tue Mar 17 00:00:00 1970 PST
+ 985 | Fri Mar 27 00:00:00 1970 PST
+ 995 | Mon Apr 06 00:00:00 1970 PST
+ 1005 |
+ 1015 |
+ 1105 |
+(103 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 2))
+(3 rows)
+
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2;
+SELECT c1,c2,c3,c4 FROM ft2 ORDER BY c1;
+ c1 | c2 | c3 | c4
+------+-----+--------------------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 3 | 303 | 00003_update3 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+ 11 | 1 | 00011 | Mon Jan 12 00:00:00 1970 PST
+ 13 | 303 | 00013_update3 | Wed Jan 14 00:00:00 1970 PST
+ 14 | 4 | 00014 | Thu Jan 15 00:00:00 1970 PST
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST
+ 18 | 8 | 00018 | Mon Jan 19 00:00:00 1970 PST
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST
+ 20 | 0 | 00020 | Wed Jan 21 00:00:00 1970 PST
+ 21 | 1 | 00021 | Thu Jan 22 00:00:00 1970 PST
+ 23 | 303 | 00023_update3 | Sat Jan 24 00:00:00 1970 PST
+ 24 | 4 | 00024 | Sun Jan 25 00:00:00 1970 PST
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST
+ 28 | 8 | 00028 | Thu Jan 29 00:00:00 1970 PST
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST
+ 30 | 0 | 00030 | Sat Jan 31 00:00:00 1970 PST
+ 31 | 1 | 00031 | Sun Feb 01 00:00:00 1970 PST
+ 33 | 303 | 00033_update3 | Tue Feb 03 00:00:00 1970 PST
+ 34 | 4 | 00034 | Wed Feb 04 00:00:00 1970 PST
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST
+ 38 | 8 | 00038 | Sun Feb 08 00:00:00 1970 PST
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST
+ 40 | 0 | 00040 | Tue Feb 10 00:00:00 1970 PST
+ 41 | 1 | 00041 | Wed Feb 11 00:00:00 1970 PST
+ 43 | 303 | 00043_update3 | Fri Feb 13 00:00:00 1970 PST
+ 44 | 4 | 00044 | Sat Feb 14 00:00:00 1970 PST
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST
+ 48 | 8 | 00048 | Wed Feb 18 00:00:00 1970 PST
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST
+ 50 | 0 | 00050 | Fri Feb 20 00:00:00 1970 PST
+ 51 | 1 | 00051 | Sat Feb 21 00:00:00 1970 PST
+ 53 | 303 | 00053_update3 | Mon Feb 23 00:00:00 1970 PST
+ 54 | 4 | 00054 | Tue Feb 24 00:00:00 1970 PST
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST
+ 58 | 8 | 00058 | Sat Feb 28 00:00:00 1970 PST
+ 59 | 509 | 00059_update9 | Sun Mar 01 00:00:00 1970 PST
+ 60 | 0 | 00060 | Mon Mar 02 00:00:00 1970 PST
+ 61 | 1 | 00061 | Tue Mar 03 00:00:00 1970 PST
+ 63 | 303 | 00063_update3 | Thu Mar 05 00:00:00 1970 PST
+ 64 | 4 | 00064 | Fri Mar 06 00:00:00 1970 PST
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST
+ 68 | 8 | 00068 | Tue Mar 10 00:00:00 1970 PST
+ 69 | 509 | 00069_update9 | Wed Mar 11 00:00:00 1970 PST
+ 70 | 0 | 00070 | Thu Mar 12 00:00:00 1970 PST
+ 71 | 1 | 00071 | Fri Mar 13 00:00:00 1970 PST
+ 73 | 303 | 00073_update3 | Sun Mar 15 00:00:00 1970 PST
+ 74 | 4 | 00074 | Mon Mar 16 00:00:00 1970 PST
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST
+ 78 | 8 | 00078 | Fri Mar 20 00:00:00 1970 PST
+ 79 | 509 | 00079_update9 | Sat Mar 21 00:00:00 1970 PST
+ 80 | 0 | 00080 | Sun Mar 22 00:00:00 1970 PST
+ 81 | 1 | 00081 | Mon Mar 23 00:00:00 1970 PST
+ 83 | 303 | 00083_update3 | Wed Mar 25 00:00:00 1970 PST
+ 84 | 4 | 00084 | Thu Mar 26 00:00:00 1970 PST
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST
+ 88 | 8 | 00088 | Mon Mar 30 00:00:00 1970 PST
+ 89 | 509 | 00089_update9 | Tue Mar 31 00:00:00 1970 PST
+ 90 | 0 | 00090 | Wed Apr 01 00:00:00 1970 PST
+ 91 | 1 | 00091 | Thu Apr 02 00:00:00 1970 PST
+ 93 | 303 | 00093_update3 | Sat Apr 04 00:00:00 1970 PST
+ 94 | 4 | 00094 | Sun Apr 05 00:00:00 1970 PST
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST
+ 98 | 8 | 00098 | Thu Apr 09 00:00:00 1970 PST
+ 99 | 509 | 00099_update9 | Fri Apr 10 00:00:00 1970 PST
+ 100 | 0 | 00100 | Thu Jan 01 00:00:00 1970 PST
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST
+ 103 | 303 | 00103_update3 | Sun Jan 04 00:00:00 1970 PST
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST
+ 109 | 509 | 00109_update9 | Sat Jan 10 00:00:00 1970 PST
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST
+ 111 | 1 | 00111 | Mon Jan 12 00:00:00 1970 PST
+ 113 | 303 | 00113_update3 | Wed Jan 14 00:00:00 1970 PST
+ 114 | 4 | 00114 | Thu Jan 15 00:00:00 1970 PST
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST
+ 118 | 8 | 00118 | Mon Jan 19 00:00:00 1970 PST
+ 119 | 509 | 00119_update9 | Tue Jan 20 00:00:00 1970 PST
+ 120 | 0 | 00120 | Wed Jan 21 00:00:00 1970 PST
+ 121 | 1 | 00121 | Thu Jan 22 00:00:00 1970 PST
+ 123 | 303 | 00123_update3 | Sat Jan 24 00:00:00 1970 PST
+ 124 | 4 | 00124 | Sun Jan 25 00:00:00 1970 PST
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST
+ 128 | 8 | 00128 | Thu Jan 29 00:00:00 1970 PST
+ 129 | 509 | 00129_update9 | Fri Jan 30 00:00:00 1970 PST
+ 130 | 0 | 00130 | Sat Jan 31 00:00:00 1970 PST
+ 131 | 1 | 00131 | Sun Feb 01 00:00:00 1970 PST
+ 133 | 303 | 00133_update3 | Tue Feb 03 00:00:00 1970 PST
+ 134 | 4 | 00134 | Wed Feb 04 00:00:00 1970 PST
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST
+ 138 | 8 | 00138 | Sun Feb 08 00:00:00 1970 PST
+ 139 | 509 | 00139_update9 | Mon Feb 09 00:00:00 1970 PST
+ 140 | 0 | 00140 | Tue Feb 10 00:00:00 1970 PST
+ 141 | 1 | 00141 | Wed Feb 11 00:00:00 1970 PST
+ 143 | 303 | 00143_update3 | Fri Feb 13 00:00:00 1970 PST
+ 144 | 4 | 00144 | Sat Feb 14 00:00:00 1970 PST
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST
+ 148 | 8 | 00148 | Wed Feb 18 00:00:00 1970 PST
+ 149 | 509 | 00149_update9 | Thu Feb 19 00:00:00 1970 PST
+ 150 | 0 | 00150 | Fri Feb 20 00:00:00 1970 PST
+ 151 | 1 | 00151 | Sat Feb 21 00:00:00 1970 PST
+ 153 | 303 | 00153_update3 | Mon Feb 23 00:00:00 1970 PST
+ 154 | 4 | 00154 | Tue Feb 24 00:00:00 1970 PST
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST
+ 158 | 8 | 00158 | Sat Feb 28 00:00:00 1970 PST
+ 159 | 509 | 00159_update9 | Sun Mar 01 00:00:00 1970 PST
+ 160 | 0 | 00160 | Mon Mar 02 00:00:00 1970 PST
+ 161 | 1 | 00161 | Tue Mar 03 00:00:00 1970 PST
+ 163 | 303 | 00163_update3 | Thu Mar 05 00:00:00 1970 PST
+ 164 | 4 | 00164 | Fri Mar 06 00:00:00 1970 PST
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST
+ 168 | 8 | 00168 | Tue Mar 10 00:00:00 1970 PST
+ 169 | 509 | 00169_update9 | Wed Mar 11 00:00:00 1970 PST
+ 170 | 0 | 00170 | Thu Mar 12 00:00:00 1970 PST
+ 171 | 1 | 00171 | Fri Mar 13 00:00:00 1970 PST
+ 173 | 303 | 00173_update3 | Sun Mar 15 00:00:00 1970 PST
+ 174 | 4 | 00174 | Mon Mar 16 00:00:00 1970 PST
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST
+ 178 | 8 | 00178 | Fri Mar 20 00:00:00 1970 PST
+ 179 | 509 | 00179_update9 | Sat Mar 21 00:00:00 1970 PST
+ 180 | 0 | 00180 | Sun Mar 22 00:00:00 1970 PST
+ 181 | 1 | 00181 | Mon Mar 23 00:00:00 1970 PST
+ 183 | 303 | 00183_update3 | Wed Mar 25 00:00:00 1970 PST
+ 184 | 4 | 00184 | Thu Mar 26 00:00:00 1970 PST
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST
+ 188 | 8 | 00188 | Mon Mar 30 00:00:00 1970 PST
+ 189 | 509 | 00189_update9 | Tue Mar 31 00:00:00 1970 PST
+ 190 | 0 | 00190 | Wed Apr 01 00:00:00 1970 PST
+ 191 | 1 | 00191 | Thu Apr 02 00:00:00 1970 PST
+ 193 | 303 | 00193_update3 | Sat Apr 04 00:00:00 1970 PST
+ 194 | 4 | 00194 | Sun Apr 05 00:00:00 1970 PST
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST
+ 198 | 8 | 00198 | Thu Apr 09 00:00:00 1970 PST
+ 199 | 509 | 00199_update9 | Fri Apr 10 00:00:00 1970 PST
+ 200 | 0 | 00200 | Thu Jan 01 00:00:00 1970 PST
+ 201 | 1 | 00201 | Fri Jan 02 00:00:00 1970 PST
+ 203 | 303 | 00203_update3 | Sun Jan 04 00:00:00 1970 PST
+ 204 | 4 | 00204 | Mon Jan 05 00:00:00 1970 PST
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST
+ 208 | 8 | 00208 | Fri Jan 09 00:00:00 1970 PST
+ 209 | 509 | 00209_update9 | Sat Jan 10 00:00:00 1970 PST
+ 210 | 0 | 00210 | Sun Jan 11 00:00:00 1970 PST
+ 211 | 1 | 00211 | Mon Jan 12 00:00:00 1970 PST
+ 213 | 303 | 00213_update3 | Wed Jan 14 00:00:00 1970 PST
+ 214 | 4 | 00214 | Thu Jan 15 00:00:00 1970 PST
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST
+ 218 | 8 | 00218 | Mon Jan 19 00:00:00 1970 PST
+ 219 | 509 | 00219_update9 | Tue Jan 20 00:00:00 1970 PST
+ 220 | 0 | 00220 | Wed Jan 21 00:00:00 1970 PST
+ 221 | 1 | 00221 | Thu Jan 22 00:00:00 1970 PST
+ 223 | 303 | 00223_update3 | Sat Jan 24 00:00:00 1970 PST
+ 224 | 4 | 00224 | Sun Jan 25 00:00:00 1970 PST
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST
+ 228 | 8 | 00228 | Thu Jan 29 00:00:00 1970 PST
+ 229 | 509 | 00229_update9 | Fri Jan 30 00:00:00 1970 PST
+ 230 | 0 | 00230 | Sat Jan 31 00:00:00 1970 PST
+ 231 | 1 | 00231 | Sun Feb 01 00:00:00 1970 PST
+ 233 | 303 | 00233_update3 | Tue Feb 03 00:00:00 1970 PST
+ 234 | 4 | 00234 | Wed Feb 04 00:00:00 1970 PST
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST
+ 238 | 8 | 00238 | Sun Feb 08 00:00:00 1970 PST
+ 239 | 509 | 00239_update9 | Mon Feb 09 00:00:00 1970 PST
+ 240 | 0 | 00240 | Tue Feb 10 00:00:00 1970 PST
+ 241 | 1 | 00241 | Wed Feb 11 00:00:00 1970 PST
+ 243 | 303 | 00243_update3 | Fri Feb 13 00:00:00 1970 PST
+ 244 | 4 | 00244 | Sat Feb 14 00:00:00 1970 PST
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST
+ 248 | 8 | 00248 | Wed Feb 18 00:00:00 1970 PST
+ 249 | 509 | 00249_update9 | Thu Feb 19 00:00:00 1970 PST
+ 250 | 0 | 00250 | Fri Feb 20 00:00:00 1970 PST
+ 251 | 1 | 00251 | Sat Feb 21 00:00:00 1970 PST
+ 253 | 303 | 00253_update3 | Mon Feb 23 00:00:00 1970 PST
+ 254 | 4 | 00254 | Tue Feb 24 00:00:00 1970 PST
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST
+ 258 | 8 | 00258 | Sat Feb 28 00:00:00 1970 PST
+ 259 | 509 | 00259_update9 | Sun Mar 01 00:00:00 1970 PST
+ 260 | 0 | 00260 | Mon Mar 02 00:00:00 1970 PST
+ 261 | 1 | 00261 | Tue Mar 03 00:00:00 1970 PST
+ 263 | 303 | 00263_update3 | Thu Mar 05 00:00:00 1970 PST
+ 264 | 4 | 00264 | Fri Mar 06 00:00:00 1970 PST
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST
+ 268 | 8 | 00268 | Tue Mar 10 00:00:00 1970 PST
+ 269 | 509 | 00269_update9 | Wed Mar 11 00:00:00 1970 PST
+ 270 | 0 | 00270 | Thu Mar 12 00:00:00 1970 PST
+ 271 | 1 | 00271 | Fri Mar 13 00:00:00 1970 PST
+ 273 | 303 | 00273_update3 | Sun Mar 15 00:00:00 1970 PST
+ 274 | 4 | 00274 | Mon Mar 16 00:00:00 1970 PST
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST
+ 278 | 8 | 00278 | Fri Mar 20 00:00:00 1970 PST
+ 279 | 509 | 00279_update9 | Sat Mar 21 00:00:00 1970 PST
+ 280 | 0 | 00280 | Sun Mar 22 00:00:00 1970 PST
+ 281 | 1 | 00281 | Mon Mar 23 00:00:00 1970 PST
+ 283 | 303 | 00283_update3 | Wed Mar 25 00:00:00 1970 PST
+ 284 | 4 | 00284 | Thu Mar 26 00:00:00 1970 PST
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST
+ 288 | 8 | 00288 | Mon Mar 30 00:00:00 1970 PST
+ 289 | 509 | 00289_update9 | Tue Mar 31 00:00:00 1970 PST
+ 290 | 0 | 00290 | Wed Apr 01 00:00:00 1970 PST
+ 291 | 1 | 00291 | Thu Apr 02 00:00:00 1970 PST
+ 293 | 303 | 00293_update3 | Sat Apr 04 00:00:00 1970 PST
+ 294 | 4 | 00294 | Sun Apr 05 00:00:00 1970 PST
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST
+ 298 | 8 | 00298 | Thu Apr 09 00:00:00 1970 PST
+ 299 | 509 | 00299_update9 | Fri Apr 10 00:00:00 1970 PST
+ 300 | 0 | 00300 | Thu Jan 01 00:00:00 1970 PST
+ 301 | 1 | 00301 | Fri Jan 02 00:00:00 1970 PST
+ 303 | 303 | 00303_update3 | Sun Jan 04 00:00:00 1970 PST
+ 304 | 4 | 00304 | Mon Jan 05 00:00:00 1970 PST
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST
+ 308 | 8 | 00308 | Fri Jan 09 00:00:00 1970 PST
+ 309 | 509 | 00309_update9 | Sat Jan 10 00:00:00 1970 PST
+ 310 | 0 | 00310 | Sun Jan 11 00:00:00 1970 PST
+ 311 | 1 | 00311 | Mon Jan 12 00:00:00 1970 PST
+ 313 | 303 | 00313_update3 | Wed Jan 14 00:00:00 1970 PST
+ 314 | 4 | 00314 | Thu Jan 15 00:00:00 1970 PST
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST
+ 318 | 8 | 00318 | Mon Jan 19 00:00:00 1970 PST
+ 319 | 509 | 00319_update9 | Tue Jan 20 00:00:00 1970 PST
+ 320 | 0 | 00320 | Wed Jan 21 00:00:00 1970 PST
+ 321 | 1 | 00321 | Thu Jan 22 00:00:00 1970 PST
+ 323 | 303 | 00323_update3 | Sat Jan 24 00:00:00 1970 PST
+ 324 | 4 | 00324 | Sun Jan 25 00:00:00 1970 PST
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST
+ 328 | 8 | 00328 | Thu Jan 29 00:00:00 1970 PST
+ 329 | 509 | 00329_update9 | Fri Jan 30 00:00:00 1970 PST
+ 330 | 0 | 00330 | Sat Jan 31 00:00:00 1970 PST
+ 331 | 1 | 00331 | Sun Feb 01 00:00:00 1970 PST
+ 333 | 303 | 00333_update3 | Tue Feb 03 00:00:00 1970 PST
+ 334 | 4 | 00334 | Wed Feb 04 00:00:00 1970 PST
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST
+ 338 | 8 | 00338 | Sun Feb 08 00:00:00 1970 PST
+ 339 | 509 | 00339_update9 | Mon Feb 09 00:00:00 1970 PST
+ 340 | 0 | 00340 | Tue Feb 10 00:00:00 1970 PST
+ 341 | 1 | 00341 | Wed Feb 11 00:00:00 1970 PST
+ 343 | 303 | 00343_update3 | Fri Feb 13 00:00:00 1970 PST
+ 344 | 4 | 00344 | Sat Feb 14 00:00:00 1970 PST
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST
+ 348 | 8 | 00348 | Wed Feb 18 00:00:00 1970 PST
+ 349 | 509 | 00349_update9 | Thu Feb 19 00:00:00 1970 PST
+ 350 | 0 | 00350 | Fri Feb 20 00:00:00 1970 PST
+ 351 | 1 | 00351 | Sat Feb 21 00:00:00 1970 PST
+ 353 | 303 | 00353_update3 | Mon Feb 23 00:00:00 1970 PST
+ 354 | 4 | 00354 | Tue Feb 24 00:00:00 1970 PST
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST
+ 358 | 8 | 00358 | Sat Feb 28 00:00:00 1970 PST
+ 359 | 509 | 00359_update9 | Sun Mar 01 00:00:00 1970 PST
+ 360 | 0 | 00360 | Mon Mar 02 00:00:00 1970 PST
+ 361 | 1 | 00361 | Tue Mar 03 00:00:00 1970 PST
+ 363 | 303 | 00363_update3 | Thu Mar 05 00:00:00 1970 PST
+ 364 | 4 | 00364 | Fri Mar 06 00:00:00 1970 PST
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST
+ 368 | 8 | 00368 | Tue Mar 10 00:00:00 1970 PST
+ 369 | 509 | 00369_update9 | Wed Mar 11 00:00:00 1970 PST
+ 370 | 0 | 00370 | Thu Mar 12 00:00:00 1970 PST
+ 371 | 1 | 00371 | Fri Mar 13 00:00:00 1970 PST
+ 373 | 303 | 00373_update3 | Sun Mar 15 00:00:00 1970 PST
+ 374 | 4 | 00374 | Mon Mar 16 00:00:00 1970 PST
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST
+ 378 | 8 | 00378 | Fri Mar 20 00:00:00 1970 PST
+ 379 | 509 | 00379_update9 | Sat Mar 21 00:00:00 1970 PST
+ 380 | 0 | 00380 | Sun Mar 22 00:00:00 1970 PST
+ 381 | 1 | 00381 | Mon Mar 23 00:00:00 1970 PST
+ 383 | 303 | 00383_update3 | Wed Mar 25 00:00:00 1970 PST
+ 384 | 4 | 00384 | Thu Mar 26 00:00:00 1970 PST
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST
+ 388 | 8 | 00388 | Mon Mar 30 00:00:00 1970 PST
+ 389 | 509 | 00389_update9 | Tue Mar 31 00:00:00 1970 PST
+ 390 | 0 | 00390 | Wed Apr 01 00:00:00 1970 PST
+ 391 | 1 | 00391 | Thu Apr 02 00:00:00 1970 PST
+ 393 | 303 | 00393_update3 | Sat Apr 04 00:00:00 1970 PST
+ 394 | 4 | 00394 | Sun Apr 05 00:00:00 1970 PST
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST
+ 398 | 8 | 00398 | Thu Apr 09 00:00:00 1970 PST
+ 399 | 509 | 00399_update9 | Fri Apr 10 00:00:00 1970 PST
+ 400 | 0 | 00400 | Thu Jan 01 00:00:00 1970 PST
+ 401 | 1 | 00401 | Fri Jan 02 00:00:00 1970 PST
+ 403 | 303 | 00403_update3 | Sun Jan 04 00:00:00 1970 PST
+ 404 | 4 | 00404 | Mon Jan 05 00:00:00 1970 PST
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST
+ 408 | 8 | 00408 | Fri Jan 09 00:00:00 1970 PST
+ 409 | 509 | 00409_update9 | Sat Jan 10 00:00:00 1970 PST
+ 410 | 0 | 00410 | Sun Jan 11 00:00:00 1970 PST
+ 411 | 1 | 00411 | Mon Jan 12 00:00:00 1970 PST
+ 413 | 303 | 00413_update3 | Wed Jan 14 00:00:00 1970 PST
+ 414 | 4 | 00414 | Thu Jan 15 00:00:00 1970 PST
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST
+ 418 | 8 | 00418 | Mon Jan 19 00:00:00 1970 PST
+ 419 | 509 | 00419_update9 | Tue Jan 20 00:00:00 1970 PST
+ 420 | 0 | 00420 | Wed Jan 21 00:00:00 1970 PST
+ 421 | 1 | 00421 | Thu Jan 22 00:00:00 1970 PST
+ 423 | 303 | 00423_update3 | Sat Jan 24 00:00:00 1970 PST
+ 424 | 4 | 00424 | Sun Jan 25 00:00:00 1970 PST
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST
+ 428 | 8 | 00428 | Thu Jan 29 00:00:00 1970 PST
+ 429 | 509 | 00429_update9 | Fri Jan 30 00:00:00 1970 PST
+ 430 | 0 | 00430 | Sat Jan 31 00:00:00 1970 PST
+ 431 | 1 | 00431 | Sun Feb 01 00:00:00 1970 PST
+ 433 | 303 | 00433_update3 | Tue Feb 03 00:00:00 1970 PST
+ 434 | 4 | 00434 | Wed Feb 04 00:00:00 1970 PST
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST
+ 438 | 8 | 00438 | Sun Feb 08 00:00:00 1970 PST
+ 439 | 509 | 00439_update9 | Mon Feb 09 00:00:00 1970 PST
+ 440 | 0 | 00440 | Tue Feb 10 00:00:00 1970 PST
+ 441 | 1 | 00441 | Wed Feb 11 00:00:00 1970 PST
+ 443 | 303 | 00443_update3 | Fri Feb 13 00:00:00 1970 PST
+ 444 | 4 | 00444 | Sat Feb 14 00:00:00 1970 PST
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST
+ 448 | 8 | 00448 | Wed Feb 18 00:00:00 1970 PST
+ 449 | 509 | 00449_update9 | Thu Feb 19 00:00:00 1970 PST
+ 450 | 0 | 00450 | Fri Feb 20 00:00:00 1970 PST
+ 451 | 1 | 00451 | Sat Feb 21 00:00:00 1970 PST
+ 453 | 303 | 00453_update3 | Mon Feb 23 00:00:00 1970 PST
+ 454 | 4 | 00454 | Tue Feb 24 00:00:00 1970 PST
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST
+ 458 | 8 | 00458 | Sat Feb 28 00:00:00 1970 PST
+ 459 | 509 | 00459_update9 | Sun Mar 01 00:00:00 1970 PST
+ 460 | 0 | 00460 | Mon Mar 02 00:00:00 1970 PST
+ 461 | 1 | 00461 | Tue Mar 03 00:00:00 1970 PST
+ 463 | 303 | 00463_update3 | Thu Mar 05 00:00:00 1970 PST
+ 464 | 4 | 00464 | Fri Mar 06 00:00:00 1970 PST
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST
+ 468 | 8 | 00468 | Tue Mar 10 00:00:00 1970 PST
+ 469 | 509 | 00469_update9 | Wed Mar 11 00:00:00 1970 PST
+ 470 | 0 | 00470 | Thu Mar 12 00:00:00 1970 PST
+ 471 | 1 | 00471 | Fri Mar 13 00:00:00 1970 PST
+ 473 | 303 | 00473_update3 | Sun Mar 15 00:00:00 1970 PST
+ 474 | 4 | 00474 | Mon Mar 16 00:00:00 1970 PST
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST
+ 478 | 8 | 00478 | Fri Mar 20 00:00:00 1970 PST
+ 479 | 509 | 00479_update9 | Sat Mar 21 00:00:00 1970 PST
+ 480 | 0 | 00480 | Sun Mar 22 00:00:00 1970 PST
+ 481 | 1 | 00481 | Mon Mar 23 00:00:00 1970 PST
+ 483 | 303 | 00483_update3 | Wed Mar 25 00:00:00 1970 PST
+ 484 | 4 | 00484 | Thu Mar 26 00:00:00 1970 PST
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST
+ 488 | 8 | 00488 | Mon Mar 30 00:00:00 1970 PST
+ 489 | 509 | 00489_update9 | Tue Mar 31 00:00:00 1970 PST
+ 490 | 0 | 00490 | Wed Apr 01 00:00:00 1970 PST
+ 491 | 1 | 00491 | Thu Apr 02 00:00:00 1970 PST
+ 493 | 303 | 00493_update3 | Sat Apr 04 00:00:00 1970 PST
+ 494 | 4 | 00494 | Sun Apr 05 00:00:00 1970 PST
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST
+ 498 | 8 | 00498 | Thu Apr 09 00:00:00 1970 PST
+ 499 | 509 | 00499_update9 | Fri Apr 10 00:00:00 1970 PST
+ 500 | 0 | 00500 | Thu Jan 01 00:00:00 1970 PST
+ 501 | 1 | 00501 | Fri Jan 02 00:00:00 1970 PST
+ 503 | 303 | 00503_update3 | Sun Jan 04 00:00:00 1970 PST
+ 504 | 4 | 00504 | Mon Jan 05 00:00:00 1970 PST
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST
+ 508 | 8 | 00508 | Fri Jan 09 00:00:00 1970 PST
+ 509 | 509 | 00509_update9 | Sat Jan 10 00:00:00 1970 PST
+ 510 | 0 | 00510 | Sun Jan 11 00:00:00 1970 PST
+ 511 | 1 | 00511 | Mon Jan 12 00:00:00 1970 PST
+ 513 | 303 | 00513_update3 | Wed Jan 14 00:00:00 1970 PST
+ 514 | 4 | 00514 | Thu Jan 15 00:00:00 1970 PST
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST
+ 518 | 8 | 00518 | Mon Jan 19 00:00:00 1970 PST
+ 519 | 509 | 00519_update9 | Tue Jan 20 00:00:00 1970 PST
+ 520 | 0 | 00520 | Wed Jan 21 00:00:00 1970 PST
+ 521 | 1 | 00521 | Thu Jan 22 00:00:00 1970 PST
+ 523 | 303 | 00523_update3 | Sat Jan 24 00:00:00 1970 PST
+ 524 | 4 | 00524 | Sun Jan 25 00:00:00 1970 PST
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST
+ 528 | 8 | 00528 | Thu Jan 29 00:00:00 1970 PST
+ 529 | 509 | 00529_update9 | Fri Jan 30 00:00:00 1970 PST
+ 530 | 0 | 00530 | Sat Jan 31 00:00:00 1970 PST
+ 531 | 1 | 00531 | Sun Feb 01 00:00:00 1970 PST
+ 533 | 303 | 00533_update3 | Tue Feb 03 00:00:00 1970 PST
+ 534 | 4 | 00534 | Wed Feb 04 00:00:00 1970 PST
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST
+ 538 | 8 | 00538 | Sun Feb 08 00:00:00 1970 PST
+ 539 | 509 | 00539_update9 | Mon Feb 09 00:00:00 1970 PST
+ 540 | 0 | 00540 | Tue Feb 10 00:00:00 1970 PST
+ 541 | 1 | 00541 | Wed Feb 11 00:00:00 1970 PST
+ 543 | 303 | 00543_update3 | Fri Feb 13 00:00:00 1970 PST
+ 544 | 4 | 00544 | Sat Feb 14 00:00:00 1970 PST
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST
+ 548 | 8 | 00548 | Wed Feb 18 00:00:00 1970 PST
+ 549 | 509 | 00549_update9 | Thu Feb 19 00:00:00 1970 PST
+ 550 | 0 | 00550 | Fri Feb 20 00:00:00 1970 PST
+ 551 | 1 | 00551 | Sat Feb 21 00:00:00 1970 PST
+ 553 | 303 | 00553_update3 | Mon Feb 23 00:00:00 1970 PST
+ 554 | 4 | 00554 | Tue Feb 24 00:00:00 1970 PST
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST
+ 558 | 8 | 00558 | Sat Feb 28 00:00:00 1970 PST
+ 559 | 509 | 00559_update9 | Sun Mar 01 00:00:00 1970 PST
+ 560 | 0 | 00560 | Mon Mar 02 00:00:00 1970 PST
+ 561 | 1 | 00561 | Tue Mar 03 00:00:00 1970 PST
+ 563 | 303 | 00563_update3 | Thu Mar 05 00:00:00 1970 PST
+ 564 | 4 | 00564 | Fri Mar 06 00:00:00 1970 PST
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST
+ 568 | 8 | 00568 | Tue Mar 10 00:00:00 1970 PST
+ 569 | 509 | 00569_update9 | Wed Mar 11 00:00:00 1970 PST
+ 570 | 0 | 00570 | Thu Mar 12 00:00:00 1970 PST
+ 571 | 1 | 00571 | Fri Mar 13 00:00:00 1970 PST
+ 573 | 303 | 00573_update3 | Sun Mar 15 00:00:00 1970 PST
+ 574 | 4 | 00574 | Mon Mar 16 00:00:00 1970 PST
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST
+ 578 | 8 | 00578 | Fri Mar 20 00:00:00 1970 PST
+ 579 | 509 | 00579_update9 | Sat Mar 21 00:00:00 1970 PST
+ 580 | 0 | 00580 | Sun Mar 22 00:00:00 1970 PST
+ 581 | 1 | 00581 | Mon Mar 23 00:00:00 1970 PST
+ 583 | 303 | 00583_update3 | Wed Mar 25 00:00:00 1970 PST
+ 584 | 4 | 00584 | Thu Mar 26 00:00:00 1970 PST
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST
+ 588 | 8 | 00588 | Mon Mar 30 00:00:00 1970 PST
+ 589 | 509 | 00589_update9 | Tue Mar 31 00:00:00 1970 PST
+ 590 | 0 | 00590 | Wed Apr 01 00:00:00 1970 PST
+ 591 | 1 | 00591 | Thu Apr 02 00:00:00 1970 PST
+ 593 | 303 | 00593_update3 | Sat Apr 04 00:00:00 1970 PST
+ 594 | 4 | 00594 | Sun Apr 05 00:00:00 1970 PST
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST
+ 598 | 8 | 00598 | Thu Apr 09 00:00:00 1970 PST
+ 599 | 509 | 00599_update9 | Fri Apr 10 00:00:00 1970 PST
+ 600 | 0 | 00600 | Thu Jan 01 00:00:00 1970 PST
+ 601 | 1 | 00601 | Fri Jan 02 00:00:00 1970 PST
+ 603 | 303 | 00603_update3 | Sun Jan 04 00:00:00 1970 PST
+ 604 | 4 | 00604 | Mon Jan 05 00:00:00 1970 PST
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST
+ 608 | 8 | 00608 | Fri Jan 09 00:00:00 1970 PST
+ 609 | 509 | 00609_update9 | Sat Jan 10 00:00:00 1970 PST
+ 610 | 0 | 00610 | Sun Jan 11 00:00:00 1970 PST
+ 611 | 1 | 00611 | Mon Jan 12 00:00:00 1970 PST
+ 613 | 303 | 00613_update3 | Wed Jan 14 00:00:00 1970 PST
+ 614 | 4 | 00614 | Thu Jan 15 00:00:00 1970 PST
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST
+ 618 | 8 | 00618 | Mon Jan 19 00:00:00 1970 PST
+ 619 | 509 | 00619_update9 | Tue Jan 20 00:00:00 1970 PST
+ 620 | 0 | 00620 | Wed Jan 21 00:00:00 1970 PST
+ 621 | 1 | 00621 | Thu Jan 22 00:00:00 1970 PST
+ 623 | 303 | 00623_update3 | Sat Jan 24 00:00:00 1970 PST
+ 624 | 4 | 00624 | Sun Jan 25 00:00:00 1970 PST
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST
+ 628 | 8 | 00628 | Thu Jan 29 00:00:00 1970 PST
+ 629 | 509 | 00629_update9 | Fri Jan 30 00:00:00 1970 PST
+ 630 | 0 | 00630 | Sat Jan 31 00:00:00 1970 PST
+ 631 | 1 | 00631 | Sun Feb 01 00:00:00 1970 PST
+ 633 | 303 | 00633_update3 | Tue Feb 03 00:00:00 1970 PST
+ 634 | 4 | 00634 | Wed Feb 04 00:00:00 1970 PST
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST
+ 638 | 8 | 00638 | Sun Feb 08 00:00:00 1970 PST
+ 639 | 509 | 00639_update9 | Mon Feb 09 00:00:00 1970 PST
+ 640 | 0 | 00640 | Tue Feb 10 00:00:00 1970 PST
+ 641 | 1 | 00641 | Wed Feb 11 00:00:00 1970 PST
+ 643 | 303 | 00643_update3 | Fri Feb 13 00:00:00 1970 PST
+ 644 | 4 | 00644 | Sat Feb 14 00:00:00 1970 PST
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST
+ 648 | 8 | 00648 | Wed Feb 18 00:00:00 1970 PST
+ 649 | 509 | 00649_update9 | Thu Feb 19 00:00:00 1970 PST
+ 650 | 0 | 00650 | Fri Feb 20 00:00:00 1970 PST
+ 651 | 1 | 00651 | Sat Feb 21 00:00:00 1970 PST
+ 653 | 303 | 00653_update3 | Mon Feb 23 00:00:00 1970 PST
+ 654 | 4 | 00654 | Tue Feb 24 00:00:00 1970 PST
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST
+ 658 | 8 | 00658 | Sat Feb 28 00:00:00 1970 PST
+ 659 | 509 | 00659_update9 | Sun Mar 01 00:00:00 1970 PST
+ 660 | 0 | 00660 | Mon Mar 02 00:00:00 1970 PST
+ 661 | 1 | 00661 | Tue Mar 03 00:00:00 1970 PST
+ 663 | 303 | 00663_update3 | Thu Mar 05 00:00:00 1970 PST
+ 664 | 4 | 00664 | Fri Mar 06 00:00:00 1970 PST
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST
+ 668 | 8 | 00668 | Tue Mar 10 00:00:00 1970 PST
+ 669 | 509 | 00669_update9 | Wed Mar 11 00:00:00 1970 PST
+ 670 | 0 | 00670 | Thu Mar 12 00:00:00 1970 PST
+ 671 | 1 | 00671 | Fri Mar 13 00:00:00 1970 PST
+ 673 | 303 | 00673_update3 | Sun Mar 15 00:00:00 1970 PST
+ 674 | 4 | 00674 | Mon Mar 16 00:00:00 1970 PST
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST
+ 678 | 8 | 00678 | Fri Mar 20 00:00:00 1970 PST
+ 679 | 509 | 00679_update9 | Sat Mar 21 00:00:00 1970 PST
+ 680 | 0 | 00680 | Sun Mar 22 00:00:00 1970 PST
+ 681 | 1 | 00681 | Mon Mar 23 00:00:00 1970 PST
+ 683 | 303 | 00683_update3 | Wed Mar 25 00:00:00 1970 PST
+ 684 | 4 | 00684 | Thu Mar 26 00:00:00 1970 PST
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST
+ 688 | 8 | 00688 | Mon Mar 30 00:00:00 1970 PST
+ 689 | 509 | 00689_update9 | Tue Mar 31 00:00:00 1970 PST
+ 690 | 0 | 00690 | Wed Apr 01 00:00:00 1970 PST
+ 691 | 1 | 00691 | Thu Apr 02 00:00:00 1970 PST
+ 693 | 303 | 00693_update3 | Sat Apr 04 00:00:00 1970 PST
+ 694 | 4 | 00694 | Sun Apr 05 00:00:00 1970 PST
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST
+ 698 | 8 | 00698 | Thu Apr 09 00:00:00 1970 PST
+ 699 | 509 | 00699_update9 | Fri Apr 10 00:00:00 1970 PST
+ 700 | 0 | 00700 | Thu Jan 01 00:00:00 1970 PST
+ 701 | 1 | 00701 | Fri Jan 02 00:00:00 1970 PST
+ 703 | 303 | 00703_update3 | Sun Jan 04 00:00:00 1970 PST
+ 704 | 4 | 00704 | Mon Jan 05 00:00:00 1970 PST
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST
+ 708 | 8 | 00708 | Fri Jan 09 00:00:00 1970 PST
+ 709 | 509 | 00709_update9 | Sat Jan 10 00:00:00 1970 PST
+ 710 | 0 | 00710 | Sun Jan 11 00:00:00 1970 PST
+ 711 | 1 | 00711 | Mon Jan 12 00:00:00 1970 PST
+ 713 | 303 | 00713_update3 | Wed Jan 14 00:00:00 1970 PST
+ 714 | 4 | 00714 | Thu Jan 15 00:00:00 1970 PST
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST
+ 718 | 8 | 00718 | Mon Jan 19 00:00:00 1970 PST
+ 719 | 509 | 00719_update9 | Tue Jan 20 00:00:00 1970 PST
+ 720 | 0 | 00720 | Wed Jan 21 00:00:00 1970 PST
+ 721 | 1 | 00721 | Thu Jan 22 00:00:00 1970 PST
+ 723 | 303 | 00723_update3 | Sat Jan 24 00:00:00 1970 PST
+ 724 | 4 | 00724 | Sun Jan 25 00:00:00 1970 PST
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST
+ 728 | 8 | 00728 | Thu Jan 29 00:00:00 1970 PST
+ 729 | 509 | 00729_update9 | Fri Jan 30 00:00:00 1970 PST
+ 730 | 0 | 00730 | Sat Jan 31 00:00:00 1970 PST
+ 731 | 1 | 00731 | Sun Feb 01 00:00:00 1970 PST
+ 733 | 303 | 00733_update3 | Tue Feb 03 00:00:00 1970 PST
+ 734 | 4 | 00734 | Wed Feb 04 00:00:00 1970 PST
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST
+ 738 | 8 | 00738 | Sun Feb 08 00:00:00 1970 PST
+ 739 | 509 | 00739_update9 | Mon Feb 09 00:00:00 1970 PST
+ 740 | 0 | 00740 | Tue Feb 10 00:00:00 1970 PST
+ 741 | 1 | 00741 | Wed Feb 11 00:00:00 1970 PST
+ 743 | 303 | 00743_update3 | Fri Feb 13 00:00:00 1970 PST
+ 744 | 4 | 00744 | Sat Feb 14 00:00:00 1970 PST
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST
+ 748 | 8 | 00748 | Wed Feb 18 00:00:00 1970 PST
+ 749 | 509 | 00749_update9 | Thu Feb 19 00:00:00 1970 PST
+ 750 | 0 | 00750 | Fri Feb 20 00:00:00 1970 PST
+ 751 | 1 | 00751 | Sat Feb 21 00:00:00 1970 PST
+ 753 | 303 | 00753_update3 | Mon Feb 23 00:00:00 1970 PST
+ 754 | 4 | 00754 | Tue Feb 24 00:00:00 1970 PST
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST
+ 758 | 8 | 00758 | Sat Feb 28 00:00:00 1970 PST
+ 759 | 509 | 00759_update9 | Sun Mar 01 00:00:00 1970 PST
+ 760 | 0 | 00760 | Mon Mar 02 00:00:00 1970 PST
+ 761 | 1 | 00761 | Tue Mar 03 00:00:00 1970 PST
+ 763 | 303 | 00763_update3 | Thu Mar 05 00:00:00 1970 PST
+ 764 | 4 | 00764 | Fri Mar 06 00:00:00 1970 PST
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST
+ 768 | 8 | 00768 | Tue Mar 10 00:00:00 1970 PST
+ 769 | 509 | 00769_update9 | Wed Mar 11 00:00:00 1970 PST
+ 770 | 0 | 00770 | Thu Mar 12 00:00:00 1970 PST
+ 771 | 1 | 00771 | Fri Mar 13 00:00:00 1970 PST
+ 773 | 303 | 00773_update3 | Sun Mar 15 00:00:00 1970 PST
+ 774 | 4 | 00774 | Mon Mar 16 00:00:00 1970 PST
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST
+ 778 | 8 | 00778 | Fri Mar 20 00:00:00 1970 PST
+ 779 | 509 | 00779_update9 | Sat Mar 21 00:00:00 1970 PST
+ 780 | 0 | 00780 | Sun Mar 22 00:00:00 1970 PST
+ 781 | 1 | 00781 | Mon Mar 23 00:00:00 1970 PST
+ 783 | 303 | 00783_update3 | Wed Mar 25 00:00:00 1970 PST
+ 784 | 4 | 00784 | Thu Mar 26 00:00:00 1970 PST
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST
+ 788 | 8 | 00788 | Mon Mar 30 00:00:00 1970 PST
+ 789 | 509 | 00789_update9 | Tue Mar 31 00:00:00 1970 PST
+ 790 | 0 | 00790 | Wed Apr 01 00:00:00 1970 PST
+ 791 | 1 | 00791 | Thu Apr 02 00:00:00 1970 PST
+ 793 | 303 | 00793_update3 | Sat Apr 04 00:00:00 1970 PST
+ 794 | 4 | 00794 | Sun Apr 05 00:00:00 1970 PST
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST
+ 798 | 8 | 00798 | Thu Apr 09 00:00:00 1970 PST
+ 799 | 509 | 00799_update9 | Fri Apr 10 00:00:00 1970 PST
+ 800 | 0 | 00800 | Thu Jan 01 00:00:00 1970 PST
+ 801 | 1 | 00801 | Fri Jan 02 00:00:00 1970 PST
+ 803 | 303 | 00803_update3 | Sun Jan 04 00:00:00 1970 PST
+ 804 | 4 | 00804 | Mon Jan 05 00:00:00 1970 PST
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST
+ 808 | 8 | 00808 | Fri Jan 09 00:00:00 1970 PST
+ 809 | 509 | 00809_update9 | Sat Jan 10 00:00:00 1970 PST
+ 810 | 0 | 00810 | Sun Jan 11 00:00:00 1970 PST
+ 811 | 1 | 00811 | Mon Jan 12 00:00:00 1970 PST
+ 813 | 303 | 00813_update3 | Wed Jan 14 00:00:00 1970 PST
+ 814 | 4 | 00814 | Thu Jan 15 00:00:00 1970 PST
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST
+ 818 | 8 | 00818 | Mon Jan 19 00:00:00 1970 PST
+ 819 | 509 | 00819_update9 | Tue Jan 20 00:00:00 1970 PST
+ 820 | 0 | 00820 | Wed Jan 21 00:00:00 1970 PST
+ 821 | 1 | 00821 | Thu Jan 22 00:00:00 1970 PST
+ 823 | 303 | 00823_update3 | Sat Jan 24 00:00:00 1970 PST
+ 824 | 4 | 00824 | Sun Jan 25 00:00:00 1970 PST
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST
+ 828 | 8 | 00828 | Thu Jan 29 00:00:00 1970 PST
+ 829 | 509 | 00829_update9 | Fri Jan 30 00:00:00 1970 PST
+ 830 | 0 | 00830 | Sat Jan 31 00:00:00 1970 PST
+ 831 | 1 | 00831 | Sun Feb 01 00:00:00 1970 PST
+ 833 | 303 | 00833_update3 | Tue Feb 03 00:00:00 1970 PST
+ 834 | 4 | 00834 | Wed Feb 04 00:00:00 1970 PST
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST
+ 838 | 8 | 00838 | Sun Feb 08 00:00:00 1970 PST
+ 839 | 509 | 00839_update9 | Mon Feb 09 00:00:00 1970 PST
+ 840 | 0 | 00840 | Tue Feb 10 00:00:00 1970 PST
+ 841 | 1 | 00841 | Wed Feb 11 00:00:00 1970 PST
+ 843 | 303 | 00843_update3 | Fri Feb 13 00:00:00 1970 PST
+ 844 | 4 | 00844 | Sat Feb 14 00:00:00 1970 PST
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST
+ 848 | 8 | 00848 | Wed Feb 18 00:00:00 1970 PST
+ 849 | 509 | 00849_update9 | Thu Feb 19 00:00:00 1970 PST
+ 850 | 0 | 00850 | Fri Feb 20 00:00:00 1970 PST
+ 851 | 1 | 00851 | Sat Feb 21 00:00:00 1970 PST
+ 853 | 303 | 00853_update3 | Mon Feb 23 00:00:00 1970 PST
+ 854 | 4 | 00854 | Tue Feb 24 00:00:00 1970 PST
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST
+ 858 | 8 | 00858 | Sat Feb 28 00:00:00 1970 PST
+ 859 | 509 | 00859_update9 | Sun Mar 01 00:00:00 1970 PST
+ 860 | 0 | 00860 | Mon Mar 02 00:00:00 1970 PST
+ 861 | 1 | 00861 | Tue Mar 03 00:00:00 1970 PST
+ 863 | 303 | 00863_update3 | Thu Mar 05 00:00:00 1970 PST
+ 864 | 4 | 00864 | Fri Mar 06 00:00:00 1970 PST
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST
+ 868 | 8 | 00868 | Tue Mar 10 00:00:00 1970 PST
+ 869 | 509 | 00869_update9 | Wed Mar 11 00:00:00 1970 PST
+ 870 | 0 | 00870 | Thu Mar 12 00:00:00 1970 PST
+ 871 | 1 | 00871 | Fri Mar 13 00:00:00 1970 PST
+ 873 | 303 | 00873_update3 | Sun Mar 15 00:00:00 1970 PST
+ 874 | 4 | 00874 | Mon Mar 16 00:00:00 1970 PST
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST
+ 878 | 8 | 00878 | Fri Mar 20 00:00:00 1970 PST
+ 879 | 509 | 00879_update9 | Sat Mar 21 00:00:00 1970 PST
+ 880 | 0 | 00880 | Sun Mar 22 00:00:00 1970 PST
+ 881 | 1 | 00881 | Mon Mar 23 00:00:00 1970 PST
+ 883 | 303 | 00883_update3 | Wed Mar 25 00:00:00 1970 PST
+ 884 | 4 | 00884 | Thu Mar 26 00:00:00 1970 PST
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST
+ 888 | 8 | 00888 | Mon Mar 30 00:00:00 1970 PST
+ 889 | 509 | 00889_update9 | Tue Mar 31 00:00:00 1970 PST
+ 890 | 0 | 00890 | Wed Apr 01 00:00:00 1970 PST
+ 891 | 1 | 00891 | Thu Apr 02 00:00:00 1970 PST
+ 893 | 303 | 00893_update3 | Sat Apr 04 00:00:00 1970 PST
+ 894 | 4 | 00894 | Sun Apr 05 00:00:00 1970 PST
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST
+ 898 | 8 | 00898 | Thu Apr 09 00:00:00 1970 PST
+ 899 | 509 | 00899_update9 | Fri Apr 10 00:00:00 1970 PST
+ 900 | 0 | 00900 | Thu Jan 01 00:00:00 1970 PST
+ 901 | 1 | 00901 | Fri Jan 02 00:00:00 1970 PST
+ 903 | 303 | 00903_update3 | Sun Jan 04 00:00:00 1970 PST
+ 904 | 4 | 00904 | Mon Jan 05 00:00:00 1970 PST
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST
+ 908 | 8 | 00908 | Fri Jan 09 00:00:00 1970 PST
+ 909 | 509 | 00909_update9 | Sat Jan 10 00:00:00 1970 PST
+ 910 | 0 | 00910 | Sun Jan 11 00:00:00 1970 PST
+ 911 | 1 | 00911 | Mon Jan 12 00:00:00 1970 PST
+ 913 | 303 | 00913_update3 | Wed Jan 14 00:00:00 1970 PST
+ 914 | 4 | 00914 | Thu Jan 15 00:00:00 1970 PST
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST
+ 918 | 8 | 00918 | Mon Jan 19 00:00:00 1970 PST
+ 919 | 509 | 00919_update9 | Tue Jan 20 00:00:00 1970 PST
+ 920 | 0 | 00920 | Wed Jan 21 00:00:00 1970 PST
+ 921 | 1 | 00921 | Thu Jan 22 00:00:00 1970 PST
+ 923 | 303 | 00923_update3 | Sat Jan 24 00:00:00 1970 PST
+ 924 | 4 | 00924 | Sun Jan 25 00:00:00 1970 PST
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST
+ 928 | 8 | 00928 | Thu Jan 29 00:00:00 1970 PST
+ 929 | 509 | 00929_update9 | Fri Jan 30 00:00:00 1970 PST
+ 930 | 0 | 00930 | Sat Jan 31 00:00:00 1970 PST
+ 931 | 1 | 00931 | Sun Feb 01 00:00:00 1970 PST
+ 933 | 303 | 00933_update3 | Tue Feb 03 00:00:00 1970 PST
+ 934 | 4 | 00934 | Wed Feb 04 00:00:00 1970 PST
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST
+ 938 | 8 | 00938 | Sun Feb 08 00:00:00 1970 PST
+ 939 | 509 | 00939_update9 | Mon Feb 09 00:00:00 1970 PST
+ 940 | 0 | 00940 | Tue Feb 10 00:00:00 1970 PST
+ 941 | 1 | 00941 | Wed Feb 11 00:00:00 1970 PST
+ 943 | 303 | 00943_update3 | Fri Feb 13 00:00:00 1970 PST
+ 944 | 4 | 00944 | Sat Feb 14 00:00:00 1970 PST
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST
+ 948 | 8 | 00948 | Wed Feb 18 00:00:00 1970 PST
+ 949 | 509 | 00949_update9 | Thu Feb 19 00:00:00 1970 PST
+ 950 | 0 | 00950 | Fri Feb 20 00:00:00 1970 PST
+ 951 | 1 | 00951 | Sat Feb 21 00:00:00 1970 PST
+ 953 | 303 | 00953_update3 | Mon Feb 23 00:00:00 1970 PST
+ 954 | 4 | 00954 | Tue Feb 24 00:00:00 1970 PST
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST
+ 958 | 8 | 00958 | Sat Feb 28 00:00:00 1970 PST
+ 959 | 509 | 00959_update9 | Sun Mar 01 00:00:00 1970 PST
+ 960 | 0 | 00960 | Mon Mar 02 00:00:00 1970 PST
+ 961 | 1 | 00961 | Tue Mar 03 00:00:00 1970 PST
+ 963 | 303 | 00963_update3 | Thu Mar 05 00:00:00 1970 PST
+ 964 | 4 | 00964 | Fri Mar 06 00:00:00 1970 PST
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST
+ 968 | 8 | 00968 | Tue Mar 10 00:00:00 1970 PST
+ 969 | 509 | 00969_update9 | Wed Mar 11 00:00:00 1970 PST
+ 970 | 0 | 00970 | Thu Mar 12 00:00:00 1970 PST
+ 971 | 1 | 00971 | Fri Mar 13 00:00:00 1970 PST
+ 973 | 303 | 00973_update3 | Sun Mar 15 00:00:00 1970 PST
+ 974 | 4 | 00974 | Mon Mar 16 00:00:00 1970 PST
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST
+ 978 | 8 | 00978 | Fri Mar 20 00:00:00 1970 PST
+ 979 | 509 | 00979_update9 | Sat Mar 21 00:00:00 1970 PST
+ 980 | 0 | 00980 | Sun Mar 22 00:00:00 1970 PST
+ 981 | 1 | 00981 | Mon Mar 23 00:00:00 1970 PST
+ 983 | 303 | 00983_update3 | Wed Mar 25 00:00:00 1970 PST
+ 984 | 4 | 00984 | Thu Mar 26 00:00:00 1970 PST
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST
+ 988 | 8 | 00988 | Mon Mar 30 00:00:00 1970 PST
+ 989 | 509 | 00989_update9 | Tue Mar 31 00:00:00 1970 PST
+ 990 | 0 | 00990 | Wed Apr 01 00:00:00 1970 PST
+ 991 | 1 | 00991 | Thu Apr 02 00:00:00 1970 PST
+ 993 | 303 | 00993_update3 | Sat Apr 04 00:00:00 1970 PST
+ 994 | 4 | 00994 | Sun Apr 05 00:00:00 1970 PST
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST
+ 998 | 8 | 00998 | Thu Apr 09 00:00:00 1970 PST
+ 999 | 509 | 00999_update9 | Fri Apr 10 00:00:00 1970 PST
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST
+ 1001 | 101 | 0000100001 |
+ 1003 | 403 | 0000300003_update3 |
+ 1004 | 104 | 0000400004 |
+ 1006 | 106 | 0000600006 |
+ 1007 | 507 | 0000700007_update7 |
+ 1008 | 108 | 0000800008 |
+ 1009 | 609 | 0000900009_update9 |
+ 1010 | 100 | 0001000010 |
+ 1011 | 101 | 0001100011 |
+ 1013 | 403 | 0001300013_update3 |
+ 1014 | 104 | 0001400014 |
+ 1016 | 106 | 0001600016 |
+ 1017 | 507 | 0001700017_update7 |
+ 1018 | 108 | 0001800018 |
+ 1019 | 609 | 0001900019_update9 |
+ 1020 | 100 | 0002000020 |
+ 1101 | 201 | aaa |
+ 1103 | 503 | ccc_update3 |
+ 1104 | 204 | ddd |
+(819 rows)
+
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Output: (ft2.tableoid)::regclass
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: 1200, 999, NULL::integer, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+(6 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = 'bar'::text WHERE (("C 1" = 1200))
+(4 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------
+ Delete on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE (("C 1" = 1200))
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+-- Test UPDATE/DELETE with RETURNING on a three-table join
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id - 1200, to_char(id, 'FM00000') FROM generate_series(1201, 1300) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.*, ft4.c1, ft4.c2, ft4.c3
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c3 = 'foo'::text FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (TRUE)) WHERE ((r2.c1 = r3.c1)) AND ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) RETURNING r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3
+(4 rows)
+
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*;
+ ft2 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | ft4 | c1 | c2 | c3
+--------------------------------+------+----+-----+----+----+----+------------+----+----------------+----+----+--------
+ (1206,6,foo,,,,"ft2 ",) | 1206 | 6 | foo | | | | ft2 | | (6,7,AAA006) | 6 | 7 | AAA006
+ (1212,12,foo,,,,"ft2 ",) | 1212 | 12 | foo | | | | ft2 | | (12,13,AAA012) | 12 | 13 | AAA012
+ (1218,18,foo,,,,"ft2 ",) | 1218 | 18 | foo | | | | ft2 | | (18,19,AAA018) | 18 | 19 | AAA018
+ (1224,24,foo,,,,"ft2 ",) | 1224 | 24 | foo | | | | ft2 | | (24,25,AAA024) | 24 | 25 | AAA024
+ (1230,30,foo,,,,"ft2 ",) | 1230 | 30 | foo | | | | ft2 | | (30,31,AAA030) | 30 | 31 | AAA030
+ (1236,36,foo,,,,"ft2 ",) | 1236 | 36 | foo | | | | ft2 | | (36,37,AAA036) | 36 | 37 | AAA036
+ (1242,42,foo,,,,"ft2 ",) | 1242 | 42 | foo | | | | ft2 | | (42,43,AAA042) | 42 | 43 | AAA042
+ (1248,48,foo,,,,"ft2 ",) | 1248 | 48 | foo | | | | ft2 | | (48,49,AAA048) | 48 | 49 | AAA048
+ (1254,54,foo,,,,"ft2 ",) | 1254 | 54 | foo | | | | ft2 | | (54,55,AAA054) | 54 | 55 | AAA054
+ (1260,60,foo,,,,"ft2 ",) | 1260 | 60 | foo | | | | ft2 | | (60,61,AAA060) | 60 | 61 | AAA060
+ (1266,66,foo,,,,"ft2 ",) | 1266 | 66 | foo | | | | ft2 | | (66,67,AAA066) | 66 | 67 | AAA066
+ (1272,72,foo,,,,"ft2 ",) | 1272 | 72 | foo | | | | ft2 | | (72,73,AAA072) | 72 | 73 | AAA072
+ (1278,78,foo,,,,"ft2 ",) | 1278 | 78 | foo | | | | ft2 | | (78,79,AAA078) | 78 | 79 | AAA078
+ (1284,84,foo,,,,"ft2 ",) | 1284 | 84 | foo | | | | ft2 | | (84,85,AAA084) | 84 | 85 | AAA084
+ (1290,90,foo,,,,"ft2 ",) | 1290 | 90 | foo | | | | ft2 | | (90,91,AAA090) | 90 | 91 | AAA090
+ (1296,96,foo,,,,"ft2 ",) | 1296 | 96 | foo | | | | ft2 | | (96,97,AAA096) | 96 | 97 | AAA096
+(16 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: 100
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1)))) WHERE ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) AND (((r1."C 1" % 10) = 0))
+(4 rows)
+
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100;
+ ?column?
+----------
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+(10 rows)
+
+DELETE FROM ft2 WHERE ft2.c1 > 1200;
+-- Test UPDATE with a MULTIEXPR sub-select
+-- (maybe someday this'll be remotely executable, but not today)
+EXPLAIN (verbose, costs off)
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 target
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2, c7 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.ft2 target
+ Output: $1, $2, (SubPlan 1 (returns $1,$2)), target.ctid, target.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1100)) FOR UPDATE
+ SubPlan 1 (returns $1,$2)
+ -> Foreign Scan on public.ft2 src
+ Output: (src.c2 * 10), src.c7
+ Remote SQL: SELECT c2, c7 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(9 rows)
+
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+UPDATE ft2 AS target SET (c2) = (
+ SELECT c2 / 10
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+-- Test UPDATE involving a join that can be pushed down,
+-- but a SET clause that can't be
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 d
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2 WHERE ctid = $1
+ -> Foreign Scan
+ Output: CASE WHEN (random() >= '0'::double precision) THEN d.c2 ELSE 0 END, d.ctid, d.*, t.*
+ Relations: (public.ft2 d) INNER JOIN (public.ft2 t)
+ Remote SQL: SELECT r1.c2, r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r1."C 1" > 1000)))) FOR UPDATE OF r1
+ -> Hash Join
+ Output: d.c2, d.ctid, d.*, t.*
+ Hash Cond: (d.c1 = t.c1)
+ -> Foreign Scan on public.ft2 d
+ Output: d.c2, d.ctid, d.*, d.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1000)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Hash
+ Output: t.*, t.c1
+ -> Foreign Scan on public.ft2 t
+ Output: t.*, t.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(17 rows)
+
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+-- Test UPDATE/DELETE with WHERE or JOIN/ON conditions containing
+-- user-defined operators/functions
+ALTER SERVER loopback OPTIONS (DROP extensions);
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id % 10, to_char(id, 'FM00000') FROM generate_series(2001, 2010) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft2
+ Output: 'bar'::text, ctid, ft2.*
+ Filter: (postgres_fdw_abs(ft2.c1) > 2000)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" FOR UPDATE
+(7 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-----+----+----+----+------------+----
+ 2001 | 1 | bar | | | | ft2 |
+ 2002 | 2 | bar | | | | ft2 |
+ 2003 | 3 | bar | | | | ft2 |
+ 2004 | 4 | bar | | | | ft2 |
+ 2005 | 5 | bar | | | | ft2 |
+ 2006 | 6 | bar | | | | ft2 |
+ 2007 | 7 | bar | | | | ft2 |
+ 2008 | 8 | bar | | | | ft2 |
+ 2009 | 9 | bar | | | | ft2 |
+ 2010 | 0 | bar | | | | ft2 |
+(10 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Nested Loop
+ Output: 'baz'::text, ft2.ctid, ft2.*, ft4.*, ft5.*, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Join Filter: (ft2.c2 === ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.*, ft2.c2
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Relations: (public.ft4) INNER JOIN (public.ft5)
+ Remote SQL: SELECT CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r3.c1, r3.c2, r3.c3 FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1))))
+ -> Hash Join
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(24 rows)
+
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3
+------+----+-----+----+----+----+------------+----+----+----+--------+----+----+--------
+ 2006 | 6 | baz | | | | ft2 | | 6 | 7 | AAA006 | 6 | 7 | AAA006
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ctid = $1 RETURNING "C 1", c2, c3
+ -> Foreign Scan
+ Output: ft2.ctid, ft4.*, ft5.*
+ Filter: (ft4.c1 === ft5.c1)
+ Relations: ((public.ft2) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r2.c1, r3.c1 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c2 = r2.c1)) AND ((r1."C 1" > 2000)))) INNER JOIN "S 1"."T 4" r3 ON (TRUE)) FOR UPDATE OF r1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft5.*, ft4.c1, ft5.c1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft4.c1
+ Join Filter: (ft2.c2 = ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.c2
+ Remote SQL: SELECT c2, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(22 rows)
+
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3;
+ c1 | c2 | c3
+------+----+-----
+ 2006 | 6 | baz
+(1 row)
+
+DELETE FROM ft2 WHERE ft2.c1 > 2000;
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- Test that trigger on remote table works as expected
+CREATE OR REPLACE FUNCTION "S 1".F_BRTRIG() RETURNS trigger AS $$
+BEGIN
+ NEW.c3 = NEW.c3 || '_trig_update';
+ RETURN NEW;
+END;
+$$ LANGUAGE plpgsql;
+CREATE TRIGGER t1_br_insert BEFORE INSERT OR UPDATE
+ ON "S 1"."T 1" FOR EACH ROW EXECUTE PROCEDURE "S 1".F_BRTRIG();
+INSERT INTO ft2 (c1,c2,c3) VALUES (1208, 818, 'fff') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+----+------------+----
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+(1 row)
+
+INSERT INTO ft2 (c1,c2,c3,c6) VALUES (1218, 818, 'ggg', '(--;') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+------+------------+----
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+(1 row)
+
+UPDATE ft2 SET c2 = c2 + 600 WHERE c1 % 10 = 8 AND c1 < 1200 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+------------------------+------------------------------+--------------------------+----+------------+-----
+ 8 | 608 | 00008_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 18 | 608 | 00018_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 28 | 608 | 00028_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 38 | 608 | 00038_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 48 | 608 | 00048_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 58 | 608 | 00058_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 68 | 608 | 00068_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 78 | 608 | 00078_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 88 | 608 | 00088_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 98 | 608 | 00098_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 108 | 608 | 00108_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 118 | 608 | 00118_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 128 | 608 | 00128_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 138 | 608 | 00138_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 148 | 608 | 00148_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 158 | 608 | 00158_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 168 | 608 | 00168_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 178 | 608 | 00178_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 188 | 608 | 00188_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 198 | 608 | 00198_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 208 | 608 | 00208_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 218 | 608 | 00218_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 228 | 608 | 00228_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 238 | 608 | 00238_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 248 | 608 | 00248_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 258 | 608 | 00258_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 268 | 608 | 00268_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 278 | 608 | 00278_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 288 | 608 | 00288_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 298 | 608 | 00298_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 308 | 608 | 00308_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 318 | 608 | 00318_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 328 | 608 | 00328_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 338 | 608 | 00338_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 348 | 608 | 00348_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 358 | 608 | 00358_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 368 | 608 | 00368_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 378 | 608 | 00378_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 388 | 608 | 00388_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 398 | 608 | 00398_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 408 | 608 | 00408_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 418 | 608 | 00418_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 428 | 608 | 00428_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 438 | 608 | 00438_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 448 | 608 | 00448_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 458 | 608 | 00458_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 468 | 608 | 00468_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 478 | 608 | 00478_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 488 | 608 | 00488_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 498 | 608 | 00498_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 508 | 608 | 00508_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 518 | 608 | 00518_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 528 | 608 | 00528_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 538 | 608 | 00538_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 548 | 608 | 00548_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 558 | 608 | 00558_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 568 | 608 | 00568_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 578 | 608 | 00578_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 588 | 608 | 00588_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 598 | 608 | 00598_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 608 | 608 | 00608_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 618 | 608 | 00618_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 628 | 608 | 00628_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 638 | 608 | 00638_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 648 | 608 | 00648_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 658 | 608 | 00658_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 668 | 608 | 00668_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 678 | 608 | 00678_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 688 | 608 | 00688_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 698 | 608 | 00698_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 708 | 608 | 00708_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 718 | 608 | 00718_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 728 | 608 | 00728_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 738 | 608 | 00738_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 748 | 608 | 00748_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 758 | 608 | 00758_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 768 | 608 | 00768_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 778 | 608 | 00778_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 788 | 608 | 00788_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 798 | 608 | 00798_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 808 | 608 | 00808_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 818 | 608 | 00818_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 828 | 608 | 00828_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 838 | 608 | 00838_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 848 | 608 | 00848_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 858 | 608 | 00858_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 868 | 608 | 00868_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 878 | 608 | 00878_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 888 | 608 | 00888_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 898 | 608 | 00898_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 908 | 608 | 00908_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 918 | 608 | 00918_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 928 | 608 | 00928_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 938 | 608 | 00938_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 948 | 608 | 00948_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 958 | 608 | 00958_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 968 | 608 | 00968_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 978 | 608 | 00978_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 988 | 608 | 00988_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 998 | 608 | 00998_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 1008 | 708 | 0000800008_trig_update | | | | ft2 |
+ 1018 | 708 | 0001800018_trig_update | | | | ft2 |
+(102 rows)
+
+-- Test errors thrown on remote side during update
+ALTER TABLE "S 1"."T 1" ADD CONSTRAINT c2positive CHECK (c2 >= 0);
+INSERT INTO ft1(c1, c2) VALUES(11, 12); -- duplicate key
+ERROR: duplicate key value violates unique constraint "t1_pkey"
+DETAIL: Key ("C 1")=(11) already exists.
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT DO NOTHING; -- works
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO NOTHING; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO UPDATE SET c3 = 'ffg'; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+-- Test savepoint/rollback behavior
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+begin;
+update ft2 set c2 = 42 where c2 = 0;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 42 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s1;
+update ft2 set c2 = 44 where c2 = 4;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s1;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s2;
+update ft2 set c2 = 46 where c2 = 6;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 42 | 100
+ 44 | 100
+ 46 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+rollback to savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s3;
+update ft2 set c2 = -2 where c2 = 42 and c1 = 10; -- fail on remote side
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (10, -2, 00010_trig_update_trig_update, 1970-01-11 08:00:00+00, 1970-01-11 00:00:00, 0, 0 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (-2) WHERE ((c2 = 42)) AND (("C 1" = 10))
+rollback to savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+-- none of the above is committed yet remotely
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+commit;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+VACUUM ANALYZE "S 1"."T 1";
+-- Above DMLs add data with c6 as NULL in ft1, so test ORDER BY NULLS LAST and NULLs
+-- FIRST behavior here.
+-- ORDER BY DESC NULLS LAST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 795::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+------+------------+-----
+ 960 | 42 | 00960_trig_update | Mon Mar 02 00:00:00 1970 PST | Mon Mar 02 00:00:00 1970 | 0 | 0 | foo
+ 970 | 42 | 00970_trig_update | Thu Mar 12 00:00:00 1970 PST | Thu Mar 12 00:00:00 1970 | 0 | 0 | foo
+ 980 | 42 | 00980_trig_update | Sun Mar 22 00:00:00 1970 PST | Sun Mar 22 00:00:00 1970 | 0 | 0 | foo
+ 990 | 42 | 00990_trig_update | Wed Apr 01 00:00:00 1970 PST | Wed Apr 01 00:00:00 1970 | 0 | 0 | foo
+ 1000 | 42 | 01000_trig_update | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 1001 | 101 | 0000100001 | | | | ft2 |
+ 1003 | 403 | 0000300003_update3 | | | | ft2 |
+ 1004 | 104 | 0000400004 | | | | ft2 |
+ 1006 | 106 | 0000600006 | | | | ft2 |
+(10 rows)
+
+-- ORDER BY DESC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+------------------------------+--------------------------+----+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | ft2 | foo
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST | Tue Jan 20 00:00:00 1970 | 9 | ft2 | foo
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST | Fri Jan 30 00:00:00 1970 | 9 | ft2 | foo
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST | Mon Feb 09 00:00:00 1970 | 9 | ft2 | foo
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST | Thu Feb 19 00:00:00 1970 | 9 | ft2 | foo
+(10 rows)
+
+-- ORDER BY ASC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 ASC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-------------------+------------------------------+--------------------------+------+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 10 | 42 | 00010_trig_update | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+ 20 | 42 | 00020_trig_update | Wed Jan 21 00:00:00 1970 PST | Wed Jan 21 00:00:00 1970 | 0 | 0 | foo
+ 30 | 42 | 00030_trig_update | Sat Jan 31 00:00:00 1970 PST | Sat Jan 31 00:00:00 1970 | 0 | 0 | foo
+ 40 | 42 | 00040_trig_update | Tue Feb 10 00:00:00 1970 PST | Tue Feb 10 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- ===================================================================
+-- test check constraints
+-- ===================================================================
+-- Consistent check constraints provide consistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- check constraint is enforced on the remote side, not locally
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
+-- But inconsistent check constraints provide inconsistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 821
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- local check constraint is not actually enforced
+INSERT INTO ft1(c1, c2) VALUES(1111, 2);
+UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
+-- ===================================================================
+-- test WITH CHECK OPTION constraints
+-- ===================================================================
+CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
+CREATE TABLE base_tbl (a int, b int);
+ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE VIEW rw_view AS SELECT * FROM foreign_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT foreign_tbl.a,
+ foreign_tbl.b
+ FROM foreign_tbl
+ WHERE foreign_tbl.a < foreign_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 5
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 15
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 5), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 15), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP TRIGGER row_before_insupd_trigger ON base_tbl;
+DROP TABLE base_tbl;
+-- test WCO for partitions
+CREATE TABLE child_tbl (a int, b int);
+ALTER TABLE child_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON child_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'child_tbl');
+CREATE TABLE parent_tbl (a int, b int) PARTITION BY RANGE(a);
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+-- Detach and re-attach once, to stress the concurrent detach case.
+ALTER TABLE parent_tbl DETACH PARTITION foreign_tbl CONCURRENTLY;
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+CREATE VIEW rw_view AS SELECT * FROM parent_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT parent_tbl.a,
+ parent_tbl.b
+ FROM parent_tbl
+ WHERE parent_tbl.a < parent_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 5
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 15
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 5), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 15), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------
+ Insert on public.parent_tbl
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+DROP TRIGGER row_before_insupd_trigger ON child_tbl;
+DROP TABLE parent_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP FUNCTION row_before_insupd_trigfunc;
+-- ===================================================================
+-- test serial columns (ie, sequence-based defaults)
+-- ===================================================================
+create table loc1 (f1 serial, f2 text);
+alter table loc1 set (autovacuum_enabled = 'false');
+create foreign table rem1 (f1 serial, f2 text)
+ server loopback options(table_name 'loc1');
+select pg_catalog.setval('rem1_f1_seq', 10, false);
+ setval
+--------
+ 10
+(1 row)
+
+insert into loc1(f2) values('hi');
+insert into rem1(f2) values('hi remote');
+insert into loc1(f2) values('bye');
+insert into rem1(f2) values('bye remote');
+select * from loc1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+select * from rem1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+-- ===================================================================
+-- test generated columns
+-- ===================================================================
+create table gloc1 (
+ a int,
+ b int generated always as (a * 2) stored);
+alter table gloc1 set (autovacuum_enabled = 'false');
+create foreign table grem1 (
+ a int,
+ b int generated always as (a * 2) stored)
+ server loopback options(table_name 'gloc1');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+explain (verbose, costs off)
+update grem1 set a = 22 where a = 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.grem1
+ Remote SQL: UPDATE public.gloc1 SET a = $2, b = DEFAULT WHERE ctid = $1
+ -> Foreign Scan on public.grem1
+ Output: 22, ctid, grem1.*
+ Remote SQL: SELECT a, b, ctid FROM public.gloc1 WHERE ((a = 2)) FOR UPDATE
+(5 rows)
+
+update grem1 set a = 22 where a = 2;
+select * from gloc1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+select * from grem1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+delete from grem1;
+-- test copy from
+copy grem1 from stdin;
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+-- test batch insert
+alter server loopback options (add batch_size '10');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 10
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test local triggers
+-- ===================================================================
+-- Trigger functions "borrowed" from triggers regress test.
+CREATE FUNCTION trigger_func() RETURNS trigger LANGUAGE plpgsql AS $$
+BEGIN
+ RAISE NOTICE 'trigger_func(%) called: action = %, when = %, level = %',
+ TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN NULL;
+END;$$;
+CREATE TRIGGER trig_stmt_before BEFORE DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE TRIGGER trig_stmt_after AFTER DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE OR REPLACE FUNCTION trigger_data() RETURNS trigger
+LANGUAGE plpgsql AS $$
+
+declare
+ oldnew text[];
+ relid text;
+ argstr text;
+begin
+
+ relid := TG_relid::regclass;
+ argstr := '';
+ for i in 0 .. TG_nargs - 1 loop
+ if i > 0 then
+ argstr := argstr || ', ';
+ end if;
+ argstr := argstr || TG_argv[i];
+ end loop;
+
+ RAISE NOTICE '%(%) % % % ON %',
+ tg_name, argstr, TG_when, TG_level, TG_OP, relid;
+ oldnew := '{}'::text[];
+ if TG_OP != 'INSERT' then
+ oldnew := array_append(oldnew, format('OLD: %s', OLD));
+ end if;
+
+ if TG_OP != 'DELETE' then
+ oldnew := array_append(oldnew, format('NEW: %s', NEW));
+ end if;
+
+ RAISE NOTICE '%', array_to_string(oldnew, ',');
+
+ if TG_OP = 'DELETE' then
+ return OLD;
+ else
+ return NEW;
+ end if;
+end;
+$$;
+-- Test basic functionality
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+delete from rem1;
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = AFTER, level = STATEMENT
+insert into rem1 values(1,'insert');
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+update rem1 set f2 = f2 || f2;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+truncate rem1;
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = BEFORE, level = STATEMENT
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = AFTER, level = STATEMENT
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_stmt_before ON rem1;
+DROP TRIGGER trig_stmt_after ON rem1;
+DELETE from rem1;
+-- Test multiple AFTER ROW triggers on a foreign table
+CREATE TRIGGER trig_row_after1
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after2
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+insert into rem1 values(1,'insert');
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+update rem1 set f2 = f2 || f2;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+delete from rem1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+-- cleanup
+DROP TRIGGER trig_row_after1 ON rem1;
+DROP TRIGGER trig_row_after2 ON rem1;
+-- Test WHEN conditions
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_insupd
+AFTER INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Insert or update not matching: nothing happens
+INSERT INTO rem1 values(1, 'insert');
+UPDATE rem1 set f2 = 'test';
+-- Insert or update matching: triggers are fired
+INSERT INTO rem1 values(2, 'update');
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+UPDATE rem1 set f2 = 'update update' where f1 = '2';
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Trigger is fired for f1=2, not for f1=1
+DELETE FROM rem1;
+NOTICE: trig_row_before_delete(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+NOTICE: trig_row_after_delete(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+-- cleanup
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_after_insupd ON rem1;
+DROP TRIGGER trig_row_before_delete ON rem1;
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- Test various RETURN statements in BEFORE triggers.
+CREATE FUNCTION trig_row_before_insupdate() RETURNS TRIGGER AS $$
+ BEGIN
+ NEW.f2 := NEW.f2 || ' triggered !';
+ RETURN NEW;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+-- The new values should have 'triggered' appended
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------
+ insert triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+ 2 | insert triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------
+ 1 | triggered !
+ 2 | triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------
+ skidoo triggered !
+ skidoo triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | skidoo triggered !
+ 2 | skidoo triggered !
+(2 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f1 = 10; -- all columns should be transmitted
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: 10, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+UPDATE rem1 set f1 = 10;
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 10 | skidoo triggered ! triggered !
+ 10 | skidoo triggered ! triggered !
+(2 rows)
+
+DELETE FROM rem1;
+-- Add a second trigger, to check that the changes are propagated correctly
+-- from trigger to trigger
+CREATE TRIGGER trig_row_before_insupd2
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------------------
+ insert triggered ! triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+ 2 | insert triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------
+ 1 | triggered ! triggered !
+ 2 | triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------------------
+ skidoo triggered ! triggered !
+ skidoo triggered ! triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | skidoo triggered ! triggered !
+ 2 | skidoo triggered ! triggered !
+(2 rows)
+
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_before_insupd2 ON rem1;
+DELETE from rem1;
+INSERT INTO rem1 VALUES (1, 'test');
+-- Test with a trigger returning NULL
+CREATE FUNCTION trig_null() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_null
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_null();
+-- Nothing should have changed.
+INSERT INTO rem1 VALUES (2, 'test2');
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+UPDATE rem1 SET f2 = 'test2';
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DELETE from rem1;
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DROP TRIGGER trig_null ON rem1;
+DELETE from rem1;
+-- Test a combination of local and remote triggers
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_local_before BEFORE INSERT OR UPDATE ON loc1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1(f2) VALUES ('test');
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (12,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (12,"test triggered !")
+UPDATE rem1 SET f2 = 'testo';
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,testo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,"testo triggered !")
+-- Test returning a system attribute
+INSERT INTO rem1(f2) VALUES ('test') RETURNING ctid;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (13,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (13,"test triggered !")
+ ctid
+--------
+ (0,25)
+(1 row)
+
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_local_before ON loc1;
+-- Test direct foreign table modification functionality
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1 WHERE false; -- currently can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Result
+ Output: ctid
+ One-Time Filter: false
+(5 rows)
+
+-- Test with statement-level triggers
+CREATE TRIGGER trig_stmt_before
+ BEFORE DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_before ON rem1;
+CREATE TRIGGER trig_stmt_after
+ AFTER DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_after ON rem1;
+-- Test with row-level ON INSERT triggers
+CREATE TRIGGER trig_row_before_insert
+BEFORE INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_insert ON rem1;
+CREATE TRIGGER trig_row_after_insert
+AFTER INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_insert ON rem1;
+-- Test with row-level ON UPDATE triggers
+CREATE TRIGGER trig_row_before_update
+BEFORE UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_update ON rem1;
+CREATE TRIGGER trig_row_after_update
+AFTER UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = $2 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_update ON rem1;
+-- Test with row-level ON DELETE triggers
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_before_delete ON rem1;
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- ===================================================================
+-- test inheritance features
+-- ===================================================================
+CREATE TABLE a (aa TEXT);
+CREATE TABLE loct (aa TEXT, bb TEXT);
+ALTER TABLE a SET (autovacuum_enabled = 'false');
+ALTER TABLE loct SET (autovacuum_enabled = 'false');
+CREATE FOREIGN TABLE b (bb TEXT) INHERITS (a)
+ SERVER loopback OPTIONS (table_name 'loct');
+INSERT INTO a(aa) VALUES('aaa');
+INSERT INTO a(aa) VALUES('aaaa');
+INSERT INTO a(aa) VALUES('aaaaa');
+INSERT INTO b(aa) VALUES('bbb');
+INSERT INTO b(aa) VALUES('bbbb');
+INSERT INTO b(aa) VALUES('bbbbb');
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+(3 rows)
+
+UPDATE a SET aa = 'zzzzzz' WHERE aa LIKE 'aaaa%';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE b SET aa = 'new';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | new
+ b | new
+ b | new
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-----+----
+ b | new |
+ b | new |
+ b | new |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE a SET aa = 'newtoo';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+ b | newtoo
+ b | newtoo
+ b | newtoo
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+--------+----
+ b | newtoo |
+ b | newtoo |
+ b | newtoo |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+(3 rows)
+
+DELETE FROM a;
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+----+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+DROP TABLE a CASCADE;
+NOTICE: drop cascades to foreign table b
+DROP TABLE loct;
+-- Check SELECT FOR UPDATE/SHARE with an inherited source table
+create table loct1 (f1 int, f2 int, f3 int);
+create table loct2 (f1 int, f2 int, f3 int);
+alter table loct1 set (autovacuum_enabled = 'false');
+alter table loct2 set (autovacuum_enabled = 'false');
+create table foo (f1 int, f2 int);
+create foreign table foo2 (f3 int) inherits (foo)
+ server loopback options (table_name 'loct1');
+create table bar (f1 int, f2 int);
+create foreign table bar2 (f3 int) inherits (bar)
+ server loopback options (table_name 'loct2');
+alter table foo set (autovacuum_enabled = 'false');
+alter table bar set (autovacuum_enabled = 'false');
+insert into foo values(1,1);
+insert into foo values(3,3);
+insert into foo2 values(2,2,2);
+insert into foo2 values(4,4,4);
+insert into bar values(1,11);
+insert into bar values(2,22);
+insert into bar values(6,66);
+insert into bar2 values(3,33,33);
+insert into bar2 values(4,44,44);
+insert into bar2 values(7,77,77);
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for update;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for update;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for share;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for share;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+-- Now check SELECT FOR UPDATE/SHARE with an inherited source table,
+-- where the parent is itself a foreign table
+create table loct4 (f1 int, f2 int, f3 int);
+create foreign table foo2child (f3 int) inherits (foo2)
+ server loopback options (table_name 'loct4');
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct1
+ -> Foreign Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct4
+(24 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop foreign table foo2child;
+-- And with a local child relation of the foreign table parent
+create table foo2child (f3 int) inherits (foo2);
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.ctid, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+ -> Seq Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.ctid, foo2_2.tableoid
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop table foo2child;
+-- Check UPDATE with inherited target and an inherited source table
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Hash Join
+ Output: (bar.f2 + 100), foo.ctid, bar.tableoid, bar.ctid, (NULL::record), foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(25 rows)
+
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 111
+ bar | 2 | 122
+ bar | 6 | 66
+ bar2 | 3 | 133
+ bar2 | 4 | 144
+ bar2 | 7 | 77
+(6 rows)
+
+-- Check UPDATE with inherited target and an appendrel subquery
+explain (verbose, costs off)
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Merge Join
+ Output: (bar.f2 + 100), (ROW(foo.f1)), bar.tableoid, bar.ctid, (NULL::record)
+ Merge Cond: (bar.f1 = foo.f1)
+ -> Sort
+ Output: bar.f2, bar.f1, bar.tableoid, bar.ctid, (NULL::record)
+ Sort Key: bar.f1
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Sort
+ Output: (ROW(foo.f1)), foo.f1
+ Sort Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: ROW(foo.f1), foo.f1
+ -> Foreign Scan on public.foo2 foo_1
+ Output: ROW(foo_1.f1), foo_1.f1
+ Remote SQL: SELECT f1 FROM public.loct1
+ -> Seq Scan on public.foo foo_2
+ Output: ROW((foo_2.f1 + 3)), (foo_2.f1 + 3)
+ -> Foreign Scan on public.foo2 foo_3
+ Output: ROW((foo_3.f1 + 3)), (foo_3.f1 + 3)
+ Remote SQL: SELECT f1 FROM public.loct1
+(30 rows)
+
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 211
+ bar | 2 | 222
+ bar | 6 | 166
+ bar2 | 3 | 233
+ bar2 | 4 | 244
+ bar2 | 7 | 177
+(6 rows)
+
+-- Test forcing the remote server to produce sorted data for a merge join,
+-- but the foreign table is an inheritance child.
+truncate table loct1;
+truncate table only foo;
+\set num_rows_foo 2000
+insert into loct1 select generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2);
+insert into foo select generate_series(1, :num_rows_foo, 2), generate_series(1, :num_rows_foo, 2);
+SET enable_hashjoin to false;
+SET enable_nestloop to false;
+alter foreign table foo2 options (use_remote_estimate 'true');
+create index i_loct1_f1 on loct1(f1);
+create index i_foo_f1 on foo(f1);
+analyze foo;
+analyze loct1;
+-- inner join; expressions in the clauses appear in the equivalence class list
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 20 | 20
+ 22 | 22
+ 24 | 24
+ 26 | 26
+ 28 | 28
+ 30 | 30
+ 32 | 32
+ 34 | 34
+ 36 | 36
+ 38 | 38
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Left Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 10 | 10
+ 11 |
+ 12 | 12
+ 13 |
+ 14 | 14
+ 15 |
+ 16 | 16
+ 17 |
+ 18 | 18
+ 19 |
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test that WHERE CURRENT OF is not supported
+begin;
+declare c cursor for select * from bar where f1 = 7;
+fetch from c;
+ f1 | f2
+----+-----
+ 7 | 177
+(1 row)
+
+update bar set f2 = null where current of c;
+ERROR: WHERE CURRENT OF is not supported for this table type
+rollback;
+explain (verbose, costs off)
+delete from foo where f1 < 5 returning *;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Delete on public.foo
+ Output: foo_1.f1, foo_1.f2
+ Delete on public.foo foo_1
+ Foreign Delete on public.foo2 foo_2
+ -> Append
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.tableoid, foo_1.ctid
+ Index Cond: (foo_1.f1 < 5)
+ -> Foreign Delete on public.foo2 foo_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ((f1 < 5)) RETURNING f1, f2
+(10 rows)
+
+delete from foo where f1 < 5 returning *;
+ f1 | f2
+----+----
+ 1 | 1
+ 3 | 3
+ 0 | 0
+ 2 | 2
+ 4 | 4
+(5 rows)
+
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Update on public.bar
+ Output: bar_1.f1, bar_1.f2
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = (f2 + 100) RETURNING f1, f2
+(11 rows)
+
+update bar set f2 = f2 + 100 returning *;
+ f1 | f2
+----+-----
+ 1 | 311
+ 2 | 322
+ 6 | 266
+ 3 | 333
+ 4 | 344
+ 7 | 277
+(6 rows)
+
+-- Test that UPDATE/DELETE with inherited target works with row-level triggers
+CREATE TRIGGER trig_row_before
+BEFORE UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+explain (verbose, costs off)
+update bar set f2 = f2 + 100;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f1 = $2, f2 = $3, f3 = $4 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+(12 rows)
+
+update bar set f2 = f2 + 100;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+explain (verbose, costs off)
+delete from bar where f2 < 400;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Delete on public.bar
+ Delete on public.bar bar_1
+ Foreign Delete on public.bar2 bar_2
+ Remote SQL: DELETE FROM public.loct2 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.tableoid, bar_1.ctid, NULL::record
+ Filter: (bar_1.f2 < 400)
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 WHERE ((f2 < 400)) FOR UPDATE
+(11 rows)
+
+delete from bar where f2 < 400;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+-- cleanup
+drop table foo cascade;
+NOTICE: drop cascades to foreign table foo2
+drop table bar cascade;
+NOTICE: drop cascades to foreign table bar2
+drop table loct1;
+drop table loct2;
+-- Test pushing down UPDATE/DELETE joins to the remote server
+create table parent (a int, b text);
+create table loct1 (a int, b text);
+create table loct2 (a int, b text);
+create foreign table remt1 (a int, b text)
+ server loopback options (table_name 'loct1');
+create foreign table remt2 (a int, b text)
+ server loopback options (table_name 'loct2');
+alter foreign table remt1 inherit parent;
+insert into remt1 values (1, 'foo');
+insert into remt1 values (2, 'bar');
+insert into remt2 values (1, 'foo');
+insert into remt2 values (2, 'bar');
+analyze remt1;
+analyze remt2;
+explain (verbose, costs off)
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.parent
+ Output: parent_1.a, parent_1.b, remt2.a, remt2.b
+ Update on public.parent parent_1
+ Foreign Update on public.remt1 parent_2
+ Remote SQL: UPDATE public.loct1 SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: (parent.b || remt2.b), remt2.*, remt2.a, remt2.b, parent.tableoid, parent.ctid, (NULL::record)
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.b, parent_1.a, parent_1.tableoid, parent_1.ctid, NULL::record
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.b, parent_2.a, parent_2.tableoid, parent_2.ctid, parent_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.b, remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.b, remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ a | b | a | b
+---+--------+---+-----
+ 1 | foofoo | 1 | foo
+ 2 | barbar | 2 | bar
+(2 rows)
+
+explain (verbose, costs off)
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Delete on public.parent
+ Output: parent_1.*
+ Delete on public.parent parent_1
+ Foreign Delete on public.remt1 parent_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: remt2.*, parent.tableoid, parent.ctid
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.a, parent_1.tableoid, parent_1.ctid
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.a, parent_2.tableoid, parent_2.ctid
+ Remote SQL: SELECT a, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ parent
+------------
+ (1,foofoo)
+ (2,barbar)
+(2 rows)
+
+-- cleanup
+drop foreign table remt1;
+drop foreign table remt2;
+drop table loct1;
+drop table loct2;
+drop table parent;
+-- ===================================================================
+-- test tuple routing for foreign-table partitions
+-- ===================================================================
+-- Test insert tuple routing
+create table itrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table itrtest attach partition remp1 for values in (1);
+alter table itrtest attach partition remp2 for values in (2);
+insert into itrtest values (1, 'foo');
+insert into itrtest values (1, 'bar') returning *;
+ a | b
+---+-----
+ 1 | bar
+(1 row)
+
+insert into itrtest values (2, 'baz');
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----
+ 2 | qux
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------
+ 1 | test1
+ 2 | test2
+(2 rows)
+
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from itrtest;
+-- MERGE ought to fail cleanly
+merge into itrtest using (select 1, 'foo') as source on (true)
+ when matched then do nothing;
+ERROR: cannot execute MERGE on relation "remp1"
+DETAIL: This operation is not supported for foreign tables.
+create unique index loct1_idx on loct1 (a);
+-- DO NOTHING without an inference specification is supported
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+-----
+ 1 | foo
+(1 row)
+
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+---
+(0 rows)
+
+-- But other cases are not supported
+insert into itrtest values (1, 'bar') on conflict (a) do nothing;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+insert into itrtest values (1, 'bar') on conflict (a) do update set b = excluded.b;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+delete from itrtest;
+drop index loct1_idx;
+-- Test that remote triggers work with insert tuple routing
+create function br_insert_trigfunc() returns trigger as $$
+begin
+ new.b := new.b || ' triggered !';
+ return new;
+end
+$$ language plpgsql;
+create trigger loct1_br_insert_trigger before insert on loct1
+ for each row execute procedure br_insert_trigfunc();
+create trigger loct2_br_insert_trigger before insert on loct2
+ for each row execute procedure br_insert_trigfunc();
+-- The new values are concatenated with ' triggered !'
+insert into itrtest values (1, 'foo') returning *;
+ a | b
+---+-----------------
+ 1 | foo triggered !
+(1 row)
+
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----------------
+ 2 | qux triggered !
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+with result as (insert into itrtest values (1, 'test1'), (2, 'test2') returning *) select * from result;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+drop trigger loct1_br_insert_trigger on loct1;
+drop trigger loct2_br_insert_trigger on loct2;
+drop table itrtest;
+drop table loct1;
+drop table loct2;
+-- Test update tuple routing
+create table utrtest (a int, b text) partition by list (a);
+create table loct (a int check (a in (1)), b text);
+create foreign table remp (a int check (a in (1)), b text) server loopback options (table_name 'loct');
+create table locp (a int check (a in (2)), b text);
+alter table utrtest attach partition remp for values in (1);
+alter table utrtest attach partition locp for values in (2);
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- It's not allowed to move a row from a partition that is foreign to another
+update utrtest set a = 2 where b = 'foo' returning *;
+ERROR: new row for relation "loct" violates check constraint "loct_a_check"
+DETAIL: Failing row contains (2, foo).
+CONTEXT: remote SQL command: UPDATE public.loct SET a = 2 WHERE ((b = 'foo')) RETURNING a, b
+-- But the reverse is allowed
+update utrtest set a = 1 where b = 'qux' returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- The executor should not let unexercised FDWs shut down
+update utrtest set a = 1 where b = 'foo';
+-- Test that remote triggers work with update tuple routing
+create trigger loct_br_insert_trigger before insert on loct
+ for each row execute procedure br_insert_trigfunc();
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition is a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 WHERE (((a = 1) OR (a = 2))) RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ Filter: ((utrtest_2.a = 1) OR (utrtest_2.a = 2))
+(10 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition isn't a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 2 returning *;
+ QUERY PLAN
+-------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ -> Seq Scan on public.locp utrtest_1
+ Output: 1, utrtest_1.tableoid, utrtest_1.ctid
+ Filter: (utrtest_1.a = 2)
+(6 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 2 returning *;
+ a | b
+---+-----------------
+ 1 | qux triggered !
+(1 row)
+
+drop trigger loct_br_insert_trigger on loct;
+-- We can move rows to a foreign partition that has been updated already,
+-- but can't move rows to a foreign partition that hasn't been updated yet
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- Test the former case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+(9 rows)
+
+update utrtest set a = 1 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ Update on public.locp utrtest_2
+ -> Hash Join
+ Output: 1, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, utrtest.*
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Foreign Scan on public.remp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, utrtest_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Seq Scan on public.locp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- Change the definition of utrtest so that the foreign partition get updated
+-- after the local partition
+delete from utrtest;
+alter table utrtest detach partition remp;
+drop foreign table remp;
+alter table loct drop constraint loct_a_check;
+alter table loct add check (a in (3));
+create foreign table remp (a int check (a in (3)), b text) server loopback options (table_name 'loct');
+alter table utrtest attach partition remp for values in (3);
+insert into utrtest values (2, 'qux');
+insert into utrtest values (3, 'xyzzy');
+-- Test the latter case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: 3, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = 3 RETURNING a, b
+(9 rows)
+
+update utrtest set a = 3 returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ -> Hash Join
+ Output: 3, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, (NULL::record)
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Scan on public.remp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, utrtest_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+drop table utrtest;
+drop table loct;
+-- Test copy tuple routing
+create table ctrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table ctrtest attach partition remp1 for values in (1);
+alter table ctrtest attach partition remp2 for values in (2);
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp2 | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-----+---
+ remp2 | qux | 2
+(1 row)
+
+-- Copying into foreign partitions directly should work as well
+copy remp1 from stdin;
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+(2 rows)
+
+delete from ctrtest;
+-- Test copy tuple routing with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from ctrtest;
+alter server loopback options (drop batch_size);
+drop table ctrtest;
+drop table loct1;
+drop table loct2;
+-- ===================================================================
+-- test COPY FROM
+-- ===================================================================
+create table loc2 (f1 int, f2 text);
+alter table loc2 set (autovacuum_enabled = 'false');
+create foreign table rem2 (f1 int, f2 text) server loopback options(table_name 'loc2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2, line 1: "-1 xyzzy"
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test local triggers
+create trigger trig_stmt_before before insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_stmt_after after insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+copy rem2 from stdin;
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop trigger trig_row_before on rem2;
+drop trigger trig_row_after on rem2;
+drop trigger trig_stmt_before on rem2;
+drop trigger trig_stmt_after on rem2;
+delete from rem2;
+create trigger trig_row_before_insert before insert on rem2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on rem2;
+delete from rem2;
+create trigger trig_null before insert on rem2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on rem2;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Test a combination of local and remote triggers
+create trigger rem2_trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger rem2_trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger loc2_trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+copy rem2 from stdin;
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,"foo triggered !")
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,"bar triggered !")
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger rem2_trig_row_before on rem2;
+drop trigger rem2_trig_row_after on rem2;
+drop trigger loc2_trig_row_before_insert on loc2;
+delete from rem2;
+-- test COPY FROM with foreign table created in the same transaction
+create table loc3 (f1 int, f2 text);
+begin;
+create foreign table rem3 (f1 int, f2 text)
+ server loopback options(table_name 'loc3');
+copy rem3 from stdin;
+commit;
+select * from rem3;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop foreign table rem3;
+drop table loc3;
+-- Test COPY FROM with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+ 3 | baz triggered !
+(3 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Check with zero-column foreign table; batch insert will be disabled
+alter table loc2 drop column f1;
+alter table loc2 drop column f2;
+alter table rem2 drop column f1;
+alter table rem2 drop column f2;
+copy rem2 from stdin;
+select * from rem2;
+--
+(3 rows)
+
+delete from rem2;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test for TRUNCATE
+-- ===================================================================
+CREATE TABLE tru_rtable0 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable0');
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(1,10) x);
+CREATE TABLE tru_ptable (id int) PARTITION BY HASH(id);
+CREATE TABLE tru_ptable__p0 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tru_rtable1 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable__p1 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback OPTIONS (table_name 'tru_rtable1');
+INSERT INTO tru_ptable (SELECT x FROM generate_series(11,20) x);
+CREATE TABLE tru_pk_table(id int primary key);
+CREATE TABLE tru_fk_table(fkey int references tru_pk_table(id));
+INSERT INTO tru_pk_table (SELECT x FROM generate_series(1,10) x);
+INSERT INTO tru_fk_table (SELECT x % 10 + 1 FROM generate_series(5,25) x);
+CREATE FOREIGN TABLE tru_pk_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_pk_table');
+CREATE TABLE tru_rtable_parent (id int);
+CREATE TABLE tru_rtable_child (id int);
+CREATE FOREIGN TABLE tru_ftable_parent (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_parent');
+CREATE FOREIGN TABLE tru_ftable_child () INHERITS (tru_ftable_parent)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_child');
+INSERT INTO tru_rtable_parent (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_rtable_child (SELECT x FROM generate_series(10, 18) x);
+-- normal truncate
+SELECT sum(id) FROM tru_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_ftable;
+SELECT count(*) FROM tru_rtable0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'truncatable' option
+ALTER SERVER loopback OPTIONS (ADD truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (ADD truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER SERVER loopback OPTIONS (DROP truncatable);
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+-- partitioned table with both local and foreign tables as partitions
+SELECT sum(id) FROM tru_ptable; -- 155
+ sum
+-----
+ 155
+(1 row)
+
+TRUNCATE tru_ptable;
+SELECT count(*) FROM tru_ptable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ptable__p0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable__p1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_rtable1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'CASCADE' option
+SELECT sum(id) FROM tru_pk_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_pk_ftable; -- failed by FK reference
+ERROR: cannot truncate a table referenced in a foreign key constraint
+DETAIL: Table "tru_fk_table" references "tru_pk_table".
+HINT: Truncate table "tru_fk_table" at the same time, or use TRUNCATE ... CASCADE.
+CONTEXT: remote SQL command: TRUNCATE public.tru_pk_table CONTINUE IDENTITY RESTRICT
+TRUNCATE tru_pk_ftable CASCADE;
+SELECT count(*) FROM tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_fk_table; -- also truncated,0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate two tables at a command
+INSERT INTO tru_ftable (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_pk_ftable (SELECT x FROM generate_series(3,10) x);
+SELECT count(*) from tru_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+TRUNCATE tru_ftable, tru_pk_ftable CASCADE;
+SELECT count(*) from tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate with ONLY clause
+-- Since ONLY is specified, the table tru_ftable_child that inherits
+-- tru_ftable_parent locally is not truncated.
+TRUNCATE ONLY tru_ftable_parent;
+SELECT sum(id) FROM tru_ftable_parent; -- 126
+ sum
+-----
+ 126
+(1 row)
+
+TRUNCATE tru_ftable_parent;
+SELECT count(*) FROM tru_ftable_parent; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- in case when remote table has inherited children
+CREATE TABLE tru_rtable0_child () INHERITS (tru_rtable0);
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(5,9) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(10,14) x);
+SELECT sum(id) FROM tru_ftable; -- 95
+ sum
+-----
+ 95
+(1 row)
+
+-- Both parent and child tables in the foreign server are truncated
+-- even though ONLY is specified because ONLY has no effect
+-- when truncating a foreign table.
+TRUNCATE ONLY tru_ftable;
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(21,25) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(26,30) x);
+SELECT sum(id) FROM tru_ftable; -- 255
+ sum
+-----
+ 255
+(1 row)
+
+TRUNCATE tru_ftable; -- truncate both of parent and child
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- cleanup
+DROP FOREIGN TABLE tru_ftable_parent, tru_ftable_child, tru_pk_ftable,tru_ftable__p1,tru_ftable;
+DROP TABLE tru_rtable0, tru_rtable1, tru_ptable, tru_ptable__p0, tru_pk_table, tru_fk_table,
+tru_rtable_parent,tru_rtable_child, tru_rtable0_child;
+-- ===================================================================
+-- test IMPORT FOREIGN SCHEMA
+-- ===================================================================
+CREATE SCHEMA import_source;
+CREATE TABLE import_source.t1 (c1 int, c2 varchar NOT NULL);
+CREATE TABLE import_source.t2 (c1 int default 42, c2 varchar NULL, c3 text collate "POSIX");
+CREATE TYPE typ1 AS (m1 int, m2 varchar);
+CREATE TABLE import_source.t3 (c1 timestamptz default now(), c2 typ1);
+CREATE TABLE import_source."x 4" (c1 float8, "C 2" text, c3 varchar(42));
+CREATE TABLE import_source."x 5" (c1 float8);
+ALTER TABLE import_source."x 5" DROP COLUMN c1;
+CREATE TABLE import_source."x 6" (c1 int, c2 int generated always as (c1 * 2) stored);
+CREATE TABLE import_source.t4 (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE import_source.t4_part PARTITION OF import_source.t4
+ FOR VALUES FROM (1) TO (100);
+CREATE TABLE import_source.t4_part2 PARTITION OF import_source.t4
+ FOR VALUES FROM (100) TO (200);
+CREATE SCHEMA import_dest1;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest1;
+\det+ import_dest1.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest1 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest1 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest1 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest1 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest1 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest1 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest1 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest1.*
+ Foreign table "import_dest1.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest1.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest1.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest1.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest1.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest1.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest1.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Options
+CREATE SCHEMA import_dest2;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest2
+ OPTIONS (import_default 'true');
+\det+ import_dest2.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest2 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest2 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest2 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest2 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest2 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest2 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest2 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest2.*
+ Foreign table "import_dest2.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest2.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | 42 | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest2.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | now() | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest2.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest2.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest2.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest2.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+CREATE SCHEMA import_dest3;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest3
+ OPTIONS (import_collate 'false', import_generated 'false', import_not_null 'false');
+\det+ import_dest3.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest3 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest3 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest3 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest3 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest3 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest3 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest3 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest3.*
+ Foreign table "import_dest3.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest3.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest3.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest3.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest3.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest3.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest3.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Check LIMIT TO and EXCEPT
+CREATE SCHEMA import_dest4;
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t1, nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+(2 rows)
+
+IMPORT FOREIGN SCHEMA import_source EXCEPT (t1, "x 4", nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest4 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest4 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+ import_dest4 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest4 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+-- Assorted error cases
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest4;
+ERROR: relation "t1" already exists
+CONTEXT: importing foreign table "t1"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO import_dest4;
+ERROR: schema "nonesuch" is not present on foreign server "loopback"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO notthere;
+ERROR: schema "notthere" does not exist
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER nowhere INTO notthere;
+ERROR: server "nowhere" does not exist
+-- Check case of a type present only on the remote server.
+-- We can fake this by dropping the type locally in our transaction.
+CREATE TYPE "Colors" AS ENUM ('red', 'green', 'blue');
+CREATE TABLE import_source.t5 (c1 int, c2 text collate "C", "Col" "Colors");
+CREATE SCHEMA import_dest5;
+BEGIN;
+DROP TYPE "Colors" CASCADE;
+NOTICE: drop cascades to column Col of table import_source.t5
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t5)
+ FROM SERVER loopback INTO import_dest5; -- ERROR
+ERROR: type "public.Colors" does not exist
+LINE 4: "Col" public."Colors" OPTIONS (column_name 'Col')
+ ^
+QUERY: CREATE FOREIGN TABLE t5 (
+ c1 integer OPTIONS (column_name 'c1'),
+ c2 text OPTIONS (column_name 'c2') COLLATE pg_catalog."C",
+ "Col" public."Colors" OPTIONS (column_name 'Col')
+) SERVER loopback
+OPTIONS (schema_name 'import_source', table_name 't5');
+CONTEXT: importing foreign table "t5"
+ROLLBACK;
+BEGIN;
+CREATE SERVER fetch101 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( fetch_size '101' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER fetch101 OPTIONS( SET fetch_size '202' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=202'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30000 ( x int ) SERVER fetch101 OPTIONS ( fetch_size '30000' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '60000');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=60000'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- ===================================================================
+-- test partitionwise joins
+-- ===================================================================
+SET enable_partitionwise_join=on;
+CREATE TABLE fprt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE fprt1_p1 (LIKE fprt1);
+CREATE TABLE fprt1_p2 (LIKE fprt1);
+ALTER TABLE fprt1_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt1_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt1_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 2) i;
+INSERT INTO fprt1_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 2) i;
+CREATE FOREIGN TABLE ftprt1_p1 PARTITION OF fprt1 FOR VALUES FROM (0) TO (250)
+ SERVER loopback OPTIONS (table_name 'fprt1_p1', use_remote_estimate 'true');
+CREATE FOREIGN TABLE ftprt1_p2 PARTITION OF fprt1 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (TABLE_NAME 'fprt1_p2');
+ANALYZE fprt1;
+ANALYZE fprt1_p1;
+ANALYZE fprt1_p2;
+CREATE TABLE fprt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE fprt2_p1 (LIKE fprt2);
+CREATE TABLE fprt2_p2 (LIKE fprt2);
+ALTER TABLE fprt2_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt2_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt2_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 3) i;
+INSERT INTO fprt2_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 3) i;
+CREATE FOREIGN TABLE ftprt2_p1 (b int, c varchar, a int)
+ SERVER loopback OPTIONS (table_name 'fprt2_p1', use_remote_estimate 'true');
+ALTER TABLE fprt2 ATTACH PARTITION ftprt2_p1 FOR VALUES FROM (0) TO (250);
+CREATE FOREIGN TABLE ftprt2_p2 PARTITION OF fprt2 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (table_name 'fprt2_p2', use_remote_estimate 'true');
+ANALYZE fprt2;
+ANALYZE fprt2_p1;
+ANALYZE fprt2_p2;
+-- inner join three tables
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t3.c
+ -> Append
+ -> Foreign Scan
+ Relations: ((ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)) INNER JOIN (ftprt1_p1 t3_1)
+ -> Foreign Scan
+ Relations: ((ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)) INNER JOIN (ftprt1_p2 t3_2)
+(7 rows)
+
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0003
+ 250 | 250 | 0005
+ 400 | 400 | 0008
+(4 rows)
+
+-- left outer join + nullable clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.a, fprt2.b, fprt2.c
+ Relations: (public.ftprt1_p1 t1) LEFT JOIN (public.ftprt2_p1 fprt2)
+ Remote SQL: SELECT r5.a, r6.b, r6.c FROM (public.fprt1_p1 r5 LEFT JOIN public.fprt2_p1 r6 ON (((r5.a = r6.b)) AND ((r5.b = r6.a)) AND ((r6.a < 10)))) WHERE ((r5.a < 10)) ORDER BY r5.a ASC NULLS LAST, r6.b ASC NULLS LAST, r6.c ASC NULLS LAST
+(4 rows)
+
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ a | b | c
+---+---+------
+ 0 | 0 | 0000
+ 2 | |
+ 4 | |
+ 6 | 6 | 0000
+ 8 | |
+(5 rows)
+
+-- with whole-row reference; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ QUERY PLAN
+--------------------------------------------------------
+ Sort
+ Sort Key: ((t1.*)::fprt1), ((t2.*)::fprt2)
+ -> Hash Full Join
+ Hash Cond: (t1.a = t2.b)
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+(11 rows)
+
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ wr | wr
+----------------+----------------
+ (0,0,0000) | (0,0,0000)
+ (50,50,0001) |
+ (100,100,0002) |
+ (150,150,0003) | (150,150,0003)
+ (200,200,0004) |
+ (250,250,0005) | (250,250,0005)
+ (300,300,0006) |
+ (350,350,0007) |
+ (400,400,0008) | (400,400,0008)
+ (450,450,0009) |
+ | (75,75,0001)
+ | (225,225,0004)
+ | (325,325,0006)
+ | (475,475,0009)
+(14 rows)
+
+-- join with lateral reference
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t1.b
+ -> Append
+ -> Foreign Scan
+ Relations: (ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)
+ -> Foreign Scan
+ Relations: (ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)
+(7 rows)
+
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+-- with PHVs, partitionwise join selected but no join pushdown
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: fprt1.a, fprt2.b
+ -> Append
+ -> Hash Full Join
+ Hash Cond: (fprt1_1.a = fprt2_1.b)
+ -> Foreign Scan on ftprt1_p1 fprt1_1
+ -> Hash
+ -> Foreign Scan on ftprt2_p1 fprt2_1
+ -> Hash Full Join
+ Hash Cond: (fprt1_2.a = fprt2_2.b)
+ -> Foreign Scan on ftprt1_p2 fprt1_2
+ -> Hash
+ -> Foreign Scan on ftprt2_p2 fprt2_2
+(13 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | phv | b | phv
+-----+--------+-----+--------
+ 0 | t1_phv | 0 | t2_phv
+ 50 | t1_phv | |
+ 100 | t1_phv | |
+ 150 | t1_phv | 150 | t2_phv
+ 200 | t1_phv | |
+ 250 | t1_phv | 250 | t2_phv
+ 300 | t1_phv | |
+ 350 | t1_phv | |
+ 400 | t1_phv | 400 | t2_phv
+ 450 | t1_phv | |
+ | | 75 | t2_phv
+ | | 225 | t2_phv
+ | | 325 | t2_phv
+ | | 475 | t2_phv
+(14 rows)
+
+-- test FOR UPDATE; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ QUERY PLAN
+--------------------------------------------------------------
+ LockRows
+ -> Sort
+ Sort Key: t1.a
+ -> Hash Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+(12 rows)
+
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+RESET enable_partitionwise_join;
+-- ===================================================================
+-- test partitionwise aggregates
+-- ===================================================================
+CREATE TABLE pagg_tab (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE pagg_tab_p1 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p2 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p3 (LIKE pagg_tab);
+INSERT INTO pagg_tab_p1 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 10;
+INSERT INTO pagg_tab_p2 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 20 and (i % 30) >= 10;
+INSERT INTO pagg_tab_p3 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 30 and (i % 30) >= 20;
+-- Create foreign partitions
+CREATE FOREIGN TABLE fpagg_tab_p1 PARTITION OF pagg_tab FOR VALUES FROM (0) TO (10) SERVER loopback OPTIONS (table_name 'pagg_tab_p1');
+CREATE FOREIGN TABLE fpagg_tab_p2 PARTITION OF pagg_tab FOR VALUES FROM (10) TO (20) SERVER loopback OPTIONS (table_name 'pagg_tab_p2');
+CREATE FOREIGN TABLE fpagg_tab_p3 PARTITION OF pagg_tab FOR VALUES FROM (20) TO (30) SERVER loopback OPTIONS (table_name 'pagg_tab_p3');
+ANALYZE pagg_tab;
+ANALYZE fpagg_tab_p1;
+ANALYZE fpagg_tab_p2;
+ANALYZE fpagg_tab_p3;
+-- When GROUP BY clause matches with PARTITION KEY.
+-- Plan with partitionwise aggregates is disabled
+SET enable_partitionwise_aggregate TO false;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> HashAggregate
+ Group Key: pagg_tab.a
+ Filter: (avg(pagg_tab.b) < '22'::numeric)
+ -> Append
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab_1
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_2
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_3
+(9 rows)
+
+-- Plan with partitionwise aggregates is enabled
+SET enable_partitionwise_aggregate TO true;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> Append
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p1 pagg_tab)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p2 pagg_tab_1)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p3 pagg_tab_2)
+(9 rows)
+
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | sum | min | count
+----+------+-----+-------
+ 0 | 2000 | 0 | 100
+ 1 | 2100 | 1 | 100
+ 10 | 2000 | 0 | 100
+ 11 | 2100 | 1 | 100
+ 20 | 2000 | 0 | 100
+ 21 | 2100 | 1 | 100
+(6 rows)
+
+-- Check with whole-row reference
+-- Should have all the columns in the target list for the given relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, (count(((t1.*)::pagg_tab)))
+ Sort Key: t1.a
+ -> Append
+ -> HashAggregate
+ Output: t1.a, count(((t1.*)::pagg_tab))
+ Group Key: t1.a
+ Filter: (avg(t1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p1 t1
+ Output: t1.a, t1.*, t1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p1
+ -> HashAggregate
+ Output: t1_1.a, count(((t1_1.*)::pagg_tab))
+ Group Key: t1_1.a
+ Filter: (avg(t1_1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p2 t1_1
+ Output: t1_1.a, t1_1.*, t1_1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p2
+ -> HashAggregate
+ Output: t1_2.a, count(((t1_2.*)::pagg_tab))
+ Group Key: t1_2.a
+ Filter: (avg(t1_2.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p3 t1_2
+ Output: t1_2.a, t1_2.*, t1_2.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p3
+(25 rows)
+
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | count
+----+-------
+ 0 | 100
+ 1 | 100
+ 10 | 100
+ 11 | 100
+ 20 | 100
+ 21 | 100
+(6 rows)
+
+-- When GROUP BY clause does not match with PARTITION KEY.
+EXPLAIN (COSTS OFF)
+SELECT b, avg(a), max(a), count(*) FROM pagg_tab GROUP BY b HAVING sum(a) < 700 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.b
+ -> Finalize HashAggregate
+ Group Key: pagg_tab.b
+ Filter: (sum(pagg_tab.a) < 700)
+ -> Append
+ -> Partial HashAggregate
+ Group Key: pagg_tab.b
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab
+ -> Partial HashAggregate
+ Group Key: pagg_tab_1.b
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_1
+ -> Partial HashAggregate
+ Group Key: pagg_tab_2.b
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_2
+(15 rows)
+
+-- ===================================================================
+-- access rights and superuser
+-- ===================================================================
+-- Non-superuser cannot create a FDW without a password in the connstr
+CREATE ROLE regress_nosuper NOSUPERUSER;
+GRANT USAGE ON FOREIGN DATA WRAPPER postgres_fdw TO regress_nosuper;
+SET ROLE regress_nosuper;
+SHOW is_superuser;
+ is_superuser
+--------------
+ off
+(1 row)
+
+-- This will be OK, we can create the FDW
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback_nopw FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+-- But creation of user mappings for non-superusers should fail
+CREATE USER MAPPING FOR public SERVER loopback_nopw;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+CREATE FOREIGN TABLE pg_temp.ft1_nopw (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback_nopw OPTIONS (schema_name 'public', table_name 'ft1');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+-- If we add a password to the connstr it'll fail, because we don't allow passwords
+-- in connstrs only in user mappings.
+ALTER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+ERROR: invalid option "password"
+HINT: Perhaps you meant the option "passfile".
+-- If we add a password for our user mapping instead, we should get a different
+-- error because the password wasn't actually *used* when we run with trust auth.
+--
+-- This won't work with installcheck, but neither will most of the FDW checks.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+-- Unpriv user cannot make the mapping passwordless
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+ERROR: password_required=false is superuser-only
+HINT: User mappings with the password_required option set to false may only be created or modified by the superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+RESET ROLE;
+-- But the superuser can
+ALTER USER MAPPING FOR regress_nosuper SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+SET ROLE regress_nosuper;
+-- Should finally work now
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- unpriv user also cannot set sslcert / sslkey on the user mapping
+-- first set password_required so we see the right error messages
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (SET password_required 'true');
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslcert 'foo.crt');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslkey 'foo.key');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+-- We're done with the role named after a specific user and need to check the
+-- changes to the public mapping.
+DROP USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+-- This will fail again as it'll resolve the user mapping for public, which
+-- lacks password_required=false
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+RESET ROLE;
+-- The user mapping for public is passwordless and lacks the password_required=false
+-- mapping option, but will work because the current user is a superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- cleanup
+DROP USER MAPPING FOR public SERVER loopback_nopw;
+DROP OWNED BY regress_nosuper;
+DROP ROLE regress_nosuper;
+-- Clean-up
+RESET enable_partitionwise_aggregate;
+-- Two-phase transactions are not supported.
+BEGIN;
+SELECT count(*) FROM ft1;
+ count
+-------
+ 822
+(1 row)
+
+-- error here
+PREPARE TRANSACTION 'fdw_tpc';
+ERROR: cannot PREPARE a transaction that has operated on postgres_fdw foreign tables
+ROLLBACK;
+WARNING: there is no transaction in progress
+-- ===================================================================
+-- reestablish new connection
+-- ===================================================================
+-- Change application_name of remote connection to special one
+-- so that we can easily terminate the connection later.
+ALTER SERVER loopback OPTIONS (application_name 'fdw_retry_check');
+-- If debug_discard_caches is active, it results in
+-- dropping remote connections after every transaction, making it
+-- impossible to test termination meaningfully. So turn that off
+-- for this test.
+SET debug_discard_caches = 0;
+-- Make sure we have a remote connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- This query should detect the broken connection when starting new remote
+-- transaction, reestablish new connection, and then succeed.
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- If we detect the broken connection when starting a new remote
+-- subtransaction, we should fail instead of establishing a new connection.
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+SAVEPOINT s;
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT 1 FROM ft1 LIMIT 1; -- should fail
+ERROR: 08006
+\set VERBOSITY default
+COMMIT;
+RESET debug_discard_caches;
+-- =============================================================================
+-- test connection invalidation cases and postgres_fdw_get_connections function
+-- =============================================================================
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- This test case is for closing the connection in pgfdw_xact_callback
+BEGIN;
+-- Connection xact depth becomes 1 i.e. the connection is in midst of the xact.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT 1 FROM ft7 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback3 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback3
+(2 rows)
+
+-- Connections are not closed at the end of the alter and drop statements.
+-- That's because the connections are in midst of this xact,
+-- they are just marked as invalid in pgfdw_inval_callback.
+ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
+DROP SERVER loopback3 CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to user mapping for public on server loopback3
+drop cascades to foreign table ft7
+-- List all the existing cached connections. loopback and loopback3
+-- should be output as invalid connections. Also the server name for
+-- loopback3 should be NULL because the server was dropped.
+SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | valid
+-------------+-------
+ loopback | f
+ | f
+(2 rows)
+
+-- The invalid connections get closed in pgfdw_xact_callback during commit.
+COMMIT;
+-- All cached connections were closed while committing above xact, so no
+-- records should be output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+(0 rows)
+
+-- =======================================================================
+-- test postgres_fdw_disconnect and postgres_fdw_disconnect_all functions
+-- =======================================================================
+BEGIN;
+-- Ensure to cache loopback connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Ensure to cache loopback2 connection.
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Issue a warning and return false as loopback connection is still in use and
+-- can not be closed.
+SELECT postgres_fdw_disconnect('loopback');
+WARNING: cannot close connection for server "loopback" because it is still in use
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Return false as connections are still in use, warnings are issued.
+-- But disable warnings temporarily because the order of them is not stable.
+SET client_min_messages = 'ERROR';
+SELECT postgres_fdw_disconnect_all();
+ postgres_fdw_disconnect_all
+-----------------------------
+ f
+(1 row)
+
+RESET client_min_messages;
+COMMIT;
+-- Ensure that loopback2 connection is closed.
+SELECT 1 FROM postgres_fdw_disconnect('loopback2');
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT server_name FROM postgres_fdw_get_connections() WHERE server_name = 'loopback2';
+ server_name
+-------------
+(0 rows)
+
+-- Return false as loopback2 connection is closed already.
+SELECT postgres_fdw_disconnect('loopback2');
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- Return an error as there is no foreign server with given name.
+SELECT postgres_fdw_disconnect('unknownserver');
+ERROR: server "unknownserver" does not exist
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- =============================================================================
+-- test case for having multiple cached connections for a foreign server
+-- =============================================================================
+CREATE ROLE regress_multi_conn_user1 SUPERUSER;
+CREATE ROLE regress_multi_conn_user2 SUPERUSER;
+CREATE USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+CREATE USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+BEGIN;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user1
+SET ROLE regress_multi_conn_user1;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user2
+SET ROLE regress_multi_conn_user2;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Should output two connections for loopback server
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback
+(2 rows)
+
+COMMIT;
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- Clean up
+DROP USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+DROP USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+DROP ROLE regress_multi_conn_user1;
+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
+-- ===================================================================
+BEGIN;
+CREATE SERVER batch10 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( batch_size '10' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER batch10 OPTIONS( SET batch_size '20' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=20'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30 ( x int ) SERVER batch10 OPTIONS ( batch_size '30' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30 OPTIONS ( SET batch_size '40');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=40'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+CREATE TABLE batch_table ( x int );
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '10' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 10
+ -> Function Scan on pg_catalog.generate_series i
+ Output: i.i
+ Function Call: generate_series(1, 10)
+(6 rows)
+
+INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+INSERT INTO ftable SELECT * FROM generate_series(11, 31) i;
+INSERT INTO ftable VALUES (32);
+INSERT INTO ftable VALUES (33), (34);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 34
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- try if large batches exceed max number of bind parameters
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '100000' );
+INSERT INTO ftable SELECT * FROM generate_series(1, 70000) i;
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 70000
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- Disable batch insert
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '1' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (1), (2);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 2
+(1 row)
+
+-- Disable batch inserting into foreign tables with BEFORE ROW INSERT triggers
+-- even if the batch_size option is enabled.
+ALTER FOREIGN TABLE ftable OPTIONS ( SET batch_size '10' );
+CREATE TRIGGER trig_row_before BEFORE INSERT ON ftable
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (3), (4);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (3), (4);
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (3)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (4)
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 4
+(1 row)
+
+-- Clean up
+DROP TRIGGER trig_row_before ON ftable;
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+-- Use partitioning
+CREATE TABLE batch_table ( x int ) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0', batch_size '10');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1', batch_size '1');
+CREATE TABLE batch_table_p2
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 2);
+INSERT INTO batch_table SELECT * FROM generate_series(1, 66) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 66
+(1 row)
+
+-- Check that enabling batched inserts doesn't interfere with cross-partition
+-- updates
+CREATE TABLE batch_cp_upd_test (a int) PARTITION BY LIST (a);
+CREATE TABLE batch_cp_upd_test1 (LIKE batch_cp_upd_test);
+CREATE FOREIGN TABLE batch_cp_upd_test1_f
+ PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_cp_upd_test1', batch_size '10');
+CREATE TABLE batch_cp_up_test1 PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (2);
+INSERT INTO batch_cp_upd_test VALUES (1), (2);
+-- The following moves a row from the local partition to the foreign one
+UPDATE batch_cp_upd_test t SET a = 1 FROM (VALUES (1), (2)) s(a) WHERE t.a = s.a;
+ERROR: cannot route tuples into foreign table to be updated "batch_cp_upd_test1_f"
+SELECT tableoid::regclass, * FROM batch_cp_upd_test;
+ tableoid | a
+----------------------+---
+ batch_cp_upd_test1_f | 1
+ batch_cp_up_test1 | 2
+(2 rows)
+
+-- Clean up
+DROP TABLE batch_table, batch_cp_upd_test, batch_table_p0, batch_table_p1 CASCADE;
+-- Use partitioning
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+CREATE TABLE batch_table ( x int, field1 text, field2 text) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+ALTER TABLE batch_table_p0 ADD CONSTRAINT p0_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+ALTER TABLE batch_table_p1 ADD CONSTRAINT p1_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1');
+INSERT INTO batch_table SELECT i, 'test'||i, 'test'|| i FROM generate_series(1, 50) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 50
+(1 row)
+
+SELECT * FROM batch_table ORDER BY x;
+ x | field1 | field2
+----+--------+--------
+ 1 | test1 | test1
+ 2 | test2 | test2
+ 3 | test3 | test3
+ 4 | test4 | test4
+ 5 | test5 | test5
+ 6 | test6 | test6
+ 7 | test7 | test7
+ 8 | test8 | test8
+ 9 | test9 | test9
+ 10 | test10 | test10
+ 11 | test11 | test11
+ 12 | test12 | test12
+ 13 | test13 | test13
+ 14 | test14 | test14
+ 15 | test15 | test15
+ 16 | test16 | test16
+ 17 | test17 | test17
+ 18 | test18 | test18
+ 19 | test19 | test19
+ 20 | test20 | test20
+ 21 | test21 | test21
+ 22 | test22 | test22
+ 23 | test23 | test23
+ 24 | test24 | test24
+ 25 | test25 | test25
+ 26 | test26 | test26
+ 27 | test27 | test27
+ 28 | test28 | test28
+ 29 | test29 | test29
+ 30 | test30 | test30
+ 31 | test31 | test31
+ 32 | test32 | test32
+ 33 | test33 | test33
+ 34 | test34 | test34
+ 35 | test35 | test35
+ 36 | test36 | test36
+ 37 | test37 | test37
+ 38 | test38 | test38
+ 39 | test39 | test39
+ 40 | test40 | test40
+ 41 | test41 | test41
+ 42 | test42 | test42
+ 43 | test43 | test43
+ 44 | test44 | test44
+ 45 | test45 | test45
+ 46 | test46 | test46
+ 47 | test47 | test47
+ 48 | test48 | test48
+ 49 | test49 | test49
+ 50 | test50 | test50
+(50 rows)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+-- ===================================================================
+-- test asynchronous execution
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD async_capable 'true');
+ALTER SERVER loopback2 OPTIONS (ADD async_capable 'true');
+CREATE TABLE async_pt (a int, b int, c text) PARTITION BY RANGE (a);
+CREATE TABLE base_tbl1 (a int, b int, c text);
+CREATE TABLE base_tbl2 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p1 PARTITION OF async_pt FOR VALUES FROM (1000) TO (2000)
+ SERVER loopback OPTIONS (table_name 'base_tbl1');
+CREATE FOREIGN TABLE async_p2 PARTITION OF async_pt FOR VALUES FROM (2000) TO (3000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl2');
+INSERT INTO async_p1 SELECT 1000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+INSERT INTO async_p2 SELECT 2000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+-- simple queries
+CREATE TABLE result_tbl (a int, b int, c text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE (((b % 100) = 0))
+(8 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1000 | 0 | 0000
+ 1100 | 100 | 0100
+ 1200 | 200 | 0200
+ 1300 | 300 | 0300
+ 1400 | 400 | 0400
+ 1500 | 500 | 0500
+ 1600 | 600 | 0600
+ 1700 | 700 | 0700
+ 1800 | 800 | 0800
+ 1900 | 900 | 0900
+ 2000 | 0 | 0000
+ 2100 | 100 | 0100
+ 2200 | 200 | 0200
+ 2300 | 300 | 0300
+ 2400 | 400 | 0400
+ 2500 | 500 | 0500
+ 2600 | 600 | 0600
+ 2700 | 700 | 0700
+ 2800 | 800 | 0800
+ 2900 | 900 | 0900
+(20 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, ('AAA'::text || async_pt_1.c)
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, ('AAA'::text || async_pt_2.c)
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+---------
+ 1505 | 505 | AAA0505
+ 2505 | 505 | AAA0505
+(2 rows)
+
+DELETE FROM result_tbl;
+-- Check case where multiple partitions use the same connection
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl3');
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Async Foreign Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(14 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+DROP FOREIGN TABLE async_p3;
+DROP TABLE base_tbl3;
+-- Check case where the partitioned table has local/remote partitions
+CREATE TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000);
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+(13 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+-- partitionwise joins
+SET enable_partitionwise_join TO true;
+CREATE TABLE join_tbl (a1 int, b1 int, c1 text, a2 int, b2 int, c2 text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t2_1.b, t2_1.c
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t2_2.b, t2_2.c
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, t1_3.c, t2_3.a, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+ 2000 | 0 | 0000 | 2000 | 0 | 0000
+ 2100 | 100 | 0100 | 2100 | 100 | 0100
+ 2200 | 200 | 0200 | 2200 | 200 | 0200
+ 2300 | 300 | 0300 | 2300 | 300 | 0300
+ 2400 | 400 | 0400 | 2400 | 400 | 0400
+ 2500 | 500 | 0500 | 2500 | 500 | 0500
+ 2600 | 600 | 0600 | 2600 | 600 | 0600
+ 2700 | 700 | 0700 | 2700 | 700 | 0700
+ 2800 | 800 | 0800 | 2800 | 800 | 0800
+ 2900 | 900 | 0900 | 2900 | 900 | 0900
+ 3000 | 0 | 0000 | 3000 | 0 | 0000
+ 3100 | 100 | 0100 | 3100 | 100 | 0100
+ 3200 | 200 | 0200 | 3200 | 200 | 0200
+ 3300 | 300 | 0300 | 3300 | 300 | 0300
+ 3400 | 400 | 0400 | 3400 | 400 | 0400
+ 3500 | 500 | 0500 | 3500 | 500 | 0500
+ 3600 | 600 | 0600 | 3600 | 600 | 0600
+ 3700 | 700 | 0700 | 3700 | 700 | 0700
+ 3800 | 800 | 0800 | 3800 | 800 | 0800
+ 3900 | 900 | 0900 | 3900 | 900 | 0900
+(30 rows)
+
+DELETE FROM join_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, ('AAA'::text || t1_1.c), t2_1.a, t2_1.b, ('AAA'::text || t2_1.c)
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, ('AAA'::text || t1_2.c), t2_2.a, t2_2.b, ('AAA'::text || t2_2.c)
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, ('AAA'::text || t1_3.c), t2_3.a, t2_3.b, ('AAA'::text || t2_3.c)
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+---------+------+-----+---------
+ 1000 | 0 | AAA0000 | 1000 | 0 | AAA0000
+ 1100 | 100 | AAA0100 | 1100 | 100 | AAA0100
+ 1200 | 200 | AAA0200 | 1200 | 200 | AAA0200
+ 1300 | 300 | AAA0300 | 1300 | 300 | AAA0300
+ 1400 | 400 | AAA0400 | 1400 | 400 | AAA0400
+ 1500 | 500 | AAA0500 | 1500 | 500 | AAA0500
+ 1600 | 600 | AAA0600 | 1600 | 600 | AAA0600
+ 1700 | 700 | AAA0700 | 1700 | 700 | AAA0700
+ 1800 | 800 | AAA0800 | 1800 | 800 | AAA0800
+ 1900 | 900 | AAA0900 | 1900 | 900 | AAA0900
+ 2000 | 0 | AAA0000 | 2000 | 0 | AAA0000
+ 2100 | 100 | AAA0100 | 2100 | 100 | AAA0100
+ 2200 | 200 | AAA0200 | 2200 | 200 | AAA0200
+ 2300 | 300 | AAA0300 | 2300 | 300 | AAA0300
+ 2400 | 400 | AAA0400 | 2400 | 400 | AAA0400
+ 2500 | 500 | AAA0500 | 2500 | 500 | AAA0500
+ 2600 | 600 | AAA0600 | 2600 | 600 | AAA0600
+ 2700 | 700 | AAA0700 | 2700 | 700 | AAA0700
+ 2800 | 800 | AAA0800 | 2800 | 800 | AAA0800
+ 2900 | 900 | AAA0900 | 2900 | 900 | AAA0900
+ 3000 | 0 | AAA0000 | 3000 | 0 | AAA0000
+ 3100 | 100 | AAA0100 | 3100 | 100 | AAA0100
+ 3200 | 200 | AAA0200 | 3200 | 200 | AAA0200
+ 3300 | 300 | AAA0300 | 3300 | 300 | AAA0300
+ 3400 | 400 | AAA0400 | 3400 | 400 | AAA0400
+ 3500 | 500 | AAA0500 | 3500 | 500 | AAA0500
+ 3600 | 600 | AAA0600 | 3600 | 600 | AAA0600
+ 3700 | 700 | AAA0700 | 3700 | 700 | AAA0700
+ 3800 | 800 | AAA0800 | 3800 | 800 | AAA0800
+ 3900 | 900 | AAA0900 | 3900 | 900 | AAA0900
+(30 rows)
+
+DELETE FROM join_tbl;
+RESET enable_partitionwise_join;
+-- Test rescan of an async Append node with do_exec_prune=false
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: ((t1.a = t2.a) AND (t1.b = t2.b))
+ -> Foreign Scan on public.async_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t2_1
+ Output: t2_1.a, t2_1.b, t2_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t2_2
+ Output: t2_2.a, t2_2.b, t2_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+(16 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+(10 rows)
+
+DELETE FROM join_tbl;
+RESET enable_hashjoin;
+-- Test interaction of async execution with plan-time partition pruning
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 3000;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(7 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 2000;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Foreign Scan on public.async_p1 async_pt
+ Output: async_pt.a, async_pt.b, async_pt.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 2000))
+(3 rows)
+
+-- Test interaction of async execution with run-time partition pruning
+SET plan_cache_mode TO force_generic_plan;
+PREPARE async_pt_query (int, int) AS
+ INSERT INTO result_tbl SELECT * FROM async_pt WHERE a < $1 AND b === $2;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (3000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 1
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < $1::integer))
+(11 rows)
+
+EXECUTE async_pt_query (3000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (2000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 2
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+(7 rows)
+
+EXECUTE async_pt_query (2000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+(1 row)
+
+DELETE FROM result_tbl;
+RESET plan_cache_mode;
+CREATE TABLE local_tbl(a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo'), (2505, 505, 'bar');
+ANALYZE local_tbl;
+CREATE INDEX base_tbl1_idx ON base_tbl1 (a);
+CREATE INDEX base_tbl2_idx ON base_tbl2 (a);
+CREATE INDEX async_p3_idx ON async_p3 (a);
+ANALYZE base_tbl1;
+ANALYZE base_tbl2;
+ANALYZE async_p3;
+ALTER FOREIGN TABLE async_p1 OPTIONS (use_remote_estimate 'true');
+ALTER FOREIGN TABLE async_p2 OPTIONS (use_remote_estimate 'true');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: local_tbl.a, local_tbl.b, local_tbl.c, async_pt.a, async_pt.b, async_pt.c
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ Filter: (local_tbl.c = 'bar'::text)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a = $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a = $1::integer))
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.a = local_tbl.a)
+(15 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Nested Loop (actual rows=1 loops=1)
+ -> Seq Scan on local_tbl (actual rows=1 loops=1)
+ Filter: (c = 'bar'::text)
+ Rows Removed by Filter: 1
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (never executed)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=1 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (never executed)
+ Filter: (a = local_tbl.a)
+(9 rows)
+
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ a | b | c | a | b | c
+------+-----+-----+------+-----+------
+ 2505 | 505 | bar | 2505 | 505 | 0505
+(1 row)
+
+ALTER FOREIGN TABLE async_p1 OPTIONS (DROP use_remote_estimate);
+ALTER FOREIGN TABLE async_p2 OPTIONS (DROP use_remote_estimate);
+DROP TABLE local_tbl;
+DROP INDEX base_tbl1_idx;
+DROP INDEX base_tbl2_idx;
+DROP INDEX async_p3_idx;
+-- UNION queries
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> HashAggregate
+ Output: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ Group Key: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(11 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(8 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+-- Disable async execution if we use gating Result nodes for pseudoconstant
+-- quals
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Result
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+(18 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+(SELECT * FROM async_p1 WHERE CURRENT_USER = SESSION_USER)
+UNION ALL
+(SELECT * FROM async_p2 WHERE CURRENT_USER = SESSION_USER);
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(13 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ((SELECT * FROM async_p1 WHERE b < 10) UNION ALL (SELECT * FROM async_p2 WHERE b < 10)) s WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((b < 10))
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(13 rows)
+
+-- Test that pending requests are processed properly
+SET enable_mergejoin TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: (t1.a = t2.a)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+ -> Materialize
+ Output: t2.a, t2.b, t2.c
+ -> Foreign Scan on public.async_p2 t2
+ Output: t2.a, t2.b, t2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(20 rows)
+
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ a | b | c | a | b | c
+------+-----+------+------+-----+------
+ 2505 | 505 | 0505 | 2505 | 505 | 0505
+(1 row)
+
+CREATE TABLE local_tbl (a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo');
+ANALYZE local_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, async_pt.a, async_pt.b, async_pt.c, ($0)
+ Join Filter: (t1.a = async_pt.a)
+ InitPlan 1 (returns $0)
+ -> Aggregate
+ Output: count(*)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_4
+ Remote SQL: SELECT NULL FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_5
+ Remote SQL: SELECT NULL FROM public.base_tbl2 WHERE ((a < 3000))
+ -> Seq Scan on public.local_tbl t1
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(20 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Nested Loop Left Join (actual rows=1 loops=1)
+ Join Filter: (t1.a = async_pt.a)
+ Rows Removed by Join Filter: 399
+ InitPlan 1 (returns $0)
+ -> Aggregate (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_4 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_5 (actual rows=200 loops=1)
+ -> Seq Scan on local_tbl t1 (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=200 loops=1)
+(12 rows)
+
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ a | b | c | a | b | c | count
+------+-----+-----+------+-----+------+-------
+ 1505 | 505 | foo | 1505 | 505 | 0505 | 400
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+----------------------------------------------------------------
+ Limit
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+(14 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit (actual rows=1 loops=1)
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 t1_1 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Async Foreign Scan on async_p2 t1_2 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Seq Scan on async_p3 t1_3 (actual rows=1 loops=1)
+ Filter: (b === 505)
+ Rows Removed by Filter: 101
+(9 rows)
+
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ a | b | c
+------+-----+------
+ 3505 | 505 | 0505
+(1 row)
+
+-- Check with foreign modify
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE remote_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl3');
+INSERT INTO remote_tbl VALUES (2505, 505, 'bar');
+CREATE TABLE base_tbl4 (a int, b int, c text);
+CREATE FOREIGN TABLE insert_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl4');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Insert on public.insert_tbl
+ Remote SQL: INSERT INTO public.base_tbl4(a, b, c) VALUES ($1, $2, $3)
+ Batch Size: 1
+ -> Append
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ -> Async Foreign Scan on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(9 rows)
+
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+SELECT * FROM insert_tbl ORDER BY a;
+ a | b | c
+------+-----+-----
+ 1505 | 505 | foo
+ 2505 | 505 | bar
+(2 rows)
+
+-- Check with direct modify
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ CTE t
+ -> Update on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ -> Foreign Update on public.remote_tbl
+ Remote SQL: UPDATE public.base_tbl3 SET c = (c || c) RETURNING a, b, c
+ -> Nested Loop Left Join
+ Output: async_pt.a, async_pt.b, async_pt.c, t.a, t.b, t.c
+ Join Filter: ((async_pt.a = t.a) AND (async_pt.b = t.b))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ -> CTE Scan on t
+ Output: t.a, t.b, t.c
+(23 rows)
+
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+--------
+ 1505 | 505 | 0505 | | |
+ 2505 | 505 | 0505 | 2505 | 505 | barbar
+ 3505 | 505 | 0505 | | |
+(3 rows)
+
+DELETE FROM join_tbl;
+DROP TABLE local_tbl;
+DROP FOREIGN TABLE remote_tbl;
+DROP FOREIGN TABLE insert_tbl;
+DROP TABLE base_tbl3;
+DROP TABLE base_tbl4;
+RESET enable_mergejoin;
+RESET enable_hashjoin;
+-- Test that UPDATE/DELETE with inherited target works with async_capable enabled
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Update on public.async_p1 async_pt_1
+ Foreign Update on public.async_p2 async_pt_2
+ Update on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Update on public.async_p1 async_pt_1
+ Remote SQL: UPDATE public.base_tbl1 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Update on public.async_p2 async_pt_2
+ Remote SQL: UPDATE public.base_tbl2 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: (async_pt_3.c || async_pt_3.c), async_pt_3.tableoid, async_pt_3.ctid, NULL::record
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Delete on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Delete on public.async_p1 async_pt_1
+ Foreign Delete on public.async_p2 async_pt_2
+ Delete on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Delete on public.async_p1 async_pt_1
+ Remote SQL: DELETE FROM public.base_tbl1 WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Delete on public.async_p2 async_pt_2
+ Remote SQL: DELETE FROM public.base_tbl2 WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.tableoid, async_pt_3.ctid
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+-- Check EXPLAIN ANALYZE for a query that scans empty partitions asynchronously
+DELETE FROM async_p1;
+DELETE FROM async_p2;
+DELETE FROM async_p3;
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Append (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=0 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (actual rows=0 loops=1)
+(4 rows)
+
+-- Clean up
+DROP TABLE async_pt;
+DROP TABLE base_tbl1;
+DROP TABLE base_tbl2;
+DROP TABLE result_tbl;
+DROP TABLE join_tbl;
+-- Test that an asynchronous fetch is processed before restarting the scan in
+-- ReScanForeignScan
+CREATE TABLE base_tbl (a int, b int);
+INSERT INTO base_tbl VALUES (1, 11), (2, 22), (3, 33);
+CREATE FOREIGN TABLE foreign_tbl (b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE FOREIGN TABLE foreign_tbl2 () INHERITS (foreign_tbl)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Seq Scan on public.base_tbl
+ Output: base_tbl.a
+ Filter: (SubPlan 1)
+ SubPlan 1
+ -> Result
+ Output: base_tbl.a
+ -> Append
+ -> Async Foreign Scan on public.foreign_tbl foreign_tbl_1
+ Remote SQL: SELECT NULL FROM public.base_tbl
+ -> Async Foreign Scan on public.foreign_tbl2 foreign_tbl_2
+ Remote SQL: SELECT NULL FROM public.base_tbl
+(11 rows)
+
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ a
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+-- Clean up
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to foreign table foreign_tbl2
+DROP TABLE base_tbl;
+ALTER SERVER loopback OPTIONS (DROP async_capable);
+ALTER SERVER loopback2 OPTIONS (DROP async_capable);
+-- ===================================================================
+-- test invalid server, foreign table and foreign data wrapper options
+-- ===================================================================
+-- Invalid fdw_startup_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_startup_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_startup_cost": 100$%$#$#
+-- Invalid fdw_tuple_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_tuple_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_tuple_cost": 100$%$#$#
+-- Invalid fetch_size option
+CREATE FOREIGN TABLE inv_fsz (c1 int )
+ SERVER loopback OPTIONS (fetch_size '100$%$#$#');
+ERROR: invalid value for integer option "fetch_size": 100$%$#$#
+-- Invalid batch_size option
+CREATE FOREIGN TABLE inv_bsz (c1 int )
+ SERVER loopback OPTIONS (batch_size '100$%$#$#');
+ERROR: invalid value for integer option "batch_size": 100$%$#$#
+-- No option is allowed to be specified at foreign data wrapper level
+ALTER FOREIGN DATA WRAPPER postgres_fdw OPTIONS (nonexistent 'fdw');
+ERROR: invalid option "nonexistent"
+HINT: There are no valid options in this context.
+-- ===================================================================
+-- test postgres_fdw.application_name GUC
+-- ===================================================================
+--- Turn debug_discard_caches off for this test to make sure that
+--- the remote connection is alive when checking its application_name.
+SET debug_discard_caches = 0;
+-- Specify escape sequences in application_name option of a server
+-- object so as to test that they are replaced with status information
+-- expectedly.
+--
+-- Since pg_stat_activity.application_name may be truncated to less than
+-- NAMEDATALEN characters, note that substring() needs to be used
+-- at the condition of test query to make sure that the string consisting
+-- of database name and process ID is also less than that.
+ALTER SERVER loopback2 OPTIONS (application_name 'fdw_%d%p');
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_database() || pg_backend_pid() for
+ current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- postgres_fdw.application_name overrides application_name option
+-- of a server object if both settings are present.
+SET postgres_fdw.application_name TO 'fdw_%a%u%%';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('application_name') ||
+ CURRENT_USER || '%' for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- Test %c (session ID) and %C (cluster name) escape sequences.
+SET postgres_fdw.application_name TO 'fdw_%C%c';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('cluster_name') ||
+ to_hex(trunc(EXTRACT(EPOCH FROM (SELECT backend_start FROM
+ pg_stat_get_activity(pg_backend_pid()))))::integer) || '.' ||
+ to_hex(pg_backend_pid())
+ for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+--Clean up
+RESET postgres_fdw.application_name;
+RESET debug_discard_caches;
+-- ===================================================================
+-- test parallel commit
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (ADD parallel_commit 'true');
+ALTER SERVER loopback2 OPTIONS (ADD parallel_commit 'true');
+CREATE TABLE ploc1 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem1 (f1 int, f2 text)
+ SERVER loopback OPTIONS (table_name 'ploc1');
+CREATE TABLE ploc2 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem2 (f1 int, f2 text)
+ SERVER loopback2 OPTIONS (table_name 'ploc2');
+BEGIN;
+INSERT INTO prem1 VALUES (101, 'foo');
+INSERT INTO prem2 VALUES (201, 'bar');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+-----
+ 101 | foo
+(1 row)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+-----
+ 201 | bar
+(1 row)
+
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (102, 'foofoo');
+INSERT INTO prem2 VALUES (202, 'barbar');
+RELEASE SAVEPOINT s;
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+(2 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+(2 rows)
+
+-- This tests executing DEALLOCATE ALL against foreign servers in parallel
+-- during pre-commit
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (103, 'baz');
+INSERT INTO prem2 VALUES (203, 'qux');
+ROLLBACK TO SAVEPOINT s;
+RELEASE SAVEPOINT s;
+INSERT INTO prem1 VALUES (104, 'bazbaz');
+INSERT INTO prem2 VALUES (204, 'quxqux');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+ 104 | bazbaz
+(3 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+ 204 | quxqux
+(3 rows)
+
+ALTER SERVER loopback OPTIONS (DROP parallel_commit);
+ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_foreign_servers
+-------------------------------------
+ f
+(1 row)
+
+\set VERBOSITY default
+COMMIT;
+ERROR: server closed the connection unexpectedly
+ This probably means the server terminated abnormally
+ before or while processing the request.
+CONTEXT: remote SQL command: COMMIT TRANSACTION
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index b0dbb41fb5..d1892e3e3c 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3788,3 +3788,29 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT postgres_fdw_verify_foreign_servers(false); -- should fail on supported platform
+\set VERBOSITY default
+COMMIT;
+
+-- Clean up
+RESET debug_discard_caches;
--
2.27.0
Hi Hayota Kuroda,
I (and my company) worried about overnight batch processing that
contains some accesses to foreign servers. If the transaction is opened
overnight and
one of foreign servers is crashed during it, the transaction must be
rollbacked.
But there is a possibility that DBAs do not recognize the crash and
they waste a time until the morning. This problem may affect customer's
business.
(It may not be sufficient to check the status from another different
server.
DBAs must check the network between the databases, and they may be
oversight.)
This is a motivation we thought.
Thanks for the clarification, I agree that this might be a valid concern
for systems.
So how about implementing a check function as an SQL function once and
update incrementally?
I think a SQL function makes sense.
This still satisfy our motivation and it can avoid overhead because we can
reduce the number of calling it.
Yes, it makes sense. Also, it allows other extensions to utilize the new
libpq function, which is neat.
If we decide that we establish a new connection in the checking function,
we can refactor the it.
And if we decide that we introduce health-check BGworker, then we can add
a process that calls implemented function periodically.
Right, your approach doesn't conflict with a more sophisticated approach,
in fact is a useful building block.
Note that poll() is used here, it means that currently this function can
be used on some limited platforms.
I think more experienced hackers could guide us here. I don't see a problem
with that, but checking other functions like pqSocketPoll(), I see that
Postgres uses the select system call. I wonder if we can have something
similar with select? Seems no, but wanted to bring up in case you know more
about that?
I have added a parameter check_all that controls the scope of
to-be-checked servers,
But this is not related with my motivation so we can remove if not needed.
I guess it kind of makes sense to have the flexibility to check all
connections vs only in tx connections.
Though, maybe we should follow a similar approach
to postgres_fdw_disconnect(servername) / postgres_fdw_disconnect_all()
postgres_fdw_verify_connection_states(servername) /
postgres_fdw_verify_connection_states_all()
That seems like a more natural API considering the other UDFs. You can also
use in combination with postgres_fdw_get_connections()
(I have not implemented another version that uses epoll() or kqueue(),
because they seem to be not called on the libpq layer. Do you know any
reasons?)
Hmm, I don't know the reason. Is that maybe epoll is available on a smaller
number of platforms and libpq can be used on more platforms as being a
client library?
Now, some comments regarding the v18:
+static int +pqConncheck_internal(int sock) +{ +#if (defined(HAVE_POLL) && defined(POLLRDHUP)) + struct pollfd input_fd; + + input_fd.fd = sock; + input_fd.events = POLLRDHUP; + input_fd.revents = 0; + + poll(&input_fd, 1, 0); + + return input_fd.revents & POLLRDHUP;
WaitEventSetWaitBlock's* defined(WAIT_USE_POLL)* branch uses the following
check to find WL_SOCKET_CLOSED
#ifdef POLLRDHUP
if ((cur_event->events & WL_SOCKET_CLOSED) &&
(cur_pollfd->revents & (POLLRDHUP | errflags)))
{
/* remote peer closed, or error */
occurred_events->events |= WL_SOCKET_CLOSED;
}
#endif
Where *errflags = POLLHUP | POLLERR | POLLNVAL;*
So, should we also be using all these flags like: input_fd.events =
POLLRDHUP | *errflags*; ?
+ ereport(ERROR,
+ (errcode(ERRCODE_CONNECTION_FAILURE), + errmsg("could not connect to server \"%s\"", + server->servername), + errdetail("Socket close is detected."), + errhint("Please check the health of the server.")));
Is erroring out always necessary? Maybe we should just return true/false,
and let the caller decide what to do? For example, you might want to
rollback to savepoint and retry? If the caller wants to rollback the whole
transaction, that is possible anyway.
Maybe similar to postgres_fdw_disconnect(), we can warn if the connection
is involved in a tx (e.g., depth > 0)?
new file mode 100644
index 0000000000..3ce169c837 --- /dev/null +++ b/contrib/postgres_fdw/expected/postgres_fdw_1.out @@ -0,0 +1,11615 @@ +-- =================================================================== +-- create FDW objects +-- =================================================================== +CREATE EXTENSION postgres_fdw; +CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw; +DO $d$ + BEGIN
Do we really need this new file or just an oversight in your patch?
Thanks,
Onder KALACI
Software Engineer at Microsoft &
Developing the Citus database extension for PostgreSQL
Dear Önder,
Sorry for my late reply. I understood that we got agreement the basic design of first version. Thanks!
I attached new version patches.
I think more experienced hackers could guide us here. I don't see a problem
with that, but checking other functions like pqSocketPoll(), I see that
Postgres uses the select system call. I wonder if we can have something
similar with select? Seems no, but wanted to bring up in case you know more
about that?
Here I have been still checking...
I guess it kind of makes sense to have the flexibility to check all
connections vs only in tx connections.Though, maybe we should follow a similar approach
to postgres_fdw_disconnect(servername) / postgres_fdw_disconnect_all()
postgres_fdw_verify_connection_states(servername) /
postgres_fdw_verify_connection_states_all()That seems like a more natural API considering the other UDFs. You can also
use in combination with postgres_fdw_get_connections()
I think you are right, fixed.
Hmm, I don't know the reason. Is that maybe epoll is available on a smaller
number of platforms and libpq can be used on more platforms as being a
client library?
Here I have been still checking...
So, should we also be using all these flags like: input_fd.events =
POLLRDHUP | *errflags*; ?
Fixed.
Is erroring out always necessary? Maybe we should just return true/false,
and let the caller decide what to do? For example, you might want to
rollback to savepoint and retry? If the caller wants to rollback the whole
transaction, that is possible anyway.
I changed as you suggested once, but I was not sure we can really do such a thing.
Please see the following case.
```
BEGIN;
SAVEPOINT s;
SELECT 1 FROM ft1 LIMIT 1; -- connect to foreign server
SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
WHERE application_name = 'fdw_retry_check'; -- kill the remote connection
SELECT 1 FROM ft1 LIMIT 1; -- will fail
-> ERROR: FATAL: terminating connection due to administrator command
ROLLBACK TO SAVEPOINT s; -- OK, go back to savepoint...
COMMIT;
-> ERROR: connection to server "loopback" was lost
```
The test means that even if we go back to the savepoint,
we could not commit the transaction because postgres_fdw tries to connect to the remove
in pgfdw_xact_callback().
Do we really have a flexibility when the remote connection seems to be closed?
If we do not have, I will revert the change.
Do we really need this new file or just an oversight in your patch?
Previously there were three file because sometimes the ordering of
output was changed, but it was no more needed.
Currently this patch contains two comparison files, one is for linux,
and another one is for unsupported OSes like Windows.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v19-0001-Add-PQConncheck-to-libpq.patchapplication/octet-stream; name=v19-0001-Add-PQConncheck-to-libpq.patchDownload
From 48f766df706c5b7db94faa59974272109093c757 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:20 +0000
Subject: [PATCH v19 1/3] Add PQConncheck to libpq
This new libpq function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
---
doc/src/sgml/libpq.sgml | 24 ++++++++++++++++++
src/interfaces/libpq/exports.txt | 1 +
src/interfaces/libpq/fe-misc.c | 42 ++++++++++++++++++++++++++++++++
src/interfaces/libpq/libpq-fe.h | 3 +++
4 files changed, 70 insertions(+)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index f9558dec3b..d77c8d6f12 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,30 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQConncheck">
+ <term><function>PQConncheck</function><indexterm><primary>PQConncheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQConncheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQConncheck"/> returns <literal>1</literal>
+ if the remote peer seems to be closed, returns <literal>0</literal> if
+ the socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..3c4f946b51 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,4 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQConncheck 187
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 4159610f6c..e561b4e1ef 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -1218,6 +1218,48 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Helper function for PQconncheck().
+ *
+ * Return >0 if opposite side seems to be disconnected.
+ */
+static int
+pqConncheck_internal(int sock)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ struct pollfd input_fd;
+ int errflags = POLLHUP | POLLERR | POLLNVAL;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP | errflags;
+ input_fd.revents = 0;
+
+ poll(&input_fd, 1, 0);
+
+ return input_fd.revents & POLLRDHUP;
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad.
+ */
+int
+PQConncheck(PGconn *conn)
+{
+ /* quick exit if invalid connection has come */
+ if (conn == NULL ||
+ conn->sock == PGINVALID_SOCKET ||
+ conn->status != CONNECTION_OK)
+ return -1;
+
+ return pqConncheck_internal(conn->sock);
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index b7df3224c0..8b2d78f3ef 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,9 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQConncheck(PGconn *conn);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v19-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v19-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From 0353eef23f1603a7ae27333bcca5379a5a7a301e Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:42 +0000
Subject: [PATCH v19 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQConncheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if checked connection is still valid, or the checking is
not supported on this platform. False is returned if the connection seems
to be closed.
---
contrib/postgres_fdw/connection.c | 100 ++++++++++++++++++
.../postgres_fdw/postgres_fdw--1.0--1.1.sql | 10 ++
doc/src/sgml/postgres-fdw.sgml | 49 +++++++++
3 files changed, 159 insertions(+)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index f0c45b00db..69959a0f12 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -86,6 +86,8 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -116,6 +118,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1862,3 +1865,100 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+
+ /* quick exit if connection cache has been not initialized yet. */
+ if (!ConnectionHash)
+ return true;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQConncheck(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so throw ereport(WARNING).
+ */
+ ForeignServer *server;
+
+ server = GetForeignServer(entry->serverid);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("could not connect to server \"%s\"",
+ server->servername),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of the server.")));
+
+ result = false;
+ }
+ }
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found, and this returns
+ * false only when the verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
diff --git a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
index ed4ca378d4..f1e2ee442f 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
@@ -18,3 +18,13 @@ CREATE FUNCTION postgres_fdw_disconnect_all ()
RETURNS bool
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 527f4deaaa..d535973237 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -790,6 +790,55 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if a checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports that
+ the connection is closed. This function is currently available only on
+ systems that support the non-standard <symbol>POLLRDHUP</symbol> extension
+ to the <symbol>poll</symbol> system call, including Linux. This returns
+ <literal>true</literal> if a lastly checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
</variablelist>
</sect2>
--
2.27.0
v19-0003-add-test.patchapplication/octet-stream; name=v19-0003-add-test.patchDownload
From 1d23e0e2849dbce40ca7415933cbbbb4a52828c3 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v19 3/3] add test
Note that this test has two comparison files. Alternative comparison file is needed
because some platforms like Windows cannot check the status of the socket.
---
.../postgres_fdw/expected/postgres_fdw.out | 44 +
.../postgres_fdw/expected/postgres_fdw_1.out | 11621 ++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 30 +
3 files changed, 11695 insertions(+)
create mode 100644 contrib/postgres_fdw/expected/postgres_fdw_1.out
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 558e94b845..1599a95f27 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11576,3 +11576,47 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- execute check function. This should return false on supported platforms,
+-- otherwise return true.
+SELECT postgres_fdw_verify_connection_states('loopback');
+WARNING: 08006
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ f
+(1 row)
+
+ABORT;
+WARNING: 08006
+\set VERBOSITY default
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/expected/postgres_fdw_1.out b/contrib/postgres_fdw/expected/postgres_fdw_1.out
new file mode 100644
index 0000000000..d8fc76fec0
--- /dev/null
+++ b/contrib/postgres_fdw/expected/postgres_fdw_1.out
@@ -0,0 +1,11621 @@
+-- ===================================================================
+-- create FDW objects
+-- ===================================================================
+CREATE EXTENSION postgres_fdw;
+CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw;
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback2 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback3 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+CREATE USER MAPPING FOR public SERVER testserver1
+ OPTIONS (user 'value', password 'value');
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback2;
+CREATE USER MAPPING FOR public SERVER loopback3;
+-- ===================================================================
+-- create objects used through FDW loopback server
+-- ===================================================================
+CREATE TYPE user_enum AS ENUM ('foo', 'bar', 'buz');
+CREATE SCHEMA "S 1";
+CREATE TABLE "S 1"."T 1" (
+ "C 1" int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10),
+ c8 user_enum,
+ CONSTRAINT t1_pkey PRIMARY KEY ("C 1")
+);
+CREATE TABLE "S 1"."T 2" (
+ c1 int NOT NULL,
+ c2 text,
+ CONSTRAINT t2_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 3" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t3_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 4" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t4_pkey PRIMARY KEY (c1)
+);
+-- Disable autovacuum for these tables to avoid unexpected effects of that
+ALTER TABLE "S 1"."T 1" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 2" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 3" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 4" SET (autovacuum_enabled = 'false');
+INSERT INTO "S 1"."T 1"
+ SELECT id,
+ id % 10,
+ to_char(id, 'FM00000'),
+ '1970-01-01'::timestamptz + ((id % 100) || ' days')::interval,
+ '1970-01-01'::timestamp + ((id % 100) || ' days')::interval,
+ id % 10,
+ id % 10,
+ 'foo'::user_enum
+ FROM generate_series(1, 1000) id;
+INSERT INTO "S 1"."T 2"
+ SELECT id,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+INSERT INTO "S 1"."T 3"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 3" WHERE c1 % 2 != 0; -- delete for outer join tests
+INSERT INTO "S 1"."T 4"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests
+ANALYZE "S 1"."T 1";
+ANALYZE "S 1"."T 2";
+ANALYZE "S 1"."T 3";
+ANALYZE "S 1"."T 4";
+-- ===================================================================
+-- create foreign tables
+-- ===================================================================
+CREATE FOREIGN TABLE ft1 (
+ c0 int,
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft1 DROP COLUMN c0;
+CREATE FOREIGN TABLE ft2 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ cx int,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft2',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft2 DROP COLUMN cx;
+CREATE FOREIGN TABLE ft4 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 3');
+CREATE FOREIGN TABLE ft5 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft6 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback2 OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft7 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback3 OPTIONS (schema_name 'S 1', table_name 'T 4');
+-- ===================================================================
+-- tests for validator
+-- ===================================================================
+-- requiressl and some other parameters are omitted because
+-- valid values for them depend on configure options
+ALTER SERVER testserver1 OPTIONS (
+ use_remote_estimate 'false',
+ updatable 'true',
+ fdw_startup_cost '123.456',
+ fdw_tuple_cost '0.123',
+ service 'value',
+ connect_timeout 'value',
+ dbname 'value',
+ host 'value',
+ hostaddr 'value',
+ port 'value',
+ --client_encoding 'value',
+ application_name 'value',
+ --fallback_application_name 'value',
+ keepalives 'value',
+ keepalives_idle 'value',
+ keepalives_interval 'value',
+ tcp_user_timeout 'value',
+ -- requiressl 'value',
+ sslcompression 'value',
+ sslmode 'value',
+ sslcert 'value',
+ sslkey 'value',
+ sslrootcert 'value',
+ sslcrl 'value',
+ --requirepeer 'value',
+ krbsrvname 'value',
+ gsslib 'value'
+ --replication 'value'
+);
+-- Error, invalid list syntax
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo; bar');
+ERROR: parameter "extensions" must be a list of extension names
+-- OK but gets a warning
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo, bar');
+WARNING: extension "foo" is not installed
+WARNING: extension "bar" is not installed
+ALTER SERVER testserver1 OPTIONS (DROP extensions);
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (DROP user, DROP password);
+-- Attempt to add a valid option that's not allowed in a user mapping
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslmode 'require');
+ERROR: invalid option "sslmode"
+-- But we can add valid ones fine
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslpassword 'dummy');
+-- Ensure valid options we haven't used in a user mapping yet are
+-- permitted to check validation.
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslkey 'value', ADD sslcert 'value');
+ALTER FOREIGN TABLE ft1 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft2 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+ALTER FOREIGN TABLE ft2 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+\det+
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------+-------+-----------+---------------------------------------+-------------
+ public | ft1 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft2 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft4 | loopback | (schema_name 'S 1', table_name 'T 3') |
+ public | ft5 | loopback | (schema_name 'S 1', table_name 'T 4') |
+ public | ft6 | loopback2 | (schema_name 'S 1', table_name 'T 4') |
+ public | ft7 | loopback3 | (schema_name 'S 1', table_name 'T 4') |
+(6 rows)
+
+-- Test that alteration of server options causes reconnection
+-- Remote's errors might be non-English, so hide them to ensure stable results
+\set VERBOSITY terse
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET dbname 'no such database');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+DO $d$
+ BEGIN
+ EXECUTE $$ALTER SERVER loopback
+ OPTIONS (SET dbname '$$||current_database()||$$')$$;
+ END;
+$d$;
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+-- Test that alteration of user mapping options causes reconnection
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (ADD user 'no such user');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (DROP user);
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+\set VERBOSITY default
+-- Now we should be able to run ANALYZE.
+-- To exercise multiple code paths, we use local stats on ft1
+-- and remote-estimate mode on ft2.
+ANALYZE ft1;
+ALTER FOREIGN TABLE ft2 OPTIONS (use_remote_estimate 'true');
+-- ===================================================================
+-- test error case for create publication on foreign table
+-- ===================================================================
+CREATE PUBLICATION testpub_ftbl FOR TABLE ft1; -- should fail
+ERROR: cannot add relation "ft1" to publication
+DETAIL: This operation is not supported for foreign tables.
+-- ===================================================================
+-- simple queries
+-- ===================================================================
+-- single table without alias
+EXPLAIN (COSTS OFF) SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------
+ Foreign Scan on ft1
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- single table with alias - also test that tableoid sort is not pushed to remote side
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ -> Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Sort Key: t1.c3, t1.c1, t1.tableoid
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(8 rows)
+
+SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF) SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: t1.*, c3, c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c3 ASC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(3 rows)
+
+SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ t1
+--------------------------------------------------------------------------------------------
+ (101,1,00101,"Fri Jan 02 00:00:00 1970 PST","Fri Jan 02 00:00:00 1970",1,"1 ",foo)
+ (102,2,00102,"Sat Jan 03 00:00:00 1970 PST","Sat Jan 03 00:00:00 1970",2,"2 ",foo)
+ (103,3,00103,"Sun Jan 04 00:00:00 1970 PST","Sun Jan 04 00:00:00 1970",3,"3 ",foo)
+ (104,4,00104,"Mon Jan 05 00:00:00 1970 PST","Mon Jan 05 00:00:00 1970",4,"4 ",foo)
+ (105,5,00105,"Tue Jan 06 00:00:00 1970 PST","Tue Jan 06 00:00:00 1970",5,"5 ",foo)
+ (106,6,00106,"Wed Jan 07 00:00:00 1970 PST","Wed Jan 07 00:00:00 1970",6,"6 ",foo)
+ (107,7,00107,"Thu Jan 08 00:00:00 1970 PST","Thu Jan 08 00:00:00 1970",7,"7 ",foo)
+ (108,8,00108,"Fri Jan 09 00:00:00 1970 PST","Fri Jan 09 00:00:00 1970",8,"8 ",foo)
+ (109,9,00109,"Sat Jan 10 00:00:00 1970 PST","Sat Jan 10 00:00:00 1970",9,"9 ",foo)
+ (110,0,00110,"Sun Jan 11 00:00:00 1970 PST","Sun Jan 11 00:00:00 1970",0,"0 ",foo)
+(10 rows)
+
+-- empty result
+SELECT * FROM ft1 WHERE false;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- with WHERE clause
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c7 >= '1')) AND (("C 1" = 101)) AND ((c6 = '1'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- with FOR UPDATE/SHARE
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 101)) FOR UPDATE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 102)) FOR SHARE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+-- aggregate
+SELECT COUNT(*) FROM ft1 t1;
+ count
+-------
+ 1000
+(1 row)
+
+-- subquery
+SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- subquery+MAX
+SELECT * FROM ft1 t1 WHERE t1.c3 = (SELECT MAX(c3) FROM ft2 t2) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+(1 row)
+
+-- used in CTE
+WITH t1 AS (SELECT * FROM ft1 WHERE c1 <= 10) SELECT t2.c1, t2.c2, t2.c3, t2.c4 FROM t1, ft2 t2 WHERE t1.c1 = t2.c1 ORDER BY t1.c1;
+ c1 | c2 | c3 | c4
+----+----+-------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+(10 rows)
+
+-- fixed values
+SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1;
+ ?column? | ?column?
+----------+----------
+ fixed |
+(1 row)
+
+-- Test forcing the remote server to produce sorted data for a merge join.
+SET enable_hashjoin TO false;
+SET enable_nestloop TO false;
+-- inner join; expressions in the clauses appear in the equivalence class list
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Left Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- A join between local table and foreign join. ORDER BY clause is added to the
+-- foreign join so that the local table can be joined using merge join strategy.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Merge Right Join
+ Output: t1."C 1"
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r3."C 1" FROM ("S 1"."T 1" r2 INNER JOIN "S 1"."T 1" r3 ON (((r3."C 1" = r2."C 1")))) ORDER BY r2."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- Test similar to above, except that the full join prevents any equivalence
+-- classes from being merged. This produces single relation equivalence classes
+-- included in join restrictions.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Right Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1, t2.c1
+ Relations: (public.ft2 t3) LEFT JOIN (public.ft1 t2)
+ Remote SQL: SELECT r3."C 1", r2."C 1" FROM ("S 1"."T 1" r3 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+-- Test similar to above with all full outer joins
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Full Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) FULL JOIN (public.ft2 t3)
+ Remote SQL: SELECT r2."C 1", r3."C 1" FROM ("S 1"."T 1" r2 FULL JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test executing assertion in estimate_path_cost_size() that makes sure that
+-- retrieved_rows for foreign rel re-used to cost pre-sorted foreign paths is
+-- a sensible value even when the rel has tuples=0
+CREATE TABLE loct_empty (c1 int NOT NULL, c2 text);
+CREATE FOREIGN TABLE ft_empty (c1 int NOT NULL, c2 text)
+ SERVER loopback OPTIONS (table_name 'loct_empty');
+INSERT INTO loct_empty
+ SELECT id, 'AAA' || to_char(id, 'FM000') FROM generate_series(1, 100) id;
+DELETE FROM loct_empty;
+ANALYZE ft_empty;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Foreign Scan on public.ft_empty
+ Output: c1, c2
+ Remote SQL: SELECT c1, c2 FROM public.loct_empty ORDER BY c1 ASC NULLS LAST
+(3 rows)
+
+-- ===================================================================
+-- WHERE with remotely-executable conditions
+-- ===================================================================
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1; -- Var, OpExpr(b), Const
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL; -- NullTest
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL; -- NullTest
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((round(abs("C 1"), 0) = 1::numeric))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1; -- OpExpr(l)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = (- "C 1")))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" IS NOT NULL) IS DISTINCT FROM ("C 1" IS NOT NULL)))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]); -- ScalarArrayOpExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ANY (ARRAY[c2, 1, ("C 1" + 0)])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1]; -- SubscriptingRef
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ((ARRAY["C 1", c2, 3])[1])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar'; -- check special chars
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c6 = E'foo''s\\bar'))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c8 = 'foo'; -- can't be sent to remote
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- parameterized remote path for foreign table
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM "S 1"."T 1" a, ft2 b WHERE a."C 1" = 47 AND b.c1 = a.c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Index Scan using t1_pkey on "S 1"."T 1" a
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Index Cond: (a."C 1" = 47)
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(8 rows)
+
+SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 47 | 7 | 00047 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo | 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+(1 row)
+
+-- check both safe and unsafe join conditions
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 a, ft2 b
+ WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Foreign Scan on public.ft2 a
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Filter: (a.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c2 = 6))
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Filter: ((b.c7)::text = upper((a.c7)::text))
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(10 rows)
+
+SELECT * FROM ft2 a, ft2 b
+WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+(100 rows)
+
+-- bug before 9.3.5 due to sloppy handling of remote-estimate parameters
+SELECT * FROM ft1 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft2 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+SELECT * FROM ft2 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft1 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+-- we should not push order by clause with volatile expressions or unsafe
+-- collations
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, random();
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, (random())
+ Sort Key: ft2.c1, (random())
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, random()
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, ft2.c3 collate "C";
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, ((c3)::text)
+ Sort Key: ft2.c1, ft2.c3 COLLATE "C"
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- user-defined operator/function
+CREATE FUNCTION postgres_fdw_abs(int) RETURNS int AS $$
+BEGIN
+RETURN abs($1);
+END
+$$ LANGUAGE plpgsql IMMUTABLE;
+CREATE OPERATOR === (
+ LEFTARG = int,
+ RIGHTARG = int,
+ PROCEDURE = int4eq,
+ COMMUTATOR = ===
+);
+-- built-in operators and functions can be shipped for remote execution
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ QUERY PLAN
+----------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- by default, user-defined ones cannot
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 = postgres_fdw_abs(t1.c2))
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- ORDER BY can be shipped, though
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- but let's put them in an extension ...
+ALTER EXTENSION postgres_fdw ADD FUNCTION postgres_fdw_abs(int);
+ALTER EXTENSION postgres_fdw ADD OPERATOR === (int, int);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- ... now they can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- and both ORDER BY and LIMIT can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2)) ORDER BY c2 ASC NULLS LAST LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- Test CASE pushdown
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE WHEN ("C 1" > 990) THEN "C 1" ELSE NULL::integer END) < 1000)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ c1 | c2 | c3
+-----+----+-------
+ 991 | 1 | 00991
+ 992 | 2 | 00992
+ 993 | 3 | 00993
+ 994 | 4 | 00994
+ 995 | 5 | 00995
+ 996 | 6 | 00996
+ 997 | 7 | 00997
+ 998 | 8 | 00998
+ 999 | 9 | 00999
+(9 rows)
+
+-- Nested CASE
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE (CASE WHEN (c2 > 0) THEN c2 ELSE NULL::integer END) WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END) > 600)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ c1 | c2 | c3
+----+----+----
+(0 rows)
+
+-- CASE arg WHEN
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE mod(c1, 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" > (CASE mod("C 1", 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)))
+(3 rows)
+
+-- CASE cannot be pushed down because of unshippable arg clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE random()::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (ft1.c1 > CASE (random())::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- these are shippable
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c6 WHEN 'foo' THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c6 WHEN 'foo'::text THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c3 WHEN c6 THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+-- but this is not because of collation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 COLLATE "C" WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: CASE (ft1.c3)::text WHEN ft1.c6 THEN true ELSE (ft1.c3 < 'bar'::text) END
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- a regconfig constant referring to this text search configuration
+-- is initially unshippable
+CREATE TEXT SEARCH CONFIGURATION public.custom_search
+ (COPY = pg_catalog.english);
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Filter: (length(to_tsvector('custom_search'::regconfig, ft1.c3)) > 0)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642))
+(4 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- but if it's in a shippable extension, it can be shipped
+ALTER EXTENSION postgres_fdw ADD TEXT SEARCH CONFIGURATION public.custom_search;
+-- however, that doesn't flush the shippability cache, so do a quick reconnect
+\c -
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642)) AND ((length(to_tsvector('public.custom_search'::regconfig, c3)) > 0))
+(3 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- ===================================================================
+-- JOIN queries
+-- ===================================================================
+-- Analyze ft4 and ft5 so that we have better statistics. These tables do not
+-- have use_remote_estimate set.
+ANALYZE ft4;
+ANALYZE ft5;
+-- join two tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3, t1.c3
+ Relations: ((public.ft1 t1) INNER JOIN (public.ft2 t2)) INNER JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3, r1.c3 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) INNER JOIN "S 1"."T 3" r4 ON (((r1."C 1" = r4.c1)))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 22 |
+ 24 | 24
+ 26 |
+ 28 |
+ 30 | 30
+ 32 |
+ 34 |
+ 36 | 36
+ 38 |
+ 40 |
+(10 rows)
+
+-- left outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + placement of clauses.
+-- clauses within the nullable side are not pulled up, but top level clause on
+-- non-nullable side is pushed into non-nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- clauses within the nullable side are not pulled up, but the top level clause
+-- on nullable side is not pushed down into nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE (((r4.c1 < 10) OR (r4.c1 IS NULL))) AND ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t2) LEFT JOIN (public.ft5 t1)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r1 ON (((r1.c1 = r2.c1)))) ORDER BY r2.c1 ASC NULLS LAST, r1.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ | 22
+ 24 | 24
+ | 26
+ | 28
+ 30 | 30
+ | 32
+ | 34
+ 36 | 36
+ | 38
+ | 40
+(10 rows)
+
+-- right outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 45::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ c1 | c1
+-----+----
+ 92 |
+ 94 |
+ 96 | 96
+ 98 |
+ 100 |
+ | 3
+ | 9
+ | 15
+ | 21
+ | 27
+(10 rows)
+
+-- full outer join with restrictions on the joining relations
+-- a. the joining relations are both base relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s4.c1, s5.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s5.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ c1 | c1
+----+----
+ 50 |
+ 52 |
+ 54 | 54
+ 56 |
+ 58 |
+ 60 | 60
+ | 51
+ | 57
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: 1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT NULL FROM ((SELECT NULL FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4 FULL JOIN (SELECT NULL FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5 ON (TRUE)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ ?column?
+----------
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- b. one of the joining relations is a base relation and the other is a join
+-- relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c1, t3.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 t2) LEFT JOIN (public.ft5 t3))
+ Remote SQL: SELECT s4.c1, s8.c1, s8.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT r5.c1, r6.c1 FROM ("S 1"."T 3" r5 LEFT JOIN "S 1"."T 4" r6 ON (((r5.c1 = r6.c1)))) WHERE ((r5.c1 >= 50)) AND ((r5.c1 <= 60))) s8(c1, c2) ON (((s4.c1 = s8.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s8.c1 ASC NULLS LAST, s8.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+(6 rows)
+
+-- c. test deparsing the remote query as nested subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft4_1.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 ft4_1) FULL JOIN (public.ft5))
+ Remote SQL: SELECT s4.c1, s10.c1, s10.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT s8.c1, s9.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL)))) s10(c1, c2) ON (((s4.c1 = s10.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s10.c1 ASC NULLS LAST, s10.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+ | | 51
+ | | 57
+(8 rows)
+
+-- d. test deparsing rowmarked relations as subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Nested Loop
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Foreign Scan
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s8.c1, s8.c2, s9.c1, s9.c2 FROM ((SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1, c2) FULL JOIN (SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1, c2) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL))) ORDER BY s8.c1 ASC NULLS LAST, s9.c1 ASC NULLS LAST
+ -> Sort
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Full Join
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Hash Cond: (ft4.c1 = ft5.c1)
+ Filter: ((ft4.c1 IS NULL) OR (ft4.c1 IS NOT NULL))
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Hash
+ Output: ft5.c1, ft5.*
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Materialize
+ Output: "T 3".c1, "T 3".ctid
+ -> Seq Scan on "S 1"."T 3"
+ Output: "T 3".c1, "T 3".ctid
+ Filter: ("T 3".c1 = 50)
+(28 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 50 | 52 |
+ 50 | 54 | 54
+ 50 | 56 |
+ 50 | 58 |
+ 50 | 60 | 60
+ 50 | | 51
+ 50 | | 57
+(8 rows)
+
+-- full outer join + inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t3.c1
+ Relations: ((public.ft4 t1) INNER JOIN (public.ft5 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1.c1, r2.c1, r4.c1 FROM (("S 1"."T 3" r1 INNER JOIN "S 1"."T 4" r2 ON (((r1.c1 = (r2.c1 + 1))) AND ((r1.c1 >= 50)) AND ((r1.c1 <= 60)))) FULL JOIN "S 1"."T 3" r4 ON (((r2.c1 = r4.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST, r4.c1 ASC NULLS LAST LIMIT 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ c1 | c1 | c1
+----+----+----
+ 52 | 51 |
+ 58 | 57 |
+ | | 2
+ | | 4
+ | | 6
+ | | 8
+ | | 10
+ | | 12
+ | | 14
+ | | 16
+(10 rows)
+
+-- full outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- right outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+SET enable_memoize TO off;
+-- right outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+RESET enable_memoize;
+-- left outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: (public.ft4 t3) LEFT JOIN ((public.ft2 t1) INNER JOIN (public.ft2 t2))
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM ("S 1"."T 3" r4 LEFT JOIN ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join + WHERE clause, only matched rows
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 = r2.c1) OR (r1.c1 IS NULL)))
+(9 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 66 | 66
+ 72 | 72
+ 78 | 78
+ 84 | 84
+ 90 | 90
+ 96 | 96
+ | 3
+ | 9
+ | 15
+ | 21
+(10 rows)
+
+-- full outer join + WHERE clause with shippable extensions set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) WHERE ((public.postgres_fdw_abs(r1."C 1") > 0)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+-- full outer join + WHERE clause with shippable extensions not set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c2, t1.c3
+ -> Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Filter: (postgres_fdw_abs(t1.c1) > 0)
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- join two tables with FOR UPDATE clause
+-- tests whole-row reference for row marks
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1 FOR UPDATE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join two tables with FOR SHARE clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1 FOR SHARE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join in CTE
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t.c1_1, t.c2_1, t.c1_3
+ CTE t
+ -> Foreign Scan
+ Output: t1.c1, t1.c3, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r1.c3, r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+ -> Sort
+ Output: t.c1_1, t.c2_1, t.c1_3
+ Sort Key: t.c1_3, t.c1_1
+ -> CTE Scan on t
+ Output: t.c1_1, t.c2_1, t.c1_3
+(12 rows)
+
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ c1_1 | c2_1
+------+------
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- ctid with whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.ctid, t1.*, t2.*, t1.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r1."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+-- SEMI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Semi Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c1)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- ANTI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Anti Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c2)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 110
+ 111
+ 112
+ 113
+ 114
+ 115
+ 116
+ 117
+ 118
+ 119
+(10 rows)
+
+-- CROSS JOIN can be pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (TRUE)) ORDER BY r1."C 1" ASC NULLS LAST, r2."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- different server, not pushed down. No result expected.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Merge Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft6 t2
+ Output: t2.c1, t2.c2, t2.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+ -> Materialize
+ Output: t1.c1, t1.c2, t1.c3
+ -> Foreign Scan on public.ft5 t1
+ Output: t1.c1, t1.c2, t1.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+(13 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+----
+(0 rows)
+
+-- unsafe join conditions (c8 has a UDT), not pushed down. Practically a CROSS
+-- JOIN since c8 in both tables has same value.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Merge Left Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t1.c8 = t2.c8)
+ -> Sort
+ Output: t1.c1, t1.c8
+ Sort Key: t1.c8
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+ -> Sort
+ Output: t2.c1, t2.c8
+ Sort Key: t2.c8
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1, t2.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+(20 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- unsafe conditions on one side (c8 has a UDT), not pushed down.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Hash Right Join
+ Output: t1.c1, t2.c1, t1.c3
+ Hash Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+ -> Hash
+ Output: t1.c1, t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c3
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c3, c8 FROM "S 1"."T 1"
+(17 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join where unsafe to pushdown condition in WHERE clause has a column not
+-- in the SELECT clause. In this test unsafe clause needs to have column
+-- references from both joining sides so that the clause is not pushed down
+-- into one of the joining sides.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Filter: (t1.c8 = t2.c8)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, r1.c8, r2.c8 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(10 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- Aggregate after UNION, for testing setrefs
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ -> Sort
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ Sort Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, avg((t1.c1 + t2.c1))
+ Group Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, t2.c1
+ Group Key: t1.c1, t2.c1
+ -> Append
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+ -> Foreign Scan
+ Output: t1_1.c1, t2_1.c1
+ Relations: (public.ft1 t1_1) INNER JOIN (public.ft2 t2_1)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(20 rows)
+
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ t1c1 | avg
+------+----------------------
+ 101 | 202.0000000000000000
+ 102 | 204.0000000000000000
+ 103 | 206.0000000000000000
+ 104 | 208.0000000000000000
+ 105 | 210.0000000000000000
+ 106 | 212.0000000000000000
+ 107 | 214.0000000000000000
+ 108 | 216.0000000000000000
+ 109 | 218.0000000000000000
+ 110 | 220.0000000000000000
+(10 rows)
+
+-- join with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Nested Loop
+ Output: t1."C 1"
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ -> Memoize
+ Cache Key: t1.c2
+ Cache Mode: binary
+ -> Subquery Scan on q
+ -> HashAggregate
+ Output: t2.c1, t3.c1
+ Group Key: t2.c1, t3.c1
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")) AND ((r1.c2 = $1::integer))))
+(17 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ C 1
+-----
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- non-Var items in targetlist of the nullable rel of a join preventing
+-- push-down in some cases
+-- unable to push {ft1, ft2}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: (13), ft2.c1
+ Join Filter: (13 = ft2.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" WHERE (("C 1" >= 10)) AND (("C 1" <= 15)) ORDER BY "C 1" ASC NULLS LAST
+ -> Materialize
+ Output: (13)
+ -> Foreign Scan on public.ft1
+ Output: 13
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 13))
+(11 rows)
+
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ a | c1
+----+----
+ | 10
+ | 11
+ | 12
+ 13 | 13
+ | 14
+ | 15
+(6 rows)
+
+-- ok to push {ft1, ft2} but not {ft1, ft2, ft4}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: ft4.c1, (13), ft1.c1, ft2.c1
+ Join Filter: (ft4.c1 = ft1.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
+ -> Materialize
+ Output: ft1.c1, ft2.c1, (13)
+ -> Foreign Scan
+ Output: ft1.c1, ft2.c1, 13
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r5."C 1" FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = 12)) AND ((r4."C 1" = 12)))) ORDER BY r4."C 1" ASC NULLS LAST
+(12 rows)
+
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ c1 | a | b | c
+----+----+----+----
+ 10 | | |
+ 12 | 13 | 12 | 12
+ 14 | | |
+(3 rows)
+
+-- join with nullable side with some columns with null values
+UPDATE ft5 SET c3 = null where c1 % 9 = 0;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2
+ Relations: (public.ft5) INNER JOIN (public.ft4)
+ Remote SQL: SELECT CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1.c1, r1.c2, r1.c3) END, r1.c1, r1.c2, r1.c3, r2.c1, r2.c2 FROM ("S 1"."T 4" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c1 = r2.c1)) AND ((r2.c1 >= 10)) AND ((r2.c1 <= 30)))) ORDER BY r1.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ ft5 | c1 | c2 | c3 | c1 | c2
+----------------+----+----+--------+----+----
+ (12,13,AAA012) | 12 | 13 | AAA012 | 12 | 13
+ (18,19,) | 18 | 19 | | 18 | 19
+ (24,25,AAA024) | 24 | 25 | AAA024 | 24 | 25
+ (30,31,AAA030) | 30 | 31 | AAA030 | 30 | 31
+(4 rows)
+
+-- multi-way join involving multiple merge joins
+-- (this case used to have EPQ-related planning problems)
+CREATE TABLE local_tbl (c1 int NOT NULL, c2 int NOT NULL, c3 text, CONSTRAINT local_tbl_pkey PRIMARY KEY (c1));
+INSERT INTO local_tbl SELECT id, id % 10, to_char(id, 'FM0000') FROM generate_series(1, 1000) id;
+ANALYZE local_tbl;
+SET enable_nestloop TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ Inner Unique: true
+ Merge Cond: (ft1.c2 = local_tbl.c1)
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Relations: (((public.ft1) INNER JOIN (public.ft2)) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r3.c1, r3.c2, r3.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r4.c1, r4.c2, r4.c3, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4.c1, r4.c2, r4.c3) END FROM ((("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")) AND ((r2."C 1" < 100)) AND ((r1."C 1" < 100)))) INNER JOIN "S 1"."T 3" r3 ON (((r1.c2 = r3.c1)))) INNER JOIN "S 1"."T 4" r4 ON (((r1.c2 = r4.c1)))) ORDER BY r1.c2 ASC NULLS LAST FOR UPDATE OF r1 FOR UPDATE OF r2 FOR UPDATE OF r3 FOR UPDATE OF r4
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Merge Cond: (ft1.c2 = ft5.c1)
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Merge Cond: (ft1.c2 = ft4.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Sort Key: ft1.c2
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Merge Cond: (ft1.c1 = ft2.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) FOR UPDATE
+ -> Materialize
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Sort
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Sort Key: ft4.c1
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" FOR UPDATE
+ -> Sort
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Sort Key: ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" FOR UPDATE
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+(47 rows)
+
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3 | c1 | c2 | c3
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+--------+----+----+--------+----+----+------
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+(10 rows)
+
+RESET enable_nestloop;
+RESET enable_hashjoin;
+-- test that add_paths_with_pathkeys_for_rel() arranges for the epq_path to
+-- return columns needed by the parent ForeignScan node
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.*, COALESCE(ft1.c3 || ft2.c3, 'foobar') FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100)) ss ON (local_tbl.c1 = ss.c1) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ -> Merge Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ Merge Cond: (local_tbl.c1 = ft1.c1)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text))
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c3 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = r4."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4."C 1" ASC NULLS LAST
+ -> Result
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c3
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), ft2.c3
+ Sort Key: ft1.c1
+ -> Hash Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text), ft2.c3
+ Hash Cond: (ft1.c1 = ft2.c1)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Hash
+ Output: ft2.*, ft2.c1, ft2.c3
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(29 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD fdw_startup_cost '10000.0');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.* FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100 AND ft1.c1 = postgres_fdw_abs(ft2.c2))) ss ON (local_tbl.c3 = ss.c3) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ -> Nested Loop Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ Join Filter: (local_tbl.c3 = ft1.c3)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ Filter: (ft1.c1 = postgres_fdw_abs(ft2.c2))
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c2 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = r4."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4.c3 ASC NULLS LAST
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Sort Key: ft1.c3
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Merge Cond: ((ft1.c1 = (postgres_fdw_abs(ft2.c2))) AND (ft1.c1 = ft2.c1))
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Sort
+ Output: ft2.*, ft2.c1, ft2.c2, (postgres_fdw_abs(ft2.c2))
+ Sort Key: (postgres_fdw_abs(ft2.c2)), ft2.c1
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, postgres_fdw_abs(ft2.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(32 rows)
+
+ALTER SERVER loopback OPTIONS (DROP fdw_startup_cost);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+DROP TABLE local_tbl;
+-- check join pushdown in situations where multiple userids are involved
+CREATE ROLE regress_view_owner SUPERUSER;
+CREATE USER MAPPING FOR regress_view_owner SERVER loopback;
+GRANT SELECT ON ft4 TO regress_view_owner;
+GRANT SELECT ON ft5 TO regress_view_owner;
+CREATE VIEW v4 AS SELECT * FROM ft4;
+CREATE VIEW v5 AS SELECT * FROM ft5;
+ALTER VIEW v5 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, different view owners
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, ft5.c2, ft5.c1
+ -> Sort
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Left Join
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.c2, ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c2, ft5.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r6.c1, r9.c2, r9.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r9 ON (((r6.c1 = r9.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r9.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, view owner not current user
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, t2.c2, t2.c1
+ -> Sort
+ Output: ft4.c1, t2.c2, t2.c1
+ Sort Key: ft4.c1, t2.c1
+ -> Hash Left Join
+ Output: ft4.c1, t2.c2, t2.c1
+ Hash Cond: (ft4.c1 = t2.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: t2.c2, t2.c1
+ -> Foreign Scan on public.ft5 t2
+ Output: t2.c2, t2.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO CURRENT_USER;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c2, t2.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r6.c1, r2.c2, r2.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r2 ON (((r6.c1 = r2.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+-- cleanup
+DROP OWNED BY regress_view_owner;
+DROP ROLE regress_view_owner;
+-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+------+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+ 100 | 49700 | 497.0000000000000000 | 2 | 992 | 0 | 49700
+ 100 | 49800 | 498.0000000000000000 | 3 | 993 | 0 | 49800
+ 100 | 49900 | 499.0000000000000000 | 4 | 994 | 0 | 49900
+ 100 | 50500 | 505.0000000000000000 | 0 | 1000 | 0 | 50500
+(5 rows)
+
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST LIMIT 1::bigint
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+-----+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+(1 row)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * (random() <= 1)::int) as sum, avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Aggregate
+ Output: sum((c1 * ((random() <= '1'::double precision))::integer)), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT count(*), sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ count | sum | avg
+-------+---------+----------------------
+ 10000 | 5010000 | 501.0000000000000000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where ((t1.c1 * t2.c1)/(t1.c1 * t2.c1)) * random() <= 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(t1.c1), count(t2.c1)
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Filter: (((((t1.c1 * t2.c1) / (t1.c1 * t2.c1)))::double precision * random()) <= '1'::double precision)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(7 rows)
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY 1 ORDER BY (c2 / 2) ASC NULLS LAST
+(4 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 500
+ 2 | 1800
+ 3 | 3900
+ 4 | 6800
+(5 rows)
+
+-- Aggregates in subquery are pushed down.
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 ORDER BY c2 ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(6 rows)
+
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+------
+ 1000 | 4500
+(1 row)
+
+-- Aggregate is still pushed down by taking unshippable expression out
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer)), ((sum(c1) * c2)), c2
+ Sort Key: ((ft1.c2 * ((random() <= '1'::double precision))::integer)), ((sum(ft1.c1) * ft1.c2))
+ -> Foreign Scan
+ Output: (c2 * ((random() <= '1'::double precision))::integer), ((sum(c1) * c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum("C 1") * c2), c2 FROM "S 1"."T 1" GROUP BY 2
+(7 rows)
+
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ sum1 | sum2
+------+--------
+ 0 | 0
+ 1 | 49600
+ 2 | 99400
+ 3 | 149400
+ 4 | 199600
+ 5 | 250000
+ 6 | 300600
+ 7 | 351400
+ 8 | 402400
+ 9 | 453600
+(10 rows)
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::int order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Sort Key: ((ft2.c2 * ((random() <= '1'::double precision))::integer))
+ -> HashAggregate
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Group Key: (ft2.c2 * ((random() <= '1'::double precision))::integer)
+ -> Foreign Scan on public.ft2
+ Output: (c2 * ((random() <= '1'::double precision))::integer)
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- GROUP BY clause in various forms, cardinal, alias and constant expression
+explain (verbose, costs off)
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), c2, 5, 7.0, 9 FROM "S 1"."T 1" GROUP BY 2, 3, 5
+(7 rows)
+
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ w | x | y | z
+-----+---+---+-----
+ 100 | 0 | 5 | 7.0
+ 100 | 1 | 5 | 7.0
+ 100 | 2 | 5 | 7.0
+ 100 | 3 | 5 | 7.0
+ 100 | 4 | 5 | 7.0
+ 100 | 5 | 5 | 7.0
+ 100 | 6 | 5 | 7.0
+ 100 | 7 | 5 | 7.0
+ 100 | 8 | 5 | 7.0
+ 100 | 9 | 5 | 7.0
+(10 rows)
+
+-- GROUP BY clause referring to same column multiple times
+-- Also, ORDER BY contains an aggregate function
+explain (verbose, costs off)
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, c2, (sum(c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, c2, sum("C 1") FROM "S 1"."T 1" WHERE ((c2 > 6)) GROUP BY 1, 2 ORDER BY sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ c2 | c2
+----+----
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(3 rows)
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 49800)) ORDER BY c2 ASC NULLS LAST
+(4 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ c2 | sum
+----+-------
+ 1 | 49600
+ 2 | 49700
+(2 rows)
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, NULL::bigint, (sqrt((ft1.c2)::double precision))
+ Filter: (((((avg(ft1.c1)) / (avg(ft1.c1))))::double precision * random()) <= '1'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ count
+-------
+ 49
+(1 row)
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * (random() <= 1)::int) > 100 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1)), c2
+ Sort Key: (sum(ft1.c1))
+ -> HashAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Filter: (avg((ft1.c1 * ((random() <= '1'::double precision))::integer)) > '100'::numeric)
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(10 rows)
+
+-- Remote aggregate in combination with a local Param (for the output
+-- of an initplan) can be trouble, per bug #15781
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ QUERY PLAN
+--------------------------------------------------
+ Foreign Scan
+ Output: $0, (sum(ft1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1"
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+(6 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ QUERY PLAN
+---------------------------------------------------
+ GroupAggregate
+ Output: ($0), sum(ft1.c1)
+ Group Key: $0
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+ -> Foreign Scan on public.ft1
+ Output: $0, ft1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(8 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY 2 ORDER BY array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1,11,21,31,41,51,61,71,81,91}
+ {2,12,22,32,42,52,62,72,82,92}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {5,15,25,35,45,55,65,75,85,95}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+(10 rows)
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5)) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY 2 ORDER BY sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))) ASC NULLS LAST
+(4 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+(10 rows)
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3) ORDER BY (("C 1" % 3)) ASC NULLS LAST) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY 3
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft2 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where (c1 / c1) * random() <= 1) from ft1 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((((ft1.c1 / ft1.c1))::double precision * random()) <= '1'::double precision)))
+ -> HashAggregate
+ Output: sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST), percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
+(7 rows)
+
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | rank | percentile_cont
+----+------+-----------------
+ 0 | 101 | 10
+ 1 | 101 | 100
+ 2 | 1 | 200
+ 3 | 1 | 300
+ 4 | 1 | 400
+(5 rows)
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY 1, 3
+(4 rows)
+
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ c1 | rank
+----+------
+ 6 | 1
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Disable hash aggregation for plan stability.
+set enable_hashagg to false;
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY 1
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 0 | 10
+ 1 | 1
+ 2 | 2
+ 3 | 3
+ 4 | 4
+ 5 | 5
+ 6 | 6
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(10 rows)
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Cleanup
+reset enable_hashagg;
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+create operator family my_op_family using btree;
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- This should not be pushed either.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- Update local stats on ft2
+ANALYZE ft2;
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now this will be pushed as sort operator is part of the extension.
+alter server loopback options (add fdw_tuple_cost '0.5');
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY 2
+(4 rows)
+
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+alter server loopback options (drop fdw_tuple_cost);
+-- This should be pushed too.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST
+(3 rows)
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft2 t1 left join ft2 t2 on (t1.c1 = random() * t2.c2);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop Left Join
+ Output: t1.c3
+ Join Filter: ((t1.c1)::double precision = (random() * (t2.c2)::double precision))
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c3, t1.c1
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1"
+ -> Materialize
+ Output: t2.c2
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(13 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Inner Unique: true
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1 ft1_1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1
+(21 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 100 | 49600
+ 100 | 49700
+ 100 | 49800
+ 100 | 49900
+ 100 | 50000
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(10 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY 3 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL))) ORDER BY avg(r1.c1) ASC NULLS LAST, sum(r2.c1) ASC NULLS LAST
+(4 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- Aggregate over FULL join needing to deparse the joining relations as
+-- subqueries.
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(ft4.c1)), (avg(ft5.c1))
+ Relations: Aggregate on ((public.ft4) FULL JOIN (public.ft5))
+ Remote SQL: SELECT count(*), sum(s4.c1), avg(s5.c1) FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ count | sum | avg
+-------+-----+---------------------
+ 8 | 330 | 55.5000000000000000
+(1 row)
+
+-- ORDER BY expression is part of the target list but not pushed down to
+-- foreign server.
+explain (verbose, costs off)
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: (((sum(c2)) * ((random() <= '1'::double precision))::integer))
+ Sort Key: (((sum(ft1.c2)) * ((random() <= '1'::double precision))::integer))
+ -> Foreign Scan
+ Output: ((sum(c2)) * ((random() <= '1'::double precision))::integer)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
+(7 rows)
+
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ sum
+------
+ 4500
+(1 row)
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c2, qry.sum
+ Sort Key: t1.c2
+ -> Nested Loop
+ Output: t1.c2, qry.sum
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Index Cond: (t1."C 1" < 100)
+ Filter: (t1.c2 < 3)
+ -> Subquery Scan on qry
+ Output: qry.sum, t2.c1
+ Filter: ((t1.c2 * 2) = qry.sum)
+ -> Foreign Scan
+ Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY 2
+(16 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ c2 | sum
+----+-----
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+reset enable_hashagg;
+-- bug #15613: bad plan for foreign table scan with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: ref_0.c2, ref_0."C 1", (ref_0.c2), ref_1.c3, ref_0."C 1"
+ -> Nested Loop
+ Output: ref_0.c2, ref_0."C 1", ref_1.c3, (ref_0.c2)
+ -> Index Scan using t1_pkey on "S 1"."T 1" ref_0
+ Output: ref_0."C 1", ref_0.c2, ref_0.c3, ref_0.c4, ref_0.c5, ref_0.c6, ref_0.c7, ref_0.c8
+ Index Cond: (ref_0."C 1" < 10)
+ -> Foreign Scan on public.ft1 ref_1
+ Output: ref_1.c3, ref_0.c2
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+ -> Materialize
+ Output: ref_3.c3
+ -> Foreign Scan on public.ft2 ref_3
+ Output: ref_3.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+(15 rows)
+
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ c2 | c1 | c2 | c3
+----+----+----+-------
+ 1 | 1 | 1 | 00001
+ 2 | 2 | 2 | 00001
+ 3 | 3 | 3 | 00001
+ 4 | 4 | 4 | 00001
+ 5 | 5 | 5 | 00001
+ 6 | 6 | 6 | 00001
+ 7 | 7 | 7 | 00001
+ 8 | 8 | 8 | 00001
+ 9 | 9 | 9 | 00001
+(9 rows)
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(q.a), count(q.b)
+ -> Nested Loop Left Join
+ Output: q.a, q.b
+ Inner Unique: true
+ Join Filter: ((ft4.c1)::numeric <= q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Materialize
+ Output: q.a, q.b
+ -> Subquery Scan on q
+ Output: q.a, q.b
+ -> Foreign Scan
+ Output: 13, (avg(ft1.c1)), NULL::bigint
+ Relations: Aggregate on ((public.ft2) LEFT JOIN (public.ft1))
+ Remote SQL: SELECT 13, avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1"))))
+(17 rows)
+
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ sum | count
+-----+-------
+ 650 | 50
+(1 row)
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: c2, c6, (sum(c1))
+ Sort Key: ft1.c2, ft1.c6
+ -> HashAggregate
+ Output: c2, c6, sum(c1)
+ Hash Key: ft1.c2
+ Hash Key: ft1.c6
+ -> Foreign Scan on public.ft1
+ Output: c2, c6, c1
+ Remote SQL: SELECT "C 1", c2, c6 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 0 | | 50500
+ 1 | | 49600
+ 2 | | 49700
+ | 0 | 50500
+ | 1 | 49600
+ | 2 | 49700
+(6 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1)), (GROUPING(c2))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, sum(c1), GROUPING(c2)
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(9 rows)
+
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 0 | 50500 | 0
+ 1 | 49600 | 0
+ 2 | 49700 | 0
+(3 rows)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((sum(c1) / 1000)), c2
+ -> Sort
+ Output: ((sum(c1) / 1000)), c2
+ Sort Key: ((sum(ft2.c1) / 1000))
+ -> Foreign Scan
+ Output: ((sum(c1) / 1000)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT (sum("C 1") / 1000), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY 2
+(9 rows)
+
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ s
+----
+ 49
+ 50
+(2 rows)
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2)), (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, (sum(c2)), count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ c2 | sum | count
+----+-----+-------
+ 0 | 0 | 5
+ 1 | 100 | 5
+ 2 | 200 | 5
+ 3 | 300 | 5
+ 4 | 400 | 5
+ 5 | 500 | 5
+ 6 | 600 | 5
+ 7 | 700 | 5
+ 8 | 800 | 5
+ 9 | 900 | 5
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2 DESC
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {8,6,4,2,0}
+ 1 | {9,7,5,3,1}
+ 2 | {8,6,4,2}
+ 3 | {9,7,5,3}
+ 4 | {8,6,4}
+ 5 | {9,7,5}
+ 6 | {8,6}
+ 7 | {9,7}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {0,2,4,6,8}
+ 1 | {1,3,5,7,9}
+ 2 | {2,4,6,8}
+ 3 | {3,5,7,9}
+ 4 | {4,6,8}
+ 5 | {5,7,9}
+ 6 | {6,8}
+ 7 | {7,9}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+-- ===================================================================
+-- parameterized queries
+-- ===================================================================
+-- simple join
+PREPARE st1(int, int) AS SELECT t1.c3, t2.c3 FROM ft1 t1, ft2 t2 WHERE t1.c1 = $1 AND t2.c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st1(1, 2);
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c3, t2.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.c3, r2.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 2)) AND ((r1."C 1" = 1))))
+(4 rows)
+
+EXECUTE st1(1, 1);
+ c3 | c3
+-------+-------
+ 00001 | 00001
+(1 row)
+
+EXECUTE st1(101, 101);
+ c3 | c3
+-------+-------
+ 00101 | 00101
+(1 row)
+
+-- subquery using stable function (can't be sent to remote)
+PREPARE st2(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c4) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st2(10, 20);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t2.c3 = t1.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Filter: (date(t2.c4) = '01-17-1970'::date)
+ Remote SQL: SELECT c3, c4 FROM "S 1"."T 1" WHERE (("C 1" > 10))
+(15 rows)
+
+EXECUTE st2(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st2(101, 121);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+-- subquery using immutable function (can be sent to remote)
+PREPARE st3(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c5) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st3(10, 20);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t2.c3 = t1.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" > 10)) AND ((date(c5) = '1970-01-17'::date))
+(14 rows)
+
+EXECUTE st3(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st3(20, 30);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- custom plan should be chosen initially
+PREPARE st4(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 = $1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+-- once we try it enough times, should switch to generic plan
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(3 rows)
+
+-- value of $1 should not be sent to remote
+PREPARE st5(user_enum,int) AS SELECT * FROM ft1 t1 WHERE c8 = $1 and c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = $1)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(4 rows)
+
+EXECUTE st5('foo', 1);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- altering FDW options requires replanning
+PREPARE st6 AS SELECT * FROM ft1 t1 WHERE t1.c1 = t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(3 rows)
+
+PREPARE st7 AS INSERT INTO ft1 (c1,c2,c3) VALUES (1001,101,'foo');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 1" RENAME TO "T 0";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 0');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 0" WHERE (("C 1" = c2))
+(3 rows)
+
+EXECUTE st6;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 0"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 0" RENAME TO "T 1";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 1');
+PREPARE st8 AS SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+EXECUTE st8;
+ count
+-------
+ 9
+(1 row)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- cleanup
+DEALLOCATE st1;
+DEALLOCATE st2;
+DEALLOCATE st3;
+DEALLOCATE st4;
+DEALLOCATE st5;
+DEALLOCATE st6;
+DEALLOCATE st7;
+DEALLOCATE st8;
+-- System columns, except ctid and oid, should not be sent to remote
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'pg_class'::regclass LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.tableoid = '1259'::oid)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'ft1'::regclass LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: (tableoid)::regclass, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ tableoid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ ft1 | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((ctid = '(0,2)'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: ctid, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ ctid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ (0,1) | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- ===================================================================
+-- used in PL/pgSQL function
+-- ===================================================================
+CREATE OR REPLACE FUNCTION f_test(p_c1 int) RETURNS int AS $$
+DECLARE
+ v_c1 int;
+BEGIN
+ SELECT c1 INTO v_c1 FROM ft1 WHERE c1 = p_c1 LIMIT 1;
+ PERFORM c1 FROM ft1 WHERE c1 = p_c1 AND p_c1 = v_c1 LIMIT 1;
+ RETURN v_c1;
+END;
+$$ LANGUAGE plpgsql;
+SELECT f_test(100);
+ f_test
+--------
+ 100
+(1 row)
+
+DROP FUNCTION f_test(int);
+-- ===================================================================
+-- REINDEX
+-- ===================================================================
+-- remote table is not created here
+CREATE FOREIGN TABLE reindex_foreign (c1 int, c2 int)
+ SERVER loopback2 OPTIONS (table_name 'reindex_local');
+REINDEX TABLE reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+REINDEX TABLE CONCURRENTLY reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+DROP FOREIGN TABLE reindex_foreign;
+-- partitions and foreign tables
+CREATE TABLE reind_fdw_parent (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE reind_fdw_0_10 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (0) TO (10);
+CREATE FOREIGN TABLE reind_fdw_10_20 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (10) TO (20)
+ SERVER loopback OPTIONS (table_name 'reind_local_10_20');
+REINDEX TABLE reind_fdw_parent; -- ok
+REINDEX TABLE CONCURRENTLY reind_fdw_parent; -- ok
+DROP TABLE reind_fdw_parent;
+-- ===================================================================
+-- conversion error
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int;
+SELECT * FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8) WHERE x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx.x8 FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: whole-row reference to foreign table "ftx"
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: processing expression at position 2 in select list
+ANALYZE ft1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "c8" of foreign table "ft1"
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- local type can be different from remote type in some cases,
+-- in particular if similarly-named operators do equivalent things
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE text;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 = 'foo')) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (('foo' = c8)) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- we declared c8 to be text locally, but it's still the same type on
+-- the remote which will balk if we try to do anything incompatible
+-- with that remote type
+SELECT * FROM ft1 WHERE c8 LIKE 'foo' LIMIT 1; -- ERROR
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+SELECT * FROM ft1 WHERE c8::text LIKE 'foo' LIMIT 1; -- ERROR; cast not pushed down
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- subtransaction
+-- + local/remote error doesn't break cursor
+-- ===================================================================
+BEGIN;
+DECLARE c CURSOR FOR SELECT * FROM ft1 ORDER BY c1;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+SAVEPOINT s;
+ERROR OUT; -- ERROR
+ERROR: syntax error at or near "ERROR"
+LINE 1: ERROR OUT;
+ ^
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+SAVEPOINT s;
+SELECT * FROM ft1 WHERE 1 / (c1 - 1) > 0; -- ERROR
+ERROR: division by zero
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (((1 / ("C 1" - 1)) > 0))
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c1 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+COMMIT;
+-- ===================================================================
+-- test handling of collations
+-- ===================================================================
+create table loct3 (f1 text collate "C" unique, f2 text, f3 varchar(10) unique);
+create foreign table ft3 (f1 text collate "C", f2 text, f3 varchar(10))
+ server loopback options (table_name 'loct3', use_remote_estimate 'true');
+-- can be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "C" = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f2 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f3 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 and l.f1 = 'foo';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = $1::character varying(10)))
+(8 rows)
+
+-- can't be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "POSIX" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f1)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f1 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 COLLATE "C" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f2)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f2 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 COLLATE "POSIX" and l.f1 = 'foo';
+ QUERY PLAN
+-------------------------------------------------------------
+ Hash Join
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ Inner Unique: true
+ Hash Cond: ((f.f3)::text = (l.f3)::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+ -> Hash
+ Output: l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+(12 rows)
+
+-- ===================================================================
+-- test writable foreign table stuff
+-- ===================================================================
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Subquery Scan on "*SELECT*"
+ Output: "*SELECT*"."?column?", "*SELECT*"."?column?_1", NULL::integer, "*SELECT*"."?column?_2", NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+ -> Foreign Scan on public.ft2 ft2_1
+ Output: (ft2_1.c1 + 1000), (ft2_1.c2 + 100), (ft2_1.c3 || ft2_1.c3)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" LIMIT 20::bigint
+(8 rows)
+
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+INSERT INTO ft2 (c1,c2,c3)
+ VALUES (1101,201,'aaa'), (1102,202,'bbb'), (1103,203,'ccc') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----+----+----+----+------------+----
+ 1101 | 201 | aaa | | | | ft2 |
+ 1102 | 202 | bbb | | | | ft2 |
+ 1103 | 203 | ccc | | | | ft2 |
+(3 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1104,204,'ddd'), (1105,205,'eee');
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 300), c3 = (c3 || '_update3') WHERE ((("C 1" % 10) = 3))
+(3 rows)
+
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 400), c3 = (c3 || '_update7') WHERE ((("C 1" % 10) = 7)) RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+(4 rows)
+
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+----+------------+-----
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 1007 | 507 | 0000700007_update7 | | | | ft2 |
+ 1017 | 507 | 0001700017_update7 | | | | ft2 |
+(102 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9; -- can be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c2 = (r1.c2 + 500), c3 = (r1.c3 || '_update9'), c7 = 'ft2 '::character(10) FROM "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 9))
+(3 rows)
+
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9;
+EXPLAIN (verbose, costs off)
+ DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: c1, c4
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 5)) RETURNING "C 1", c4
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4;
+ c1 | c4
+------+------------------------------
+ 5 | Tue Jan 06 00:00:00 1970 PST
+ 15 | Fri Jan 16 00:00:00 1970 PST
+ 25 | Mon Jan 26 00:00:00 1970 PST
+ 35 | Thu Feb 05 00:00:00 1970 PST
+ 45 | Sun Feb 15 00:00:00 1970 PST
+ 55 | Wed Feb 25 00:00:00 1970 PST
+ 65 | Sat Mar 07 00:00:00 1970 PST
+ 75 | Tue Mar 17 00:00:00 1970 PST
+ 85 | Fri Mar 27 00:00:00 1970 PST
+ 95 | Mon Apr 06 00:00:00 1970 PST
+ 105 | Tue Jan 06 00:00:00 1970 PST
+ 115 | Fri Jan 16 00:00:00 1970 PST
+ 125 | Mon Jan 26 00:00:00 1970 PST
+ 135 | Thu Feb 05 00:00:00 1970 PST
+ 145 | Sun Feb 15 00:00:00 1970 PST
+ 155 | Wed Feb 25 00:00:00 1970 PST
+ 165 | Sat Mar 07 00:00:00 1970 PST
+ 175 | Tue Mar 17 00:00:00 1970 PST
+ 185 | Fri Mar 27 00:00:00 1970 PST
+ 195 | Mon Apr 06 00:00:00 1970 PST
+ 205 | Tue Jan 06 00:00:00 1970 PST
+ 215 | Fri Jan 16 00:00:00 1970 PST
+ 225 | Mon Jan 26 00:00:00 1970 PST
+ 235 | Thu Feb 05 00:00:00 1970 PST
+ 245 | Sun Feb 15 00:00:00 1970 PST
+ 255 | Wed Feb 25 00:00:00 1970 PST
+ 265 | Sat Mar 07 00:00:00 1970 PST
+ 275 | Tue Mar 17 00:00:00 1970 PST
+ 285 | Fri Mar 27 00:00:00 1970 PST
+ 295 | Mon Apr 06 00:00:00 1970 PST
+ 305 | Tue Jan 06 00:00:00 1970 PST
+ 315 | Fri Jan 16 00:00:00 1970 PST
+ 325 | Mon Jan 26 00:00:00 1970 PST
+ 335 | Thu Feb 05 00:00:00 1970 PST
+ 345 | Sun Feb 15 00:00:00 1970 PST
+ 355 | Wed Feb 25 00:00:00 1970 PST
+ 365 | Sat Mar 07 00:00:00 1970 PST
+ 375 | Tue Mar 17 00:00:00 1970 PST
+ 385 | Fri Mar 27 00:00:00 1970 PST
+ 395 | Mon Apr 06 00:00:00 1970 PST
+ 405 | Tue Jan 06 00:00:00 1970 PST
+ 415 | Fri Jan 16 00:00:00 1970 PST
+ 425 | Mon Jan 26 00:00:00 1970 PST
+ 435 | Thu Feb 05 00:00:00 1970 PST
+ 445 | Sun Feb 15 00:00:00 1970 PST
+ 455 | Wed Feb 25 00:00:00 1970 PST
+ 465 | Sat Mar 07 00:00:00 1970 PST
+ 475 | Tue Mar 17 00:00:00 1970 PST
+ 485 | Fri Mar 27 00:00:00 1970 PST
+ 495 | Mon Apr 06 00:00:00 1970 PST
+ 505 | Tue Jan 06 00:00:00 1970 PST
+ 515 | Fri Jan 16 00:00:00 1970 PST
+ 525 | Mon Jan 26 00:00:00 1970 PST
+ 535 | Thu Feb 05 00:00:00 1970 PST
+ 545 | Sun Feb 15 00:00:00 1970 PST
+ 555 | Wed Feb 25 00:00:00 1970 PST
+ 565 | Sat Mar 07 00:00:00 1970 PST
+ 575 | Tue Mar 17 00:00:00 1970 PST
+ 585 | Fri Mar 27 00:00:00 1970 PST
+ 595 | Mon Apr 06 00:00:00 1970 PST
+ 605 | Tue Jan 06 00:00:00 1970 PST
+ 615 | Fri Jan 16 00:00:00 1970 PST
+ 625 | Mon Jan 26 00:00:00 1970 PST
+ 635 | Thu Feb 05 00:00:00 1970 PST
+ 645 | Sun Feb 15 00:00:00 1970 PST
+ 655 | Wed Feb 25 00:00:00 1970 PST
+ 665 | Sat Mar 07 00:00:00 1970 PST
+ 675 | Tue Mar 17 00:00:00 1970 PST
+ 685 | Fri Mar 27 00:00:00 1970 PST
+ 695 | Mon Apr 06 00:00:00 1970 PST
+ 705 | Tue Jan 06 00:00:00 1970 PST
+ 715 | Fri Jan 16 00:00:00 1970 PST
+ 725 | Mon Jan 26 00:00:00 1970 PST
+ 735 | Thu Feb 05 00:00:00 1970 PST
+ 745 | Sun Feb 15 00:00:00 1970 PST
+ 755 | Wed Feb 25 00:00:00 1970 PST
+ 765 | Sat Mar 07 00:00:00 1970 PST
+ 775 | Tue Mar 17 00:00:00 1970 PST
+ 785 | Fri Mar 27 00:00:00 1970 PST
+ 795 | Mon Apr 06 00:00:00 1970 PST
+ 805 | Tue Jan 06 00:00:00 1970 PST
+ 815 | Fri Jan 16 00:00:00 1970 PST
+ 825 | Mon Jan 26 00:00:00 1970 PST
+ 835 | Thu Feb 05 00:00:00 1970 PST
+ 845 | Sun Feb 15 00:00:00 1970 PST
+ 855 | Wed Feb 25 00:00:00 1970 PST
+ 865 | Sat Mar 07 00:00:00 1970 PST
+ 875 | Tue Mar 17 00:00:00 1970 PST
+ 885 | Fri Mar 27 00:00:00 1970 PST
+ 895 | Mon Apr 06 00:00:00 1970 PST
+ 905 | Tue Jan 06 00:00:00 1970 PST
+ 915 | Fri Jan 16 00:00:00 1970 PST
+ 925 | Mon Jan 26 00:00:00 1970 PST
+ 935 | Thu Feb 05 00:00:00 1970 PST
+ 945 | Sun Feb 15 00:00:00 1970 PST
+ 955 | Wed Feb 25 00:00:00 1970 PST
+ 965 | Sat Mar 07 00:00:00 1970 PST
+ 975 | Tue Mar 17 00:00:00 1970 PST
+ 985 | Fri Mar 27 00:00:00 1970 PST
+ 995 | Mon Apr 06 00:00:00 1970 PST
+ 1005 |
+ 1015 |
+ 1105 |
+(103 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 2))
+(3 rows)
+
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2;
+SELECT c1,c2,c3,c4 FROM ft2 ORDER BY c1;
+ c1 | c2 | c3 | c4
+------+-----+--------------------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 3 | 303 | 00003_update3 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+ 11 | 1 | 00011 | Mon Jan 12 00:00:00 1970 PST
+ 13 | 303 | 00013_update3 | Wed Jan 14 00:00:00 1970 PST
+ 14 | 4 | 00014 | Thu Jan 15 00:00:00 1970 PST
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST
+ 18 | 8 | 00018 | Mon Jan 19 00:00:00 1970 PST
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST
+ 20 | 0 | 00020 | Wed Jan 21 00:00:00 1970 PST
+ 21 | 1 | 00021 | Thu Jan 22 00:00:00 1970 PST
+ 23 | 303 | 00023_update3 | Sat Jan 24 00:00:00 1970 PST
+ 24 | 4 | 00024 | Sun Jan 25 00:00:00 1970 PST
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST
+ 28 | 8 | 00028 | Thu Jan 29 00:00:00 1970 PST
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST
+ 30 | 0 | 00030 | Sat Jan 31 00:00:00 1970 PST
+ 31 | 1 | 00031 | Sun Feb 01 00:00:00 1970 PST
+ 33 | 303 | 00033_update3 | Tue Feb 03 00:00:00 1970 PST
+ 34 | 4 | 00034 | Wed Feb 04 00:00:00 1970 PST
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST
+ 38 | 8 | 00038 | Sun Feb 08 00:00:00 1970 PST
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST
+ 40 | 0 | 00040 | Tue Feb 10 00:00:00 1970 PST
+ 41 | 1 | 00041 | Wed Feb 11 00:00:00 1970 PST
+ 43 | 303 | 00043_update3 | Fri Feb 13 00:00:00 1970 PST
+ 44 | 4 | 00044 | Sat Feb 14 00:00:00 1970 PST
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST
+ 48 | 8 | 00048 | Wed Feb 18 00:00:00 1970 PST
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST
+ 50 | 0 | 00050 | Fri Feb 20 00:00:00 1970 PST
+ 51 | 1 | 00051 | Sat Feb 21 00:00:00 1970 PST
+ 53 | 303 | 00053_update3 | Mon Feb 23 00:00:00 1970 PST
+ 54 | 4 | 00054 | Tue Feb 24 00:00:00 1970 PST
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST
+ 58 | 8 | 00058 | Sat Feb 28 00:00:00 1970 PST
+ 59 | 509 | 00059_update9 | Sun Mar 01 00:00:00 1970 PST
+ 60 | 0 | 00060 | Mon Mar 02 00:00:00 1970 PST
+ 61 | 1 | 00061 | Tue Mar 03 00:00:00 1970 PST
+ 63 | 303 | 00063_update3 | Thu Mar 05 00:00:00 1970 PST
+ 64 | 4 | 00064 | Fri Mar 06 00:00:00 1970 PST
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST
+ 68 | 8 | 00068 | Tue Mar 10 00:00:00 1970 PST
+ 69 | 509 | 00069_update9 | Wed Mar 11 00:00:00 1970 PST
+ 70 | 0 | 00070 | Thu Mar 12 00:00:00 1970 PST
+ 71 | 1 | 00071 | Fri Mar 13 00:00:00 1970 PST
+ 73 | 303 | 00073_update3 | Sun Mar 15 00:00:00 1970 PST
+ 74 | 4 | 00074 | Mon Mar 16 00:00:00 1970 PST
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST
+ 78 | 8 | 00078 | Fri Mar 20 00:00:00 1970 PST
+ 79 | 509 | 00079_update9 | Sat Mar 21 00:00:00 1970 PST
+ 80 | 0 | 00080 | Sun Mar 22 00:00:00 1970 PST
+ 81 | 1 | 00081 | Mon Mar 23 00:00:00 1970 PST
+ 83 | 303 | 00083_update3 | Wed Mar 25 00:00:00 1970 PST
+ 84 | 4 | 00084 | Thu Mar 26 00:00:00 1970 PST
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST
+ 88 | 8 | 00088 | Mon Mar 30 00:00:00 1970 PST
+ 89 | 509 | 00089_update9 | Tue Mar 31 00:00:00 1970 PST
+ 90 | 0 | 00090 | Wed Apr 01 00:00:00 1970 PST
+ 91 | 1 | 00091 | Thu Apr 02 00:00:00 1970 PST
+ 93 | 303 | 00093_update3 | Sat Apr 04 00:00:00 1970 PST
+ 94 | 4 | 00094 | Sun Apr 05 00:00:00 1970 PST
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST
+ 98 | 8 | 00098 | Thu Apr 09 00:00:00 1970 PST
+ 99 | 509 | 00099_update9 | Fri Apr 10 00:00:00 1970 PST
+ 100 | 0 | 00100 | Thu Jan 01 00:00:00 1970 PST
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST
+ 103 | 303 | 00103_update3 | Sun Jan 04 00:00:00 1970 PST
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST
+ 109 | 509 | 00109_update9 | Sat Jan 10 00:00:00 1970 PST
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST
+ 111 | 1 | 00111 | Mon Jan 12 00:00:00 1970 PST
+ 113 | 303 | 00113_update3 | Wed Jan 14 00:00:00 1970 PST
+ 114 | 4 | 00114 | Thu Jan 15 00:00:00 1970 PST
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST
+ 118 | 8 | 00118 | Mon Jan 19 00:00:00 1970 PST
+ 119 | 509 | 00119_update9 | Tue Jan 20 00:00:00 1970 PST
+ 120 | 0 | 00120 | Wed Jan 21 00:00:00 1970 PST
+ 121 | 1 | 00121 | Thu Jan 22 00:00:00 1970 PST
+ 123 | 303 | 00123_update3 | Sat Jan 24 00:00:00 1970 PST
+ 124 | 4 | 00124 | Sun Jan 25 00:00:00 1970 PST
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST
+ 128 | 8 | 00128 | Thu Jan 29 00:00:00 1970 PST
+ 129 | 509 | 00129_update9 | Fri Jan 30 00:00:00 1970 PST
+ 130 | 0 | 00130 | Sat Jan 31 00:00:00 1970 PST
+ 131 | 1 | 00131 | Sun Feb 01 00:00:00 1970 PST
+ 133 | 303 | 00133_update3 | Tue Feb 03 00:00:00 1970 PST
+ 134 | 4 | 00134 | Wed Feb 04 00:00:00 1970 PST
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST
+ 138 | 8 | 00138 | Sun Feb 08 00:00:00 1970 PST
+ 139 | 509 | 00139_update9 | Mon Feb 09 00:00:00 1970 PST
+ 140 | 0 | 00140 | Tue Feb 10 00:00:00 1970 PST
+ 141 | 1 | 00141 | Wed Feb 11 00:00:00 1970 PST
+ 143 | 303 | 00143_update3 | Fri Feb 13 00:00:00 1970 PST
+ 144 | 4 | 00144 | Sat Feb 14 00:00:00 1970 PST
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST
+ 148 | 8 | 00148 | Wed Feb 18 00:00:00 1970 PST
+ 149 | 509 | 00149_update9 | Thu Feb 19 00:00:00 1970 PST
+ 150 | 0 | 00150 | Fri Feb 20 00:00:00 1970 PST
+ 151 | 1 | 00151 | Sat Feb 21 00:00:00 1970 PST
+ 153 | 303 | 00153_update3 | Mon Feb 23 00:00:00 1970 PST
+ 154 | 4 | 00154 | Tue Feb 24 00:00:00 1970 PST
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST
+ 158 | 8 | 00158 | Sat Feb 28 00:00:00 1970 PST
+ 159 | 509 | 00159_update9 | Sun Mar 01 00:00:00 1970 PST
+ 160 | 0 | 00160 | Mon Mar 02 00:00:00 1970 PST
+ 161 | 1 | 00161 | Tue Mar 03 00:00:00 1970 PST
+ 163 | 303 | 00163_update3 | Thu Mar 05 00:00:00 1970 PST
+ 164 | 4 | 00164 | Fri Mar 06 00:00:00 1970 PST
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST
+ 168 | 8 | 00168 | Tue Mar 10 00:00:00 1970 PST
+ 169 | 509 | 00169_update9 | Wed Mar 11 00:00:00 1970 PST
+ 170 | 0 | 00170 | Thu Mar 12 00:00:00 1970 PST
+ 171 | 1 | 00171 | Fri Mar 13 00:00:00 1970 PST
+ 173 | 303 | 00173_update3 | Sun Mar 15 00:00:00 1970 PST
+ 174 | 4 | 00174 | Mon Mar 16 00:00:00 1970 PST
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST
+ 178 | 8 | 00178 | Fri Mar 20 00:00:00 1970 PST
+ 179 | 509 | 00179_update9 | Sat Mar 21 00:00:00 1970 PST
+ 180 | 0 | 00180 | Sun Mar 22 00:00:00 1970 PST
+ 181 | 1 | 00181 | Mon Mar 23 00:00:00 1970 PST
+ 183 | 303 | 00183_update3 | Wed Mar 25 00:00:00 1970 PST
+ 184 | 4 | 00184 | Thu Mar 26 00:00:00 1970 PST
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST
+ 188 | 8 | 00188 | Mon Mar 30 00:00:00 1970 PST
+ 189 | 509 | 00189_update9 | Tue Mar 31 00:00:00 1970 PST
+ 190 | 0 | 00190 | Wed Apr 01 00:00:00 1970 PST
+ 191 | 1 | 00191 | Thu Apr 02 00:00:00 1970 PST
+ 193 | 303 | 00193_update3 | Sat Apr 04 00:00:00 1970 PST
+ 194 | 4 | 00194 | Sun Apr 05 00:00:00 1970 PST
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST
+ 198 | 8 | 00198 | Thu Apr 09 00:00:00 1970 PST
+ 199 | 509 | 00199_update9 | Fri Apr 10 00:00:00 1970 PST
+ 200 | 0 | 00200 | Thu Jan 01 00:00:00 1970 PST
+ 201 | 1 | 00201 | Fri Jan 02 00:00:00 1970 PST
+ 203 | 303 | 00203_update3 | Sun Jan 04 00:00:00 1970 PST
+ 204 | 4 | 00204 | Mon Jan 05 00:00:00 1970 PST
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST
+ 208 | 8 | 00208 | Fri Jan 09 00:00:00 1970 PST
+ 209 | 509 | 00209_update9 | Sat Jan 10 00:00:00 1970 PST
+ 210 | 0 | 00210 | Sun Jan 11 00:00:00 1970 PST
+ 211 | 1 | 00211 | Mon Jan 12 00:00:00 1970 PST
+ 213 | 303 | 00213_update3 | Wed Jan 14 00:00:00 1970 PST
+ 214 | 4 | 00214 | Thu Jan 15 00:00:00 1970 PST
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST
+ 218 | 8 | 00218 | Mon Jan 19 00:00:00 1970 PST
+ 219 | 509 | 00219_update9 | Tue Jan 20 00:00:00 1970 PST
+ 220 | 0 | 00220 | Wed Jan 21 00:00:00 1970 PST
+ 221 | 1 | 00221 | Thu Jan 22 00:00:00 1970 PST
+ 223 | 303 | 00223_update3 | Sat Jan 24 00:00:00 1970 PST
+ 224 | 4 | 00224 | Sun Jan 25 00:00:00 1970 PST
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST
+ 228 | 8 | 00228 | Thu Jan 29 00:00:00 1970 PST
+ 229 | 509 | 00229_update9 | Fri Jan 30 00:00:00 1970 PST
+ 230 | 0 | 00230 | Sat Jan 31 00:00:00 1970 PST
+ 231 | 1 | 00231 | Sun Feb 01 00:00:00 1970 PST
+ 233 | 303 | 00233_update3 | Tue Feb 03 00:00:00 1970 PST
+ 234 | 4 | 00234 | Wed Feb 04 00:00:00 1970 PST
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST
+ 238 | 8 | 00238 | Sun Feb 08 00:00:00 1970 PST
+ 239 | 509 | 00239_update9 | Mon Feb 09 00:00:00 1970 PST
+ 240 | 0 | 00240 | Tue Feb 10 00:00:00 1970 PST
+ 241 | 1 | 00241 | Wed Feb 11 00:00:00 1970 PST
+ 243 | 303 | 00243_update3 | Fri Feb 13 00:00:00 1970 PST
+ 244 | 4 | 00244 | Sat Feb 14 00:00:00 1970 PST
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST
+ 248 | 8 | 00248 | Wed Feb 18 00:00:00 1970 PST
+ 249 | 509 | 00249_update9 | Thu Feb 19 00:00:00 1970 PST
+ 250 | 0 | 00250 | Fri Feb 20 00:00:00 1970 PST
+ 251 | 1 | 00251 | Sat Feb 21 00:00:00 1970 PST
+ 253 | 303 | 00253_update3 | Mon Feb 23 00:00:00 1970 PST
+ 254 | 4 | 00254 | Tue Feb 24 00:00:00 1970 PST
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST
+ 258 | 8 | 00258 | Sat Feb 28 00:00:00 1970 PST
+ 259 | 509 | 00259_update9 | Sun Mar 01 00:00:00 1970 PST
+ 260 | 0 | 00260 | Mon Mar 02 00:00:00 1970 PST
+ 261 | 1 | 00261 | Tue Mar 03 00:00:00 1970 PST
+ 263 | 303 | 00263_update3 | Thu Mar 05 00:00:00 1970 PST
+ 264 | 4 | 00264 | Fri Mar 06 00:00:00 1970 PST
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST
+ 268 | 8 | 00268 | Tue Mar 10 00:00:00 1970 PST
+ 269 | 509 | 00269_update9 | Wed Mar 11 00:00:00 1970 PST
+ 270 | 0 | 00270 | Thu Mar 12 00:00:00 1970 PST
+ 271 | 1 | 00271 | Fri Mar 13 00:00:00 1970 PST
+ 273 | 303 | 00273_update3 | Sun Mar 15 00:00:00 1970 PST
+ 274 | 4 | 00274 | Mon Mar 16 00:00:00 1970 PST
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST
+ 278 | 8 | 00278 | Fri Mar 20 00:00:00 1970 PST
+ 279 | 509 | 00279_update9 | Sat Mar 21 00:00:00 1970 PST
+ 280 | 0 | 00280 | Sun Mar 22 00:00:00 1970 PST
+ 281 | 1 | 00281 | Mon Mar 23 00:00:00 1970 PST
+ 283 | 303 | 00283_update3 | Wed Mar 25 00:00:00 1970 PST
+ 284 | 4 | 00284 | Thu Mar 26 00:00:00 1970 PST
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST
+ 288 | 8 | 00288 | Mon Mar 30 00:00:00 1970 PST
+ 289 | 509 | 00289_update9 | Tue Mar 31 00:00:00 1970 PST
+ 290 | 0 | 00290 | Wed Apr 01 00:00:00 1970 PST
+ 291 | 1 | 00291 | Thu Apr 02 00:00:00 1970 PST
+ 293 | 303 | 00293_update3 | Sat Apr 04 00:00:00 1970 PST
+ 294 | 4 | 00294 | Sun Apr 05 00:00:00 1970 PST
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST
+ 298 | 8 | 00298 | Thu Apr 09 00:00:00 1970 PST
+ 299 | 509 | 00299_update9 | Fri Apr 10 00:00:00 1970 PST
+ 300 | 0 | 00300 | Thu Jan 01 00:00:00 1970 PST
+ 301 | 1 | 00301 | Fri Jan 02 00:00:00 1970 PST
+ 303 | 303 | 00303_update3 | Sun Jan 04 00:00:00 1970 PST
+ 304 | 4 | 00304 | Mon Jan 05 00:00:00 1970 PST
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST
+ 308 | 8 | 00308 | Fri Jan 09 00:00:00 1970 PST
+ 309 | 509 | 00309_update9 | Sat Jan 10 00:00:00 1970 PST
+ 310 | 0 | 00310 | Sun Jan 11 00:00:00 1970 PST
+ 311 | 1 | 00311 | Mon Jan 12 00:00:00 1970 PST
+ 313 | 303 | 00313_update3 | Wed Jan 14 00:00:00 1970 PST
+ 314 | 4 | 00314 | Thu Jan 15 00:00:00 1970 PST
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST
+ 318 | 8 | 00318 | Mon Jan 19 00:00:00 1970 PST
+ 319 | 509 | 00319_update9 | Tue Jan 20 00:00:00 1970 PST
+ 320 | 0 | 00320 | Wed Jan 21 00:00:00 1970 PST
+ 321 | 1 | 00321 | Thu Jan 22 00:00:00 1970 PST
+ 323 | 303 | 00323_update3 | Sat Jan 24 00:00:00 1970 PST
+ 324 | 4 | 00324 | Sun Jan 25 00:00:00 1970 PST
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST
+ 328 | 8 | 00328 | Thu Jan 29 00:00:00 1970 PST
+ 329 | 509 | 00329_update9 | Fri Jan 30 00:00:00 1970 PST
+ 330 | 0 | 00330 | Sat Jan 31 00:00:00 1970 PST
+ 331 | 1 | 00331 | Sun Feb 01 00:00:00 1970 PST
+ 333 | 303 | 00333_update3 | Tue Feb 03 00:00:00 1970 PST
+ 334 | 4 | 00334 | Wed Feb 04 00:00:00 1970 PST
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST
+ 338 | 8 | 00338 | Sun Feb 08 00:00:00 1970 PST
+ 339 | 509 | 00339_update9 | Mon Feb 09 00:00:00 1970 PST
+ 340 | 0 | 00340 | Tue Feb 10 00:00:00 1970 PST
+ 341 | 1 | 00341 | Wed Feb 11 00:00:00 1970 PST
+ 343 | 303 | 00343_update3 | Fri Feb 13 00:00:00 1970 PST
+ 344 | 4 | 00344 | Sat Feb 14 00:00:00 1970 PST
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST
+ 348 | 8 | 00348 | Wed Feb 18 00:00:00 1970 PST
+ 349 | 509 | 00349_update9 | Thu Feb 19 00:00:00 1970 PST
+ 350 | 0 | 00350 | Fri Feb 20 00:00:00 1970 PST
+ 351 | 1 | 00351 | Sat Feb 21 00:00:00 1970 PST
+ 353 | 303 | 00353_update3 | Mon Feb 23 00:00:00 1970 PST
+ 354 | 4 | 00354 | Tue Feb 24 00:00:00 1970 PST
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST
+ 358 | 8 | 00358 | Sat Feb 28 00:00:00 1970 PST
+ 359 | 509 | 00359_update9 | Sun Mar 01 00:00:00 1970 PST
+ 360 | 0 | 00360 | Mon Mar 02 00:00:00 1970 PST
+ 361 | 1 | 00361 | Tue Mar 03 00:00:00 1970 PST
+ 363 | 303 | 00363_update3 | Thu Mar 05 00:00:00 1970 PST
+ 364 | 4 | 00364 | Fri Mar 06 00:00:00 1970 PST
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST
+ 368 | 8 | 00368 | Tue Mar 10 00:00:00 1970 PST
+ 369 | 509 | 00369_update9 | Wed Mar 11 00:00:00 1970 PST
+ 370 | 0 | 00370 | Thu Mar 12 00:00:00 1970 PST
+ 371 | 1 | 00371 | Fri Mar 13 00:00:00 1970 PST
+ 373 | 303 | 00373_update3 | Sun Mar 15 00:00:00 1970 PST
+ 374 | 4 | 00374 | Mon Mar 16 00:00:00 1970 PST
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST
+ 378 | 8 | 00378 | Fri Mar 20 00:00:00 1970 PST
+ 379 | 509 | 00379_update9 | Sat Mar 21 00:00:00 1970 PST
+ 380 | 0 | 00380 | Sun Mar 22 00:00:00 1970 PST
+ 381 | 1 | 00381 | Mon Mar 23 00:00:00 1970 PST
+ 383 | 303 | 00383_update3 | Wed Mar 25 00:00:00 1970 PST
+ 384 | 4 | 00384 | Thu Mar 26 00:00:00 1970 PST
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST
+ 388 | 8 | 00388 | Mon Mar 30 00:00:00 1970 PST
+ 389 | 509 | 00389_update9 | Tue Mar 31 00:00:00 1970 PST
+ 390 | 0 | 00390 | Wed Apr 01 00:00:00 1970 PST
+ 391 | 1 | 00391 | Thu Apr 02 00:00:00 1970 PST
+ 393 | 303 | 00393_update3 | Sat Apr 04 00:00:00 1970 PST
+ 394 | 4 | 00394 | Sun Apr 05 00:00:00 1970 PST
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST
+ 398 | 8 | 00398 | Thu Apr 09 00:00:00 1970 PST
+ 399 | 509 | 00399_update9 | Fri Apr 10 00:00:00 1970 PST
+ 400 | 0 | 00400 | Thu Jan 01 00:00:00 1970 PST
+ 401 | 1 | 00401 | Fri Jan 02 00:00:00 1970 PST
+ 403 | 303 | 00403_update3 | Sun Jan 04 00:00:00 1970 PST
+ 404 | 4 | 00404 | Mon Jan 05 00:00:00 1970 PST
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST
+ 408 | 8 | 00408 | Fri Jan 09 00:00:00 1970 PST
+ 409 | 509 | 00409_update9 | Sat Jan 10 00:00:00 1970 PST
+ 410 | 0 | 00410 | Sun Jan 11 00:00:00 1970 PST
+ 411 | 1 | 00411 | Mon Jan 12 00:00:00 1970 PST
+ 413 | 303 | 00413_update3 | Wed Jan 14 00:00:00 1970 PST
+ 414 | 4 | 00414 | Thu Jan 15 00:00:00 1970 PST
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST
+ 418 | 8 | 00418 | Mon Jan 19 00:00:00 1970 PST
+ 419 | 509 | 00419_update9 | Tue Jan 20 00:00:00 1970 PST
+ 420 | 0 | 00420 | Wed Jan 21 00:00:00 1970 PST
+ 421 | 1 | 00421 | Thu Jan 22 00:00:00 1970 PST
+ 423 | 303 | 00423_update3 | Sat Jan 24 00:00:00 1970 PST
+ 424 | 4 | 00424 | Sun Jan 25 00:00:00 1970 PST
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST
+ 428 | 8 | 00428 | Thu Jan 29 00:00:00 1970 PST
+ 429 | 509 | 00429_update9 | Fri Jan 30 00:00:00 1970 PST
+ 430 | 0 | 00430 | Sat Jan 31 00:00:00 1970 PST
+ 431 | 1 | 00431 | Sun Feb 01 00:00:00 1970 PST
+ 433 | 303 | 00433_update3 | Tue Feb 03 00:00:00 1970 PST
+ 434 | 4 | 00434 | Wed Feb 04 00:00:00 1970 PST
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST
+ 438 | 8 | 00438 | Sun Feb 08 00:00:00 1970 PST
+ 439 | 509 | 00439_update9 | Mon Feb 09 00:00:00 1970 PST
+ 440 | 0 | 00440 | Tue Feb 10 00:00:00 1970 PST
+ 441 | 1 | 00441 | Wed Feb 11 00:00:00 1970 PST
+ 443 | 303 | 00443_update3 | Fri Feb 13 00:00:00 1970 PST
+ 444 | 4 | 00444 | Sat Feb 14 00:00:00 1970 PST
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST
+ 448 | 8 | 00448 | Wed Feb 18 00:00:00 1970 PST
+ 449 | 509 | 00449_update9 | Thu Feb 19 00:00:00 1970 PST
+ 450 | 0 | 00450 | Fri Feb 20 00:00:00 1970 PST
+ 451 | 1 | 00451 | Sat Feb 21 00:00:00 1970 PST
+ 453 | 303 | 00453_update3 | Mon Feb 23 00:00:00 1970 PST
+ 454 | 4 | 00454 | Tue Feb 24 00:00:00 1970 PST
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST
+ 458 | 8 | 00458 | Sat Feb 28 00:00:00 1970 PST
+ 459 | 509 | 00459_update9 | Sun Mar 01 00:00:00 1970 PST
+ 460 | 0 | 00460 | Mon Mar 02 00:00:00 1970 PST
+ 461 | 1 | 00461 | Tue Mar 03 00:00:00 1970 PST
+ 463 | 303 | 00463_update3 | Thu Mar 05 00:00:00 1970 PST
+ 464 | 4 | 00464 | Fri Mar 06 00:00:00 1970 PST
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST
+ 468 | 8 | 00468 | Tue Mar 10 00:00:00 1970 PST
+ 469 | 509 | 00469_update9 | Wed Mar 11 00:00:00 1970 PST
+ 470 | 0 | 00470 | Thu Mar 12 00:00:00 1970 PST
+ 471 | 1 | 00471 | Fri Mar 13 00:00:00 1970 PST
+ 473 | 303 | 00473_update3 | Sun Mar 15 00:00:00 1970 PST
+ 474 | 4 | 00474 | Mon Mar 16 00:00:00 1970 PST
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST
+ 478 | 8 | 00478 | Fri Mar 20 00:00:00 1970 PST
+ 479 | 509 | 00479_update9 | Sat Mar 21 00:00:00 1970 PST
+ 480 | 0 | 00480 | Sun Mar 22 00:00:00 1970 PST
+ 481 | 1 | 00481 | Mon Mar 23 00:00:00 1970 PST
+ 483 | 303 | 00483_update3 | Wed Mar 25 00:00:00 1970 PST
+ 484 | 4 | 00484 | Thu Mar 26 00:00:00 1970 PST
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST
+ 488 | 8 | 00488 | Mon Mar 30 00:00:00 1970 PST
+ 489 | 509 | 00489_update9 | Tue Mar 31 00:00:00 1970 PST
+ 490 | 0 | 00490 | Wed Apr 01 00:00:00 1970 PST
+ 491 | 1 | 00491 | Thu Apr 02 00:00:00 1970 PST
+ 493 | 303 | 00493_update3 | Sat Apr 04 00:00:00 1970 PST
+ 494 | 4 | 00494 | Sun Apr 05 00:00:00 1970 PST
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST
+ 498 | 8 | 00498 | Thu Apr 09 00:00:00 1970 PST
+ 499 | 509 | 00499_update9 | Fri Apr 10 00:00:00 1970 PST
+ 500 | 0 | 00500 | Thu Jan 01 00:00:00 1970 PST
+ 501 | 1 | 00501 | Fri Jan 02 00:00:00 1970 PST
+ 503 | 303 | 00503_update3 | Sun Jan 04 00:00:00 1970 PST
+ 504 | 4 | 00504 | Mon Jan 05 00:00:00 1970 PST
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST
+ 508 | 8 | 00508 | Fri Jan 09 00:00:00 1970 PST
+ 509 | 509 | 00509_update9 | Sat Jan 10 00:00:00 1970 PST
+ 510 | 0 | 00510 | Sun Jan 11 00:00:00 1970 PST
+ 511 | 1 | 00511 | Mon Jan 12 00:00:00 1970 PST
+ 513 | 303 | 00513_update3 | Wed Jan 14 00:00:00 1970 PST
+ 514 | 4 | 00514 | Thu Jan 15 00:00:00 1970 PST
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST
+ 518 | 8 | 00518 | Mon Jan 19 00:00:00 1970 PST
+ 519 | 509 | 00519_update9 | Tue Jan 20 00:00:00 1970 PST
+ 520 | 0 | 00520 | Wed Jan 21 00:00:00 1970 PST
+ 521 | 1 | 00521 | Thu Jan 22 00:00:00 1970 PST
+ 523 | 303 | 00523_update3 | Sat Jan 24 00:00:00 1970 PST
+ 524 | 4 | 00524 | Sun Jan 25 00:00:00 1970 PST
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST
+ 528 | 8 | 00528 | Thu Jan 29 00:00:00 1970 PST
+ 529 | 509 | 00529_update9 | Fri Jan 30 00:00:00 1970 PST
+ 530 | 0 | 00530 | Sat Jan 31 00:00:00 1970 PST
+ 531 | 1 | 00531 | Sun Feb 01 00:00:00 1970 PST
+ 533 | 303 | 00533_update3 | Tue Feb 03 00:00:00 1970 PST
+ 534 | 4 | 00534 | Wed Feb 04 00:00:00 1970 PST
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST
+ 538 | 8 | 00538 | Sun Feb 08 00:00:00 1970 PST
+ 539 | 509 | 00539_update9 | Mon Feb 09 00:00:00 1970 PST
+ 540 | 0 | 00540 | Tue Feb 10 00:00:00 1970 PST
+ 541 | 1 | 00541 | Wed Feb 11 00:00:00 1970 PST
+ 543 | 303 | 00543_update3 | Fri Feb 13 00:00:00 1970 PST
+ 544 | 4 | 00544 | Sat Feb 14 00:00:00 1970 PST
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST
+ 548 | 8 | 00548 | Wed Feb 18 00:00:00 1970 PST
+ 549 | 509 | 00549_update9 | Thu Feb 19 00:00:00 1970 PST
+ 550 | 0 | 00550 | Fri Feb 20 00:00:00 1970 PST
+ 551 | 1 | 00551 | Sat Feb 21 00:00:00 1970 PST
+ 553 | 303 | 00553_update3 | Mon Feb 23 00:00:00 1970 PST
+ 554 | 4 | 00554 | Tue Feb 24 00:00:00 1970 PST
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST
+ 558 | 8 | 00558 | Sat Feb 28 00:00:00 1970 PST
+ 559 | 509 | 00559_update9 | Sun Mar 01 00:00:00 1970 PST
+ 560 | 0 | 00560 | Mon Mar 02 00:00:00 1970 PST
+ 561 | 1 | 00561 | Tue Mar 03 00:00:00 1970 PST
+ 563 | 303 | 00563_update3 | Thu Mar 05 00:00:00 1970 PST
+ 564 | 4 | 00564 | Fri Mar 06 00:00:00 1970 PST
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST
+ 568 | 8 | 00568 | Tue Mar 10 00:00:00 1970 PST
+ 569 | 509 | 00569_update9 | Wed Mar 11 00:00:00 1970 PST
+ 570 | 0 | 00570 | Thu Mar 12 00:00:00 1970 PST
+ 571 | 1 | 00571 | Fri Mar 13 00:00:00 1970 PST
+ 573 | 303 | 00573_update3 | Sun Mar 15 00:00:00 1970 PST
+ 574 | 4 | 00574 | Mon Mar 16 00:00:00 1970 PST
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST
+ 578 | 8 | 00578 | Fri Mar 20 00:00:00 1970 PST
+ 579 | 509 | 00579_update9 | Sat Mar 21 00:00:00 1970 PST
+ 580 | 0 | 00580 | Sun Mar 22 00:00:00 1970 PST
+ 581 | 1 | 00581 | Mon Mar 23 00:00:00 1970 PST
+ 583 | 303 | 00583_update3 | Wed Mar 25 00:00:00 1970 PST
+ 584 | 4 | 00584 | Thu Mar 26 00:00:00 1970 PST
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST
+ 588 | 8 | 00588 | Mon Mar 30 00:00:00 1970 PST
+ 589 | 509 | 00589_update9 | Tue Mar 31 00:00:00 1970 PST
+ 590 | 0 | 00590 | Wed Apr 01 00:00:00 1970 PST
+ 591 | 1 | 00591 | Thu Apr 02 00:00:00 1970 PST
+ 593 | 303 | 00593_update3 | Sat Apr 04 00:00:00 1970 PST
+ 594 | 4 | 00594 | Sun Apr 05 00:00:00 1970 PST
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST
+ 598 | 8 | 00598 | Thu Apr 09 00:00:00 1970 PST
+ 599 | 509 | 00599_update9 | Fri Apr 10 00:00:00 1970 PST
+ 600 | 0 | 00600 | Thu Jan 01 00:00:00 1970 PST
+ 601 | 1 | 00601 | Fri Jan 02 00:00:00 1970 PST
+ 603 | 303 | 00603_update3 | Sun Jan 04 00:00:00 1970 PST
+ 604 | 4 | 00604 | Mon Jan 05 00:00:00 1970 PST
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST
+ 608 | 8 | 00608 | Fri Jan 09 00:00:00 1970 PST
+ 609 | 509 | 00609_update9 | Sat Jan 10 00:00:00 1970 PST
+ 610 | 0 | 00610 | Sun Jan 11 00:00:00 1970 PST
+ 611 | 1 | 00611 | Mon Jan 12 00:00:00 1970 PST
+ 613 | 303 | 00613_update3 | Wed Jan 14 00:00:00 1970 PST
+ 614 | 4 | 00614 | Thu Jan 15 00:00:00 1970 PST
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST
+ 618 | 8 | 00618 | Mon Jan 19 00:00:00 1970 PST
+ 619 | 509 | 00619_update9 | Tue Jan 20 00:00:00 1970 PST
+ 620 | 0 | 00620 | Wed Jan 21 00:00:00 1970 PST
+ 621 | 1 | 00621 | Thu Jan 22 00:00:00 1970 PST
+ 623 | 303 | 00623_update3 | Sat Jan 24 00:00:00 1970 PST
+ 624 | 4 | 00624 | Sun Jan 25 00:00:00 1970 PST
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST
+ 628 | 8 | 00628 | Thu Jan 29 00:00:00 1970 PST
+ 629 | 509 | 00629_update9 | Fri Jan 30 00:00:00 1970 PST
+ 630 | 0 | 00630 | Sat Jan 31 00:00:00 1970 PST
+ 631 | 1 | 00631 | Sun Feb 01 00:00:00 1970 PST
+ 633 | 303 | 00633_update3 | Tue Feb 03 00:00:00 1970 PST
+ 634 | 4 | 00634 | Wed Feb 04 00:00:00 1970 PST
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST
+ 638 | 8 | 00638 | Sun Feb 08 00:00:00 1970 PST
+ 639 | 509 | 00639_update9 | Mon Feb 09 00:00:00 1970 PST
+ 640 | 0 | 00640 | Tue Feb 10 00:00:00 1970 PST
+ 641 | 1 | 00641 | Wed Feb 11 00:00:00 1970 PST
+ 643 | 303 | 00643_update3 | Fri Feb 13 00:00:00 1970 PST
+ 644 | 4 | 00644 | Sat Feb 14 00:00:00 1970 PST
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST
+ 648 | 8 | 00648 | Wed Feb 18 00:00:00 1970 PST
+ 649 | 509 | 00649_update9 | Thu Feb 19 00:00:00 1970 PST
+ 650 | 0 | 00650 | Fri Feb 20 00:00:00 1970 PST
+ 651 | 1 | 00651 | Sat Feb 21 00:00:00 1970 PST
+ 653 | 303 | 00653_update3 | Mon Feb 23 00:00:00 1970 PST
+ 654 | 4 | 00654 | Tue Feb 24 00:00:00 1970 PST
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST
+ 658 | 8 | 00658 | Sat Feb 28 00:00:00 1970 PST
+ 659 | 509 | 00659_update9 | Sun Mar 01 00:00:00 1970 PST
+ 660 | 0 | 00660 | Mon Mar 02 00:00:00 1970 PST
+ 661 | 1 | 00661 | Tue Mar 03 00:00:00 1970 PST
+ 663 | 303 | 00663_update3 | Thu Mar 05 00:00:00 1970 PST
+ 664 | 4 | 00664 | Fri Mar 06 00:00:00 1970 PST
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST
+ 668 | 8 | 00668 | Tue Mar 10 00:00:00 1970 PST
+ 669 | 509 | 00669_update9 | Wed Mar 11 00:00:00 1970 PST
+ 670 | 0 | 00670 | Thu Mar 12 00:00:00 1970 PST
+ 671 | 1 | 00671 | Fri Mar 13 00:00:00 1970 PST
+ 673 | 303 | 00673_update3 | Sun Mar 15 00:00:00 1970 PST
+ 674 | 4 | 00674 | Mon Mar 16 00:00:00 1970 PST
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST
+ 678 | 8 | 00678 | Fri Mar 20 00:00:00 1970 PST
+ 679 | 509 | 00679_update9 | Sat Mar 21 00:00:00 1970 PST
+ 680 | 0 | 00680 | Sun Mar 22 00:00:00 1970 PST
+ 681 | 1 | 00681 | Mon Mar 23 00:00:00 1970 PST
+ 683 | 303 | 00683_update3 | Wed Mar 25 00:00:00 1970 PST
+ 684 | 4 | 00684 | Thu Mar 26 00:00:00 1970 PST
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST
+ 688 | 8 | 00688 | Mon Mar 30 00:00:00 1970 PST
+ 689 | 509 | 00689_update9 | Tue Mar 31 00:00:00 1970 PST
+ 690 | 0 | 00690 | Wed Apr 01 00:00:00 1970 PST
+ 691 | 1 | 00691 | Thu Apr 02 00:00:00 1970 PST
+ 693 | 303 | 00693_update3 | Sat Apr 04 00:00:00 1970 PST
+ 694 | 4 | 00694 | Sun Apr 05 00:00:00 1970 PST
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST
+ 698 | 8 | 00698 | Thu Apr 09 00:00:00 1970 PST
+ 699 | 509 | 00699_update9 | Fri Apr 10 00:00:00 1970 PST
+ 700 | 0 | 00700 | Thu Jan 01 00:00:00 1970 PST
+ 701 | 1 | 00701 | Fri Jan 02 00:00:00 1970 PST
+ 703 | 303 | 00703_update3 | Sun Jan 04 00:00:00 1970 PST
+ 704 | 4 | 00704 | Mon Jan 05 00:00:00 1970 PST
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST
+ 708 | 8 | 00708 | Fri Jan 09 00:00:00 1970 PST
+ 709 | 509 | 00709_update9 | Sat Jan 10 00:00:00 1970 PST
+ 710 | 0 | 00710 | Sun Jan 11 00:00:00 1970 PST
+ 711 | 1 | 00711 | Mon Jan 12 00:00:00 1970 PST
+ 713 | 303 | 00713_update3 | Wed Jan 14 00:00:00 1970 PST
+ 714 | 4 | 00714 | Thu Jan 15 00:00:00 1970 PST
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST
+ 718 | 8 | 00718 | Mon Jan 19 00:00:00 1970 PST
+ 719 | 509 | 00719_update9 | Tue Jan 20 00:00:00 1970 PST
+ 720 | 0 | 00720 | Wed Jan 21 00:00:00 1970 PST
+ 721 | 1 | 00721 | Thu Jan 22 00:00:00 1970 PST
+ 723 | 303 | 00723_update3 | Sat Jan 24 00:00:00 1970 PST
+ 724 | 4 | 00724 | Sun Jan 25 00:00:00 1970 PST
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST
+ 728 | 8 | 00728 | Thu Jan 29 00:00:00 1970 PST
+ 729 | 509 | 00729_update9 | Fri Jan 30 00:00:00 1970 PST
+ 730 | 0 | 00730 | Sat Jan 31 00:00:00 1970 PST
+ 731 | 1 | 00731 | Sun Feb 01 00:00:00 1970 PST
+ 733 | 303 | 00733_update3 | Tue Feb 03 00:00:00 1970 PST
+ 734 | 4 | 00734 | Wed Feb 04 00:00:00 1970 PST
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST
+ 738 | 8 | 00738 | Sun Feb 08 00:00:00 1970 PST
+ 739 | 509 | 00739_update9 | Mon Feb 09 00:00:00 1970 PST
+ 740 | 0 | 00740 | Tue Feb 10 00:00:00 1970 PST
+ 741 | 1 | 00741 | Wed Feb 11 00:00:00 1970 PST
+ 743 | 303 | 00743_update3 | Fri Feb 13 00:00:00 1970 PST
+ 744 | 4 | 00744 | Sat Feb 14 00:00:00 1970 PST
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST
+ 748 | 8 | 00748 | Wed Feb 18 00:00:00 1970 PST
+ 749 | 509 | 00749_update9 | Thu Feb 19 00:00:00 1970 PST
+ 750 | 0 | 00750 | Fri Feb 20 00:00:00 1970 PST
+ 751 | 1 | 00751 | Sat Feb 21 00:00:00 1970 PST
+ 753 | 303 | 00753_update3 | Mon Feb 23 00:00:00 1970 PST
+ 754 | 4 | 00754 | Tue Feb 24 00:00:00 1970 PST
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST
+ 758 | 8 | 00758 | Sat Feb 28 00:00:00 1970 PST
+ 759 | 509 | 00759_update9 | Sun Mar 01 00:00:00 1970 PST
+ 760 | 0 | 00760 | Mon Mar 02 00:00:00 1970 PST
+ 761 | 1 | 00761 | Tue Mar 03 00:00:00 1970 PST
+ 763 | 303 | 00763_update3 | Thu Mar 05 00:00:00 1970 PST
+ 764 | 4 | 00764 | Fri Mar 06 00:00:00 1970 PST
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST
+ 768 | 8 | 00768 | Tue Mar 10 00:00:00 1970 PST
+ 769 | 509 | 00769_update9 | Wed Mar 11 00:00:00 1970 PST
+ 770 | 0 | 00770 | Thu Mar 12 00:00:00 1970 PST
+ 771 | 1 | 00771 | Fri Mar 13 00:00:00 1970 PST
+ 773 | 303 | 00773_update3 | Sun Mar 15 00:00:00 1970 PST
+ 774 | 4 | 00774 | Mon Mar 16 00:00:00 1970 PST
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST
+ 778 | 8 | 00778 | Fri Mar 20 00:00:00 1970 PST
+ 779 | 509 | 00779_update9 | Sat Mar 21 00:00:00 1970 PST
+ 780 | 0 | 00780 | Sun Mar 22 00:00:00 1970 PST
+ 781 | 1 | 00781 | Mon Mar 23 00:00:00 1970 PST
+ 783 | 303 | 00783_update3 | Wed Mar 25 00:00:00 1970 PST
+ 784 | 4 | 00784 | Thu Mar 26 00:00:00 1970 PST
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST
+ 788 | 8 | 00788 | Mon Mar 30 00:00:00 1970 PST
+ 789 | 509 | 00789_update9 | Tue Mar 31 00:00:00 1970 PST
+ 790 | 0 | 00790 | Wed Apr 01 00:00:00 1970 PST
+ 791 | 1 | 00791 | Thu Apr 02 00:00:00 1970 PST
+ 793 | 303 | 00793_update3 | Sat Apr 04 00:00:00 1970 PST
+ 794 | 4 | 00794 | Sun Apr 05 00:00:00 1970 PST
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST
+ 798 | 8 | 00798 | Thu Apr 09 00:00:00 1970 PST
+ 799 | 509 | 00799_update9 | Fri Apr 10 00:00:00 1970 PST
+ 800 | 0 | 00800 | Thu Jan 01 00:00:00 1970 PST
+ 801 | 1 | 00801 | Fri Jan 02 00:00:00 1970 PST
+ 803 | 303 | 00803_update3 | Sun Jan 04 00:00:00 1970 PST
+ 804 | 4 | 00804 | Mon Jan 05 00:00:00 1970 PST
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST
+ 808 | 8 | 00808 | Fri Jan 09 00:00:00 1970 PST
+ 809 | 509 | 00809_update9 | Sat Jan 10 00:00:00 1970 PST
+ 810 | 0 | 00810 | Sun Jan 11 00:00:00 1970 PST
+ 811 | 1 | 00811 | Mon Jan 12 00:00:00 1970 PST
+ 813 | 303 | 00813_update3 | Wed Jan 14 00:00:00 1970 PST
+ 814 | 4 | 00814 | Thu Jan 15 00:00:00 1970 PST
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST
+ 818 | 8 | 00818 | Mon Jan 19 00:00:00 1970 PST
+ 819 | 509 | 00819_update9 | Tue Jan 20 00:00:00 1970 PST
+ 820 | 0 | 00820 | Wed Jan 21 00:00:00 1970 PST
+ 821 | 1 | 00821 | Thu Jan 22 00:00:00 1970 PST
+ 823 | 303 | 00823_update3 | Sat Jan 24 00:00:00 1970 PST
+ 824 | 4 | 00824 | Sun Jan 25 00:00:00 1970 PST
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST
+ 828 | 8 | 00828 | Thu Jan 29 00:00:00 1970 PST
+ 829 | 509 | 00829_update9 | Fri Jan 30 00:00:00 1970 PST
+ 830 | 0 | 00830 | Sat Jan 31 00:00:00 1970 PST
+ 831 | 1 | 00831 | Sun Feb 01 00:00:00 1970 PST
+ 833 | 303 | 00833_update3 | Tue Feb 03 00:00:00 1970 PST
+ 834 | 4 | 00834 | Wed Feb 04 00:00:00 1970 PST
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST
+ 838 | 8 | 00838 | Sun Feb 08 00:00:00 1970 PST
+ 839 | 509 | 00839_update9 | Mon Feb 09 00:00:00 1970 PST
+ 840 | 0 | 00840 | Tue Feb 10 00:00:00 1970 PST
+ 841 | 1 | 00841 | Wed Feb 11 00:00:00 1970 PST
+ 843 | 303 | 00843_update3 | Fri Feb 13 00:00:00 1970 PST
+ 844 | 4 | 00844 | Sat Feb 14 00:00:00 1970 PST
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST
+ 848 | 8 | 00848 | Wed Feb 18 00:00:00 1970 PST
+ 849 | 509 | 00849_update9 | Thu Feb 19 00:00:00 1970 PST
+ 850 | 0 | 00850 | Fri Feb 20 00:00:00 1970 PST
+ 851 | 1 | 00851 | Sat Feb 21 00:00:00 1970 PST
+ 853 | 303 | 00853_update3 | Mon Feb 23 00:00:00 1970 PST
+ 854 | 4 | 00854 | Tue Feb 24 00:00:00 1970 PST
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST
+ 858 | 8 | 00858 | Sat Feb 28 00:00:00 1970 PST
+ 859 | 509 | 00859_update9 | Sun Mar 01 00:00:00 1970 PST
+ 860 | 0 | 00860 | Mon Mar 02 00:00:00 1970 PST
+ 861 | 1 | 00861 | Tue Mar 03 00:00:00 1970 PST
+ 863 | 303 | 00863_update3 | Thu Mar 05 00:00:00 1970 PST
+ 864 | 4 | 00864 | Fri Mar 06 00:00:00 1970 PST
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST
+ 868 | 8 | 00868 | Tue Mar 10 00:00:00 1970 PST
+ 869 | 509 | 00869_update9 | Wed Mar 11 00:00:00 1970 PST
+ 870 | 0 | 00870 | Thu Mar 12 00:00:00 1970 PST
+ 871 | 1 | 00871 | Fri Mar 13 00:00:00 1970 PST
+ 873 | 303 | 00873_update3 | Sun Mar 15 00:00:00 1970 PST
+ 874 | 4 | 00874 | Mon Mar 16 00:00:00 1970 PST
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST
+ 878 | 8 | 00878 | Fri Mar 20 00:00:00 1970 PST
+ 879 | 509 | 00879_update9 | Sat Mar 21 00:00:00 1970 PST
+ 880 | 0 | 00880 | Sun Mar 22 00:00:00 1970 PST
+ 881 | 1 | 00881 | Mon Mar 23 00:00:00 1970 PST
+ 883 | 303 | 00883_update3 | Wed Mar 25 00:00:00 1970 PST
+ 884 | 4 | 00884 | Thu Mar 26 00:00:00 1970 PST
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST
+ 888 | 8 | 00888 | Mon Mar 30 00:00:00 1970 PST
+ 889 | 509 | 00889_update9 | Tue Mar 31 00:00:00 1970 PST
+ 890 | 0 | 00890 | Wed Apr 01 00:00:00 1970 PST
+ 891 | 1 | 00891 | Thu Apr 02 00:00:00 1970 PST
+ 893 | 303 | 00893_update3 | Sat Apr 04 00:00:00 1970 PST
+ 894 | 4 | 00894 | Sun Apr 05 00:00:00 1970 PST
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST
+ 898 | 8 | 00898 | Thu Apr 09 00:00:00 1970 PST
+ 899 | 509 | 00899_update9 | Fri Apr 10 00:00:00 1970 PST
+ 900 | 0 | 00900 | Thu Jan 01 00:00:00 1970 PST
+ 901 | 1 | 00901 | Fri Jan 02 00:00:00 1970 PST
+ 903 | 303 | 00903_update3 | Sun Jan 04 00:00:00 1970 PST
+ 904 | 4 | 00904 | Mon Jan 05 00:00:00 1970 PST
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST
+ 908 | 8 | 00908 | Fri Jan 09 00:00:00 1970 PST
+ 909 | 509 | 00909_update9 | Sat Jan 10 00:00:00 1970 PST
+ 910 | 0 | 00910 | Sun Jan 11 00:00:00 1970 PST
+ 911 | 1 | 00911 | Mon Jan 12 00:00:00 1970 PST
+ 913 | 303 | 00913_update3 | Wed Jan 14 00:00:00 1970 PST
+ 914 | 4 | 00914 | Thu Jan 15 00:00:00 1970 PST
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST
+ 918 | 8 | 00918 | Mon Jan 19 00:00:00 1970 PST
+ 919 | 509 | 00919_update9 | Tue Jan 20 00:00:00 1970 PST
+ 920 | 0 | 00920 | Wed Jan 21 00:00:00 1970 PST
+ 921 | 1 | 00921 | Thu Jan 22 00:00:00 1970 PST
+ 923 | 303 | 00923_update3 | Sat Jan 24 00:00:00 1970 PST
+ 924 | 4 | 00924 | Sun Jan 25 00:00:00 1970 PST
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST
+ 928 | 8 | 00928 | Thu Jan 29 00:00:00 1970 PST
+ 929 | 509 | 00929_update9 | Fri Jan 30 00:00:00 1970 PST
+ 930 | 0 | 00930 | Sat Jan 31 00:00:00 1970 PST
+ 931 | 1 | 00931 | Sun Feb 01 00:00:00 1970 PST
+ 933 | 303 | 00933_update3 | Tue Feb 03 00:00:00 1970 PST
+ 934 | 4 | 00934 | Wed Feb 04 00:00:00 1970 PST
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST
+ 938 | 8 | 00938 | Sun Feb 08 00:00:00 1970 PST
+ 939 | 509 | 00939_update9 | Mon Feb 09 00:00:00 1970 PST
+ 940 | 0 | 00940 | Tue Feb 10 00:00:00 1970 PST
+ 941 | 1 | 00941 | Wed Feb 11 00:00:00 1970 PST
+ 943 | 303 | 00943_update3 | Fri Feb 13 00:00:00 1970 PST
+ 944 | 4 | 00944 | Sat Feb 14 00:00:00 1970 PST
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST
+ 948 | 8 | 00948 | Wed Feb 18 00:00:00 1970 PST
+ 949 | 509 | 00949_update9 | Thu Feb 19 00:00:00 1970 PST
+ 950 | 0 | 00950 | Fri Feb 20 00:00:00 1970 PST
+ 951 | 1 | 00951 | Sat Feb 21 00:00:00 1970 PST
+ 953 | 303 | 00953_update3 | Mon Feb 23 00:00:00 1970 PST
+ 954 | 4 | 00954 | Tue Feb 24 00:00:00 1970 PST
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST
+ 958 | 8 | 00958 | Sat Feb 28 00:00:00 1970 PST
+ 959 | 509 | 00959_update9 | Sun Mar 01 00:00:00 1970 PST
+ 960 | 0 | 00960 | Mon Mar 02 00:00:00 1970 PST
+ 961 | 1 | 00961 | Tue Mar 03 00:00:00 1970 PST
+ 963 | 303 | 00963_update3 | Thu Mar 05 00:00:00 1970 PST
+ 964 | 4 | 00964 | Fri Mar 06 00:00:00 1970 PST
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST
+ 968 | 8 | 00968 | Tue Mar 10 00:00:00 1970 PST
+ 969 | 509 | 00969_update9 | Wed Mar 11 00:00:00 1970 PST
+ 970 | 0 | 00970 | Thu Mar 12 00:00:00 1970 PST
+ 971 | 1 | 00971 | Fri Mar 13 00:00:00 1970 PST
+ 973 | 303 | 00973_update3 | Sun Mar 15 00:00:00 1970 PST
+ 974 | 4 | 00974 | Mon Mar 16 00:00:00 1970 PST
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST
+ 978 | 8 | 00978 | Fri Mar 20 00:00:00 1970 PST
+ 979 | 509 | 00979_update9 | Sat Mar 21 00:00:00 1970 PST
+ 980 | 0 | 00980 | Sun Mar 22 00:00:00 1970 PST
+ 981 | 1 | 00981 | Mon Mar 23 00:00:00 1970 PST
+ 983 | 303 | 00983_update3 | Wed Mar 25 00:00:00 1970 PST
+ 984 | 4 | 00984 | Thu Mar 26 00:00:00 1970 PST
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST
+ 988 | 8 | 00988 | Mon Mar 30 00:00:00 1970 PST
+ 989 | 509 | 00989_update9 | Tue Mar 31 00:00:00 1970 PST
+ 990 | 0 | 00990 | Wed Apr 01 00:00:00 1970 PST
+ 991 | 1 | 00991 | Thu Apr 02 00:00:00 1970 PST
+ 993 | 303 | 00993_update3 | Sat Apr 04 00:00:00 1970 PST
+ 994 | 4 | 00994 | Sun Apr 05 00:00:00 1970 PST
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST
+ 998 | 8 | 00998 | Thu Apr 09 00:00:00 1970 PST
+ 999 | 509 | 00999_update9 | Fri Apr 10 00:00:00 1970 PST
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST
+ 1001 | 101 | 0000100001 |
+ 1003 | 403 | 0000300003_update3 |
+ 1004 | 104 | 0000400004 |
+ 1006 | 106 | 0000600006 |
+ 1007 | 507 | 0000700007_update7 |
+ 1008 | 108 | 0000800008 |
+ 1009 | 609 | 0000900009_update9 |
+ 1010 | 100 | 0001000010 |
+ 1011 | 101 | 0001100011 |
+ 1013 | 403 | 0001300013_update3 |
+ 1014 | 104 | 0001400014 |
+ 1016 | 106 | 0001600016 |
+ 1017 | 507 | 0001700017_update7 |
+ 1018 | 108 | 0001800018 |
+ 1019 | 609 | 0001900019_update9 |
+ 1020 | 100 | 0002000020 |
+ 1101 | 201 | aaa |
+ 1103 | 503 | ccc_update3 |
+ 1104 | 204 | ddd |
+(819 rows)
+
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Output: (ft2.tableoid)::regclass
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: 1200, 999, NULL::integer, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+(6 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = 'bar'::text WHERE (("C 1" = 1200))
+(4 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------
+ Delete on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE (("C 1" = 1200))
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+-- Test UPDATE/DELETE with RETURNING on a three-table join
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id - 1200, to_char(id, 'FM00000') FROM generate_series(1201, 1300) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.*, ft4.c1, ft4.c2, ft4.c3
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c3 = 'foo'::text FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (TRUE)) WHERE ((r2.c1 = r3.c1)) AND ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) RETURNING r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3
+(4 rows)
+
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*;
+ ft2 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | ft4 | c1 | c2 | c3
+--------------------------------+------+----+-----+----+----+----+------------+----+----------------+----+----+--------
+ (1206,6,foo,,,,"ft2 ",) | 1206 | 6 | foo | | | | ft2 | | (6,7,AAA006) | 6 | 7 | AAA006
+ (1212,12,foo,,,,"ft2 ",) | 1212 | 12 | foo | | | | ft2 | | (12,13,AAA012) | 12 | 13 | AAA012
+ (1218,18,foo,,,,"ft2 ",) | 1218 | 18 | foo | | | | ft2 | | (18,19,AAA018) | 18 | 19 | AAA018
+ (1224,24,foo,,,,"ft2 ",) | 1224 | 24 | foo | | | | ft2 | | (24,25,AAA024) | 24 | 25 | AAA024
+ (1230,30,foo,,,,"ft2 ",) | 1230 | 30 | foo | | | | ft2 | | (30,31,AAA030) | 30 | 31 | AAA030
+ (1236,36,foo,,,,"ft2 ",) | 1236 | 36 | foo | | | | ft2 | | (36,37,AAA036) | 36 | 37 | AAA036
+ (1242,42,foo,,,,"ft2 ",) | 1242 | 42 | foo | | | | ft2 | | (42,43,AAA042) | 42 | 43 | AAA042
+ (1248,48,foo,,,,"ft2 ",) | 1248 | 48 | foo | | | | ft2 | | (48,49,AAA048) | 48 | 49 | AAA048
+ (1254,54,foo,,,,"ft2 ",) | 1254 | 54 | foo | | | | ft2 | | (54,55,AAA054) | 54 | 55 | AAA054
+ (1260,60,foo,,,,"ft2 ",) | 1260 | 60 | foo | | | | ft2 | | (60,61,AAA060) | 60 | 61 | AAA060
+ (1266,66,foo,,,,"ft2 ",) | 1266 | 66 | foo | | | | ft2 | | (66,67,AAA066) | 66 | 67 | AAA066
+ (1272,72,foo,,,,"ft2 ",) | 1272 | 72 | foo | | | | ft2 | | (72,73,AAA072) | 72 | 73 | AAA072
+ (1278,78,foo,,,,"ft2 ",) | 1278 | 78 | foo | | | | ft2 | | (78,79,AAA078) | 78 | 79 | AAA078
+ (1284,84,foo,,,,"ft2 ",) | 1284 | 84 | foo | | | | ft2 | | (84,85,AAA084) | 84 | 85 | AAA084
+ (1290,90,foo,,,,"ft2 ",) | 1290 | 90 | foo | | | | ft2 | | (90,91,AAA090) | 90 | 91 | AAA090
+ (1296,96,foo,,,,"ft2 ",) | 1296 | 96 | foo | | | | ft2 | | (96,97,AAA096) | 96 | 97 | AAA096
+(16 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: 100
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1)))) WHERE ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) AND (((r1."C 1" % 10) = 0))
+(4 rows)
+
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100;
+ ?column?
+----------
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+(10 rows)
+
+DELETE FROM ft2 WHERE ft2.c1 > 1200;
+-- Test UPDATE with a MULTIEXPR sub-select
+-- (maybe someday this'll be remotely executable, but not today)
+EXPLAIN (verbose, costs off)
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 target
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2, c7 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.ft2 target
+ Output: $1, $2, (SubPlan 1 (returns $1,$2)), target.ctid, target.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1100)) FOR UPDATE
+ SubPlan 1 (returns $1,$2)
+ -> Foreign Scan on public.ft2 src
+ Output: (src.c2 * 10), src.c7
+ Remote SQL: SELECT c2, c7 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(9 rows)
+
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+UPDATE ft2 AS target SET (c2) = (
+ SELECT c2 / 10
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+-- Test UPDATE involving a join that can be pushed down,
+-- but a SET clause that can't be
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 d
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2 WHERE ctid = $1
+ -> Foreign Scan
+ Output: CASE WHEN (random() >= '0'::double precision) THEN d.c2 ELSE 0 END, d.ctid, d.*, t.*
+ Relations: (public.ft2 d) INNER JOIN (public.ft2 t)
+ Remote SQL: SELECT r1.c2, r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r1."C 1" > 1000)))) FOR UPDATE OF r1
+ -> Hash Join
+ Output: d.c2, d.ctid, d.*, t.*
+ Hash Cond: (d.c1 = t.c1)
+ -> Foreign Scan on public.ft2 d
+ Output: d.c2, d.ctid, d.*, d.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1000)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Hash
+ Output: t.*, t.c1
+ -> Foreign Scan on public.ft2 t
+ Output: t.*, t.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(17 rows)
+
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+-- Test UPDATE/DELETE with WHERE or JOIN/ON conditions containing
+-- user-defined operators/functions
+ALTER SERVER loopback OPTIONS (DROP extensions);
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id % 10, to_char(id, 'FM00000') FROM generate_series(2001, 2010) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft2
+ Output: 'bar'::text, ctid, ft2.*
+ Filter: (postgres_fdw_abs(ft2.c1) > 2000)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" FOR UPDATE
+(7 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-----+----+----+----+------------+----
+ 2001 | 1 | bar | | | | ft2 |
+ 2002 | 2 | bar | | | | ft2 |
+ 2003 | 3 | bar | | | | ft2 |
+ 2004 | 4 | bar | | | | ft2 |
+ 2005 | 5 | bar | | | | ft2 |
+ 2006 | 6 | bar | | | | ft2 |
+ 2007 | 7 | bar | | | | ft2 |
+ 2008 | 8 | bar | | | | ft2 |
+ 2009 | 9 | bar | | | | ft2 |
+ 2010 | 0 | bar | | | | ft2 |
+(10 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Nested Loop
+ Output: 'baz'::text, ft2.ctid, ft2.*, ft4.*, ft5.*, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Join Filter: (ft2.c2 === ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.*, ft2.c2
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Relations: (public.ft4) INNER JOIN (public.ft5)
+ Remote SQL: SELECT CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r3.c1, r3.c2, r3.c3 FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1))))
+ -> Hash Join
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(24 rows)
+
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3
+------+----+-----+----+----+----+------------+----+----+----+--------+----+----+--------
+ 2006 | 6 | baz | | | | ft2 | | 6 | 7 | AAA006 | 6 | 7 | AAA006
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ctid = $1 RETURNING "C 1", c2, c3
+ -> Foreign Scan
+ Output: ft2.ctid, ft4.*, ft5.*
+ Filter: (ft4.c1 === ft5.c1)
+ Relations: ((public.ft2) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r2.c1, r3.c1 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c2 = r2.c1)) AND ((r1."C 1" > 2000)))) INNER JOIN "S 1"."T 4" r3 ON (TRUE)) FOR UPDATE OF r1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft5.*, ft4.c1, ft5.c1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft4.c1
+ Join Filter: (ft2.c2 = ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.c2
+ Remote SQL: SELECT c2, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(22 rows)
+
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3;
+ c1 | c2 | c3
+------+----+-----
+ 2006 | 6 | baz
+(1 row)
+
+DELETE FROM ft2 WHERE ft2.c1 > 2000;
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- Test that trigger on remote table works as expected
+CREATE OR REPLACE FUNCTION "S 1".F_BRTRIG() RETURNS trigger AS $$
+BEGIN
+ NEW.c3 = NEW.c3 || '_trig_update';
+ RETURN NEW;
+END;
+$$ LANGUAGE plpgsql;
+CREATE TRIGGER t1_br_insert BEFORE INSERT OR UPDATE
+ ON "S 1"."T 1" FOR EACH ROW EXECUTE PROCEDURE "S 1".F_BRTRIG();
+INSERT INTO ft2 (c1,c2,c3) VALUES (1208, 818, 'fff') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+----+------------+----
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+(1 row)
+
+INSERT INTO ft2 (c1,c2,c3,c6) VALUES (1218, 818, 'ggg', '(--;') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+------+------------+----
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+(1 row)
+
+UPDATE ft2 SET c2 = c2 + 600 WHERE c1 % 10 = 8 AND c1 < 1200 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+------------------------+------------------------------+--------------------------+----+------------+-----
+ 8 | 608 | 00008_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 18 | 608 | 00018_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 28 | 608 | 00028_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 38 | 608 | 00038_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 48 | 608 | 00048_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 58 | 608 | 00058_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 68 | 608 | 00068_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 78 | 608 | 00078_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 88 | 608 | 00088_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 98 | 608 | 00098_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 108 | 608 | 00108_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 118 | 608 | 00118_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 128 | 608 | 00128_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 138 | 608 | 00138_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 148 | 608 | 00148_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 158 | 608 | 00158_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 168 | 608 | 00168_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 178 | 608 | 00178_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 188 | 608 | 00188_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 198 | 608 | 00198_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 208 | 608 | 00208_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 218 | 608 | 00218_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 228 | 608 | 00228_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 238 | 608 | 00238_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 248 | 608 | 00248_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 258 | 608 | 00258_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 268 | 608 | 00268_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 278 | 608 | 00278_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 288 | 608 | 00288_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 298 | 608 | 00298_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 308 | 608 | 00308_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 318 | 608 | 00318_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 328 | 608 | 00328_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 338 | 608 | 00338_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 348 | 608 | 00348_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 358 | 608 | 00358_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 368 | 608 | 00368_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 378 | 608 | 00378_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 388 | 608 | 00388_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 398 | 608 | 00398_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 408 | 608 | 00408_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 418 | 608 | 00418_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 428 | 608 | 00428_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 438 | 608 | 00438_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 448 | 608 | 00448_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 458 | 608 | 00458_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 468 | 608 | 00468_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 478 | 608 | 00478_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 488 | 608 | 00488_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 498 | 608 | 00498_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 508 | 608 | 00508_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 518 | 608 | 00518_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 528 | 608 | 00528_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 538 | 608 | 00538_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 548 | 608 | 00548_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 558 | 608 | 00558_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 568 | 608 | 00568_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 578 | 608 | 00578_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 588 | 608 | 00588_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 598 | 608 | 00598_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 608 | 608 | 00608_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 618 | 608 | 00618_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 628 | 608 | 00628_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 638 | 608 | 00638_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 648 | 608 | 00648_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 658 | 608 | 00658_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 668 | 608 | 00668_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 678 | 608 | 00678_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 688 | 608 | 00688_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 698 | 608 | 00698_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 708 | 608 | 00708_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 718 | 608 | 00718_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 728 | 608 | 00728_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 738 | 608 | 00738_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 748 | 608 | 00748_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 758 | 608 | 00758_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 768 | 608 | 00768_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 778 | 608 | 00778_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 788 | 608 | 00788_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 798 | 608 | 00798_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 808 | 608 | 00808_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 818 | 608 | 00818_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 828 | 608 | 00828_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 838 | 608 | 00838_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 848 | 608 | 00848_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 858 | 608 | 00858_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 868 | 608 | 00868_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 878 | 608 | 00878_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 888 | 608 | 00888_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 898 | 608 | 00898_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 908 | 608 | 00908_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 918 | 608 | 00918_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 928 | 608 | 00928_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 938 | 608 | 00938_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 948 | 608 | 00948_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 958 | 608 | 00958_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 968 | 608 | 00968_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 978 | 608 | 00978_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 988 | 608 | 00988_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 998 | 608 | 00998_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 1008 | 708 | 0000800008_trig_update | | | | ft2 |
+ 1018 | 708 | 0001800018_trig_update | | | | ft2 |
+(102 rows)
+
+-- Test errors thrown on remote side during update
+ALTER TABLE "S 1"."T 1" ADD CONSTRAINT c2positive CHECK (c2 >= 0);
+INSERT INTO ft1(c1, c2) VALUES(11, 12); -- duplicate key
+ERROR: duplicate key value violates unique constraint "t1_pkey"
+DETAIL: Key ("C 1")=(11) already exists.
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT DO NOTHING; -- works
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO NOTHING; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO UPDATE SET c3 = 'ffg'; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+-- Test savepoint/rollback behavior
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+begin;
+update ft2 set c2 = 42 where c2 = 0;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 42 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s1;
+update ft2 set c2 = 44 where c2 = 4;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s1;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s2;
+update ft2 set c2 = 46 where c2 = 6;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 42 | 100
+ 44 | 100
+ 46 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+rollback to savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s3;
+update ft2 set c2 = -2 where c2 = 42 and c1 = 10; -- fail on remote side
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (10, -2, 00010_trig_update_trig_update, 1970-01-11 08:00:00+00, 1970-01-11 00:00:00, 0, 0 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (-2) WHERE ((c2 = 42)) AND (("C 1" = 10))
+rollback to savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+-- none of the above is committed yet remotely
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+commit;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+VACUUM ANALYZE "S 1"."T 1";
+-- Above DMLs add data with c6 as NULL in ft1, so test ORDER BY NULLS LAST and NULLs
+-- FIRST behavior here.
+-- ORDER BY DESC NULLS LAST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 795::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+------+------------+-----
+ 960 | 42 | 00960_trig_update | Mon Mar 02 00:00:00 1970 PST | Mon Mar 02 00:00:00 1970 | 0 | 0 | foo
+ 970 | 42 | 00970_trig_update | Thu Mar 12 00:00:00 1970 PST | Thu Mar 12 00:00:00 1970 | 0 | 0 | foo
+ 980 | 42 | 00980_trig_update | Sun Mar 22 00:00:00 1970 PST | Sun Mar 22 00:00:00 1970 | 0 | 0 | foo
+ 990 | 42 | 00990_trig_update | Wed Apr 01 00:00:00 1970 PST | Wed Apr 01 00:00:00 1970 | 0 | 0 | foo
+ 1000 | 42 | 01000_trig_update | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 1001 | 101 | 0000100001 | | | | ft2 |
+ 1003 | 403 | 0000300003_update3 | | | | ft2 |
+ 1004 | 104 | 0000400004 | | | | ft2 |
+ 1006 | 106 | 0000600006 | | | | ft2 |
+(10 rows)
+
+-- ORDER BY DESC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+------------------------------+--------------------------+----+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | ft2 | foo
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST | Tue Jan 20 00:00:00 1970 | 9 | ft2 | foo
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST | Fri Jan 30 00:00:00 1970 | 9 | ft2 | foo
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST | Mon Feb 09 00:00:00 1970 | 9 | ft2 | foo
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST | Thu Feb 19 00:00:00 1970 | 9 | ft2 | foo
+(10 rows)
+
+-- ORDER BY ASC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 ASC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-------------------+------------------------------+--------------------------+------+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 10 | 42 | 00010_trig_update | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+ 20 | 42 | 00020_trig_update | Wed Jan 21 00:00:00 1970 PST | Wed Jan 21 00:00:00 1970 | 0 | 0 | foo
+ 30 | 42 | 00030_trig_update | Sat Jan 31 00:00:00 1970 PST | Sat Jan 31 00:00:00 1970 | 0 | 0 | foo
+ 40 | 42 | 00040_trig_update | Tue Feb 10 00:00:00 1970 PST | Tue Feb 10 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- ===================================================================
+-- test check constraints
+-- ===================================================================
+-- Consistent check constraints provide consistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- check constraint is enforced on the remote side, not locally
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
+-- But inconsistent check constraints provide inconsistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 821
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- local check constraint is not actually enforced
+INSERT INTO ft1(c1, c2) VALUES(1111, 2);
+UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
+-- ===================================================================
+-- test WITH CHECK OPTION constraints
+-- ===================================================================
+CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
+CREATE TABLE base_tbl (a int, b int);
+ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE VIEW rw_view AS SELECT * FROM foreign_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT foreign_tbl.a,
+ foreign_tbl.b
+ FROM foreign_tbl
+ WHERE foreign_tbl.a < foreign_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 5
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 15
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 5), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 15), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP TRIGGER row_before_insupd_trigger ON base_tbl;
+DROP TABLE base_tbl;
+-- test WCO for partitions
+CREATE TABLE child_tbl (a int, b int);
+ALTER TABLE child_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON child_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'child_tbl');
+CREATE TABLE parent_tbl (a int, b int) PARTITION BY RANGE(a);
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+-- Detach and re-attach once, to stress the concurrent detach case.
+ALTER TABLE parent_tbl DETACH PARTITION foreign_tbl CONCURRENTLY;
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+CREATE VIEW rw_view AS SELECT * FROM parent_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT parent_tbl.a,
+ parent_tbl.b
+ FROM parent_tbl
+ WHERE parent_tbl.a < parent_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 5
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 15
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 5), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 15), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------
+ Insert on public.parent_tbl
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+DROP TRIGGER row_before_insupd_trigger ON child_tbl;
+DROP TABLE parent_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP FUNCTION row_before_insupd_trigfunc;
+-- ===================================================================
+-- test serial columns (ie, sequence-based defaults)
+-- ===================================================================
+create table loc1 (f1 serial, f2 text);
+alter table loc1 set (autovacuum_enabled = 'false');
+create foreign table rem1 (f1 serial, f2 text)
+ server loopback options(table_name 'loc1');
+select pg_catalog.setval('rem1_f1_seq', 10, false);
+ setval
+--------
+ 10
+(1 row)
+
+insert into loc1(f2) values('hi');
+insert into rem1(f2) values('hi remote');
+insert into loc1(f2) values('bye');
+insert into rem1(f2) values('bye remote');
+select * from loc1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+select * from rem1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+-- ===================================================================
+-- test generated columns
+-- ===================================================================
+create table gloc1 (
+ a int,
+ b int generated always as (a * 2) stored);
+alter table gloc1 set (autovacuum_enabled = 'false');
+create foreign table grem1 (
+ a int,
+ b int generated always as (a * 2) stored)
+ server loopback options(table_name 'gloc1');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+explain (verbose, costs off)
+update grem1 set a = 22 where a = 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.grem1
+ Remote SQL: UPDATE public.gloc1 SET a = $2, b = DEFAULT WHERE ctid = $1
+ -> Foreign Scan on public.grem1
+ Output: 22, ctid, grem1.*
+ Remote SQL: SELECT a, b, ctid FROM public.gloc1 WHERE ((a = 2)) FOR UPDATE
+(5 rows)
+
+update grem1 set a = 22 where a = 2;
+select * from gloc1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+select * from grem1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+delete from grem1;
+-- test copy from
+copy grem1 from stdin;
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+-- test batch insert
+alter server loopback options (add batch_size '10');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 10
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test local triggers
+-- ===================================================================
+-- Trigger functions "borrowed" from triggers regress test.
+CREATE FUNCTION trigger_func() RETURNS trigger LANGUAGE plpgsql AS $$
+BEGIN
+ RAISE NOTICE 'trigger_func(%) called: action = %, when = %, level = %',
+ TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN NULL;
+END;$$;
+CREATE TRIGGER trig_stmt_before BEFORE DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE TRIGGER trig_stmt_after AFTER DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE OR REPLACE FUNCTION trigger_data() RETURNS trigger
+LANGUAGE plpgsql AS $$
+
+declare
+ oldnew text[];
+ relid text;
+ argstr text;
+begin
+
+ relid := TG_relid::regclass;
+ argstr := '';
+ for i in 0 .. TG_nargs - 1 loop
+ if i > 0 then
+ argstr := argstr || ', ';
+ end if;
+ argstr := argstr || TG_argv[i];
+ end loop;
+
+ RAISE NOTICE '%(%) % % % ON %',
+ tg_name, argstr, TG_when, TG_level, TG_OP, relid;
+ oldnew := '{}'::text[];
+ if TG_OP != 'INSERT' then
+ oldnew := array_append(oldnew, format('OLD: %s', OLD));
+ end if;
+
+ if TG_OP != 'DELETE' then
+ oldnew := array_append(oldnew, format('NEW: %s', NEW));
+ end if;
+
+ RAISE NOTICE '%', array_to_string(oldnew, ',');
+
+ if TG_OP = 'DELETE' then
+ return OLD;
+ else
+ return NEW;
+ end if;
+end;
+$$;
+-- Test basic functionality
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+delete from rem1;
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = AFTER, level = STATEMENT
+insert into rem1 values(1,'insert');
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+update rem1 set f2 = f2 || f2;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+truncate rem1;
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = BEFORE, level = STATEMENT
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = AFTER, level = STATEMENT
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_stmt_before ON rem1;
+DROP TRIGGER trig_stmt_after ON rem1;
+DELETE from rem1;
+-- Test multiple AFTER ROW triggers on a foreign table
+CREATE TRIGGER trig_row_after1
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after2
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+insert into rem1 values(1,'insert');
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+update rem1 set f2 = f2 || f2;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+delete from rem1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+-- cleanup
+DROP TRIGGER trig_row_after1 ON rem1;
+DROP TRIGGER trig_row_after2 ON rem1;
+-- Test WHEN conditions
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_insupd
+AFTER INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Insert or update not matching: nothing happens
+INSERT INTO rem1 values(1, 'insert');
+UPDATE rem1 set f2 = 'test';
+-- Insert or update matching: triggers are fired
+INSERT INTO rem1 values(2, 'update');
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+UPDATE rem1 set f2 = 'update update' where f1 = '2';
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Trigger is fired for f1=2, not for f1=1
+DELETE FROM rem1;
+NOTICE: trig_row_before_delete(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+NOTICE: trig_row_after_delete(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+-- cleanup
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_after_insupd ON rem1;
+DROP TRIGGER trig_row_before_delete ON rem1;
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- Test various RETURN statements in BEFORE triggers.
+CREATE FUNCTION trig_row_before_insupdate() RETURNS TRIGGER AS $$
+ BEGIN
+ NEW.f2 := NEW.f2 || ' triggered !';
+ RETURN NEW;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+-- The new values should have 'triggered' appended
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------
+ insert triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+ 2 | insert triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------
+ 1 | triggered !
+ 2 | triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------
+ skidoo triggered !
+ skidoo triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | skidoo triggered !
+ 2 | skidoo triggered !
+(2 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f1 = 10; -- all columns should be transmitted
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: 10, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+UPDATE rem1 set f1 = 10;
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 10 | skidoo triggered ! triggered !
+ 10 | skidoo triggered ! triggered !
+(2 rows)
+
+DELETE FROM rem1;
+-- Add a second trigger, to check that the changes are propagated correctly
+-- from trigger to trigger
+CREATE TRIGGER trig_row_before_insupd2
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------------------
+ insert triggered ! triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+ 2 | insert triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------
+ 1 | triggered ! triggered !
+ 2 | triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------------------
+ skidoo triggered ! triggered !
+ skidoo triggered ! triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | skidoo triggered ! triggered !
+ 2 | skidoo triggered ! triggered !
+(2 rows)
+
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_before_insupd2 ON rem1;
+DELETE from rem1;
+INSERT INTO rem1 VALUES (1, 'test');
+-- Test with a trigger returning NULL
+CREATE FUNCTION trig_null() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_null
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_null();
+-- Nothing should have changed.
+INSERT INTO rem1 VALUES (2, 'test2');
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+UPDATE rem1 SET f2 = 'test2';
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DELETE from rem1;
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DROP TRIGGER trig_null ON rem1;
+DELETE from rem1;
+-- Test a combination of local and remote triggers
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_local_before BEFORE INSERT OR UPDATE ON loc1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1(f2) VALUES ('test');
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (12,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (12,"test triggered !")
+UPDATE rem1 SET f2 = 'testo';
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,testo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,"testo triggered !")
+-- Test returning a system attribute
+INSERT INTO rem1(f2) VALUES ('test') RETURNING ctid;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (13,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (13,"test triggered !")
+ ctid
+--------
+ (0,25)
+(1 row)
+
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_local_before ON loc1;
+-- Test direct foreign table modification functionality
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1 WHERE false; -- currently can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Result
+ Output: ctid
+ One-Time Filter: false
+(5 rows)
+
+-- Test with statement-level triggers
+CREATE TRIGGER trig_stmt_before
+ BEFORE DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_before ON rem1;
+CREATE TRIGGER trig_stmt_after
+ AFTER DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_after ON rem1;
+-- Test with row-level ON INSERT triggers
+CREATE TRIGGER trig_row_before_insert
+BEFORE INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_insert ON rem1;
+CREATE TRIGGER trig_row_after_insert
+AFTER INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_insert ON rem1;
+-- Test with row-level ON UPDATE triggers
+CREATE TRIGGER trig_row_before_update
+BEFORE UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_update ON rem1;
+CREATE TRIGGER trig_row_after_update
+AFTER UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = $2 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_update ON rem1;
+-- Test with row-level ON DELETE triggers
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_before_delete ON rem1;
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- ===================================================================
+-- test inheritance features
+-- ===================================================================
+CREATE TABLE a (aa TEXT);
+CREATE TABLE loct (aa TEXT, bb TEXT);
+ALTER TABLE a SET (autovacuum_enabled = 'false');
+ALTER TABLE loct SET (autovacuum_enabled = 'false');
+CREATE FOREIGN TABLE b (bb TEXT) INHERITS (a)
+ SERVER loopback OPTIONS (table_name 'loct');
+INSERT INTO a(aa) VALUES('aaa');
+INSERT INTO a(aa) VALUES('aaaa');
+INSERT INTO a(aa) VALUES('aaaaa');
+INSERT INTO b(aa) VALUES('bbb');
+INSERT INTO b(aa) VALUES('bbbb');
+INSERT INTO b(aa) VALUES('bbbbb');
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+(3 rows)
+
+UPDATE a SET aa = 'zzzzzz' WHERE aa LIKE 'aaaa%';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE b SET aa = 'new';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | new
+ b | new
+ b | new
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-----+----
+ b | new |
+ b | new |
+ b | new |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE a SET aa = 'newtoo';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+ b | newtoo
+ b | newtoo
+ b | newtoo
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+--------+----
+ b | newtoo |
+ b | newtoo |
+ b | newtoo |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+(3 rows)
+
+DELETE FROM a;
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+----+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+DROP TABLE a CASCADE;
+NOTICE: drop cascades to foreign table b
+DROP TABLE loct;
+-- Check SELECT FOR UPDATE/SHARE with an inherited source table
+create table loct1 (f1 int, f2 int, f3 int);
+create table loct2 (f1 int, f2 int, f3 int);
+alter table loct1 set (autovacuum_enabled = 'false');
+alter table loct2 set (autovacuum_enabled = 'false');
+create table foo (f1 int, f2 int);
+create foreign table foo2 (f3 int) inherits (foo)
+ server loopback options (table_name 'loct1');
+create table bar (f1 int, f2 int);
+create foreign table bar2 (f3 int) inherits (bar)
+ server loopback options (table_name 'loct2');
+alter table foo set (autovacuum_enabled = 'false');
+alter table bar set (autovacuum_enabled = 'false');
+insert into foo values(1,1);
+insert into foo values(3,3);
+insert into foo2 values(2,2,2);
+insert into foo2 values(4,4,4);
+insert into bar values(1,11);
+insert into bar values(2,22);
+insert into bar values(6,66);
+insert into bar2 values(3,33,33);
+insert into bar2 values(4,44,44);
+insert into bar2 values(7,77,77);
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for update;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for update;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for share;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for share;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+-- Now check SELECT FOR UPDATE/SHARE with an inherited source table,
+-- where the parent is itself a foreign table
+create table loct4 (f1 int, f2 int, f3 int);
+create foreign table foo2child (f3 int) inherits (foo2)
+ server loopback options (table_name 'loct4');
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct1
+ -> Foreign Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct4
+(24 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop foreign table foo2child;
+-- And with a local child relation of the foreign table parent
+create table foo2child (f3 int) inherits (foo2);
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.ctid, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+ -> Seq Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.ctid, foo2_2.tableoid
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop table foo2child;
+-- Check UPDATE with inherited target and an inherited source table
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Hash Join
+ Output: (bar.f2 + 100), foo.ctid, bar.tableoid, bar.ctid, (NULL::record), foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(25 rows)
+
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 111
+ bar | 2 | 122
+ bar | 6 | 66
+ bar2 | 3 | 133
+ bar2 | 4 | 144
+ bar2 | 7 | 77
+(6 rows)
+
+-- Check UPDATE with inherited target and an appendrel subquery
+explain (verbose, costs off)
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Merge Join
+ Output: (bar.f2 + 100), (ROW(foo.f1)), bar.tableoid, bar.ctid, (NULL::record)
+ Merge Cond: (bar.f1 = foo.f1)
+ -> Sort
+ Output: bar.f2, bar.f1, bar.tableoid, bar.ctid, (NULL::record)
+ Sort Key: bar.f1
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Sort
+ Output: (ROW(foo.f1)), foo.f1
+ Sort Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: ROW(foo.f1), foo.f1
+ -> Foreign Scan on public.foo2 foo_1
+ Output: ROW(foo_1.f1), foo_1.f1
+ Remote SQL: SELECT f1 FROM public.loct1
+ -> Seq Scan on public.foo foo_2
+ Output: ROW((foo_2.f1 + 3)), (foo_2.f1 + 3)
+ -> Foreign Scan on public.foo2 foo_3
+ Output: ROW((foo_3.f1 + 3)), (foo_3.f1 + 3)
+ Remote SQL: SELECT f1 FROM public.loct1
+(30 rows)
+
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 211
+ bar | 2 | 222
+ bar | 6 | 166
+ bar2 | 3 | 233
+ bar2 | 4 | 244
+ bar2 | 7 | 177
+(6 rows)
+
+-- Test forcing the remote server to produce sorted data for a merge join,
+-- but the foreign table is an inheritance child.
+truncate table loct1;
+truncate table only foo;
+\set num_rows_foo 2000
+insert into loct1 select generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2);
+insert into foo select generate_series(1, :num_rows_foo, 2), generate_series(1, :num_rows_foo, 2);
+SET enable_hashjoin to false;
+SET enable_nestloop to false;
+alter foreign table foo2 options (use_remote_estimate 'true');
+create index i_loct1_f1 on loct1(f1);
+create index i_foo_f1 on foo(f1);
+analyze foo;
+analyze loct1;
+-- inner join; expressions in the clauses appear in the equivalence class list
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 20 | 20
+ 22 | 22
+ 24 | 24
+ 26 | 26
+ 28 | 28
+ 30 | 30
+ 32 | 32
+ 34 | 34
+ 36 | 36
+ 38 | 38
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Left Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 10 | 10
+ 11 |
+ 12 | 12
+ 13 |
+ 14 | 14
+ 15 |
+ 16 | 16
+ 17 |
+ 18 | 18
+ 19 |
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test that WHERE CURRENT OF is not supported
+begin;
+declare c cursor for select * from bar where f1 = 7;
+fetch from c;
+ f1 | f2
+----+-----
+ 7 | 177
+(1 row)
+
+update bar set f2 = null where current of c;
+ERROR: WHERE CURRENT OF is not supported for this table type
+rollback;
+explain (verbose, costs off)
+delete from foo where f1 < 5 returning *;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Delete on public.foo
+ Output: foo_1.f1, foo_1.f2
+ Delete on public.foo foo_1
+ Foreign Delete on public.foo2 foo_2
+ -> Append
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.tableoid, foo_1.ctid
+ Index Cond: (foo_1.f1 < 5)
+ -> Foreign Delete on public.foo2 foo_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ((f1 < 5)) RETURNING f1, f2
+(10 rows)
+
+delete from foo where f1 < 5 returning *;
+ f1 | f2
+----+----
+ 1 | 1
+ 3 | 3
+ 0 | 0
+ 2 | 2
+ 4 | 4
+(5 rows)
+
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Update on public.bar
+ Output: bar_1.f1, bar_1.f2
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = (f2 + 100) RETURNING f1, f2
+(11 rows)
+
+update bar set f2 = f2 + 100 returning *;
+ f1 | f2
+----+-----
+ 1 | 311
+ 2 | 322
+ 6 | 266
+ 3 | 333
+ 4 | 344
+ 7 | 277
+(6 rows)
+
+-- Test that UPDATE/DELETE with inherited target works with row-level triggers
+CREATE TRIGGER trig_row_before
+BEFORE UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+explain (verbose, costs off)
+update bar set f2 = f2 + 100;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f1 = $2, f2 = $3, f3 = $4 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+(12 rows)
+
+update bar set f2 = f2 + 100;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+explain (verbose, costs off)
+delete from bar where f2 < 400;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Delete on public.bar
+ Delete on public.bar bar_1
+ Foreign Delete on public.bar2 bar_2
+ Remote SQL: DELETE FROM public.loct2 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.tableoid, bar_1.ctid, NULL::record
+ Filter: (bar_1.f2 < 400)
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 WHERE ((f2 < 400)) FOR UPDATE
+(11 rows)
+
+delete from bar where f2 < 400;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+-- cleanup
+drop table foo cascade;
+NOTICE: drop cascades to foreign table foo2
+drop table bar cascade;
+NOTICE: drop cascades to foreign table bar2
+drop table loct1;
+drop table loct2;
+-- Test pushing down UPDATE/DELETE joins to the remote server
+create table parent (a int, b text);
+create table loct1 (a int, b text);
+create table loct2 (a int, b text);
+create foreign table remt1 (a int, b text)
+ server loopback options (table_name 'loct1');
+create foreign table remt2 (a int, b text)
+ server loopback options (table_name 'loct2');
+alter foreign table remt1 inherit parent;
+insert into remt1 values (1, 'foo');
+insert into remt1 values (2, 'bar');
+insert into remt2 values (1, 'foo');
+insert into remt2 values (2, 'bar');
+analyze remt1;
+analyze remt2;
+explain (verbose, costs off)
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.parent
+ Output: parent_1.a, parent_1.b, remt2.a, remt2.b
+ Update on public.parent parent_1
+ Foreign Update on public.remt1 parent_2
+ Remote SQL: UPDATE public.loct1 SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: (parent.b || remt2.b), remt2.*, remt2.a, remt2.b, parent.tableoid, parent.ctid, (NULL::record)
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.b, parent_1.a, parent_1.tableoid, parent_1.ctid, NULL::record
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.b, parent_2.a, parent_2.tableoid, parent_2.ctid, parent_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.b, remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.b, remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ a | b | a | b
+---+--------+---+-----
+ 1 | foofoo | 1 | foo
+ 2 | barbar | 2 | bar
+(2 rows)
+
+explain (verbose, costs off)
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Delete on public.parent
+ Output: parent_1.*
+ Delete on public.parent parent_1
+ Foreign Delete on public.remt1 parent_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: remt2.*, parent.tableoid, parent.ctid
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.a, parent_1.tableoid, parent_1.ctid
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.a, parent_2.tableoid, parent_2.ctid
+ Remote SQL: SELECT a, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ parent
+------------
+ (1,foofoo)
+ (2,barbar)
+(2 rows)
+
+-- cleanup
+drop foreign table remt1;
+drop foreign table remt2;
+drop table loct1;
+drop table loct2;
+drop table parent;
+-- ===================================================================
+-- test tuple routing for foreign-table partitions
+-- ===================================================================
+-- Test insert tuple routing
+create table itrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table itrtest attach partition remp1 for values in (1);
+alter table itrtest attach partition remp2 for values in (2);
+insert into itrtest values (1, 'foo');
+insert into itrtest values (1, 'bar') returning *;
+ a | b
+---+-----
+ 1 | bar
+(1 row)
+
+insert into itrtest values (2, 'baz');
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----
+ 2 | qux
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------
+ 1 | test1
+ 2 | test2
+(2 rows)
+
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from itrtest;
+-- MERGE ought to fail cleanly
+merge into itrtest using (select 1, 'foo') as source on (true)
+ when matched then do nothing;
+ERROR: cannot execute MERGE on relation "remp1"
+DETAIL: This operation is not supported for foreign tables.
+create unique index loct1_idx on loct1 (a);
+-- DO NOTHING without an inference specification is supported
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+-----
+ 1 | foo
+(1 row)
+
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+---
+(0 rows)
+
+-- But other cases are not supported
+insert into itrtest values (1, 'bar') on conflict (a) do nothing;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+insert into itrtest values (1, 'bar') on conflict (a) do update set b = excluded.b;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+delete from itrtest;
+drop index loct1_idx;
+-- Test that remote triggers work with insert tuple routing
+create function br_insert_trigfunc() returns trigger as $$
+begin
+ new.b := new.b || ' triggered !';
+ return new;
+end
+$$ language plpgsql;
+create trigger loct1_br_insert_trigger before insert on loct1
+ for each row execute procedure br_insert_trigfunc();
+create trigger loct2_br_insert_trigger before insert on loct2
+ for each row execute procedure br_insert_trigfunc();
+-- The new values are concatenated with ' triggered !'
+insert into itrtest values (1, 'foo') returning *;
+ a | b
+---+-----------------
+ 1 | foo triggered !
+(1 row)
+
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----------------
+ 2 | qux triggered !
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+with result as (insert into itrtest values (1, 'test1'), (2, 'test2') returning *) select * from result;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+drop trigger loct1_br_insert_trigger on loct1;
+drop trigger loct2_br_insert_trigger on loct2;
+drop table itrtest;
+drop table loct1;
+drop table loct2;
+-- Test update tuple routing
+create table utrtest (a int, b text) partition by list (a);
+create table loct (a int check (a in (1)), b text);
+create foreign table remp (a int check (a in (1)), b text) server loopback options (table_name 'loct');
+create table locp (a int check (a in (2)), b text);
+alter table utrtest attach partition remp for values in (1);
+alter table utrtest attach partition locp for values in (2);
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- It's not allowed to move a row from a partition that is foreign to another
+update utrtest set a = 2 where b = 'foo' returning *;
+ERROR: new row for relation "loct" violates check constraint "loct_a_check"
+DETAIL: Failing row contains (2, foo).
+CONTEXT: remote SQL command: UPDATE public.loct SET a = 2 WHERE ((b = 'foo')) RETURNING a, b
+-- But the reverse is allowed
+update utrtest set a = 1 where b = 'qux' returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- The executor should not let unexercised FDWs shut down
+update utrtest set a = 1 where b = 'foo';
+-- Test that remote triggers work with update tuple routing
+create trigger loct_br_insert_trigger before insert on loct
+ for each row execute procedure br_insert_trigfunc();
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition is a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 WHERE (((a = 1) OR (a = 2))) RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ Filter: ((utrtest_2.a = 1) OR (utrtest_2.a = 2))
+(10 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition isn't a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 2 returning *;
+ QUERY PLAN
+-------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ -> Seq Scan on public.locp utrtest_1
+ Output: 1, utrtest_1.tableoid, utrtest_1.ctid
+ Filter: (utrtest_1.a = 2)
+(6 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 2 returning *;
+ a | b
+---+-----------------
+ 1 | qux triggered !
+(1 row)
+
+drop trigger loct_br_insert_trigger on loct;
+-- We can move rows to a foreign partition that has been updated already,
+-- but can't move rows to a foreign partition that hasn't been updated yet
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- Test the former case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+(9 rows)
+
+update utrtest set a = 1 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ Update on public.locp utrtest_2
+ -> Hash Join
+ Output: 1, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, utrtest.*
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Foreign Scan on public.remp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, utrtest_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Seq Scan on public.locp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- Change the definition of utrtest so that the foreign partition get updated
+-- after the local partition
+delete from utrtest;
+alter table utrtest detach partition remp;
+drop foreign table remp;
+alter table loct drop constraint loct_a_check;
+alter table loct add check (a in (3));
+create foreign table remp (a int check (a in (3)), b text) server loopback options (table_name 'loct');
+alter table utrtest attach partition remp for values in (3);
+insert into utrtest values (2, 'qux');
+insert into utrtest values (3, 'xyzzy');
+-- Test the latter case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: 3, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = 3 RETURNING a, b
+(9 rows)
+
+update utrtest set a = 3 returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ -> Hash Join
+ Output: 3, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, (NULL::record)
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Scan on public.remp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, utrtest_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+drop table utrtest;
+drop table loct;
+-- Test copy tuple routing
+create table ctrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table ctrtest attach partition remp1 for values in (1);
+alter table ctrtest attach partition remp2 for values in (2);
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp2 | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-----+---
+ remp2 | qux | 2
+(1 row)
+
+-- Copying into foreign partitions directly should work as well
+copy remp1 from stdin;
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+(2 rows)
+
+delete from ctrtest;
+-- Test copy tuple routing with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from ctrtest;
+alter server loopback options (drop batch_size);
+drop table ctrtest;
+drop table loct1;
+drop table loct2;
+-- ===================================================================
+-- test COPY FROM
+-- ===================================================================
+create table loc2 (f1 int, f2 text);
+alter table loc2 set (autovacuum_enabled = 'false');
+create foreign table rem2 (f1 int, f2 text) server loopback options(table_name 'loc2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2, line 1: "-1 xyzzy"
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test local triggers
+create trigger trig_stmt_before before insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_stmt_after after insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+copy rem2 from stdin;
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop trigger trig_row_before on rem2;
+drop trigger trig_row_after on rem2;
+drop trigger trig_stmt_before on rem2;
+drop trigger trig_stmt_after on rem2;
+delete from rem2;
+create trigger trig_row_before_insert before insert on rem2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on rem2;
+delete from rem2;
+create trigger trig_null before insert on rem2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on rem2;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Test a combination of local and remote triggers
+create trigger rem2_trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger rem2_trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger loc2_trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+copy rem2 from stdin;
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,"foo triggered !")
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,"bar triggered !")
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger rem2_trig_row_before on rem2;
+drop trigger rem2_trig_row_after on rem2;
+drop trigger loc2_trig_row_before_insert on loc2;
+delete from rem2;
+-- test COPY FROM with foreign table created in the same transaction
+create table loc3 (f1 int, f2 text);
+begin;
+create foreign table rem3 (f1 int, f2 text)
+ server loopback options(table_name 'loc3');
+copy rem3 from stdin;
+commit;
+select * from rem3;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop foreign table rem3;
+drop table loc3;
+-- Test COPY FROM with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+ 3 | baz triggered !
+(3 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Check with zero-column foreign table; batch insert will be disabled
+alter table loc2 drop column f1;
+alter table loc2 drop column f2;
+alter table rem2 drop column f1;
+alter table rem2 drop column f2;
+copy rem2 from stdin;
+select * from rem2;
+--
+(3 rows)
+
+delete from rem2;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test for TRUNCATE
+-- ===================================================================
+CREATE TABLE tru_rtable0 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable0');
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(1,10) x);
+CREATE TABLE tru_ptable (id int) PARTITION BY HASH(id);
+CREATE TABLE tru_ptable__p0 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tru_rtable1 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable__p1 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback OPTIONS (table_name 'tru_rtable1');
+INSERT INTO tru_ptable (SELECT x FROM generate_series(11,20) x);
+CREATE TABLE tru_pk_table(id int primary key);
+CREATE TABLE tru_fk_table(fkey int references tru_pk_table(id));
+INSERT INTO tru_pk_table (SELECT x FROM generate_series(1,10) x);
+INSERT INTO tru_fk_table (SELECT x % 10 + 1 FROM generate_series(5,25) x);
+CREATE FOREIGN TABLE tru_pk_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_pk_table');
+CREATE TABLE tru_rtable_parent (id int);
+CREATE TABLE tru_rtable_child (id int);
+CREATE FOREIGN TABLE tru_ftable_parent (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_parent');
+CREATE FOREIGN TABLE tru_ftable_child () INHERITS (tru_ftable_parent)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_child');
+INSERT INTO tru_rtable_parent (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_rtable_child (SELECT x FROM generate_series(10, 18) x);
+-- normal truncate
+SELECT sum(id) FROM tru_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_ftable;
+SELECT count(*) FROM tru_rtable0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'truncatable' option
+ALTER SERVER loopback OPTIONS (ADD truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (ADD truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER SERVER loopback OPTIONS (DROP truncatable);
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+-- partitioned table with both local and foreign tables as partitions
+SELECT sum(id) FROM tru_ptable; -- 155
+ sum
+-----
+ 155
+(1 row)
+
+TRUNCATE tru_ptable;
+SELECT count(*) FROM tru_ptable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ptable__p0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable__p1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_rtable1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'CASCADE' option
+SELECT sum(id) FROM tru_pk_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_pk_ftable; -- failed by FK reference
+ERROR: cannot truncate a table referenced in a foreign key constraint
+DETAIL: Table "tru_fk_table" references "tru_pk_table".
+HINT: Truncate table "tru_fk_table" at the same time, or use TRUNCATE ... CASCADE.
+CONTEXT: remote SQL command: TRUNCATE public.tru_pk_table CONTINUE IDENTITY RESTRICT
+TRUNCATE tru_pk_ftable CASCADE;
+SELECT count(*) FROM tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_fk_table; -- also truncated,0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate two tables at a command
+INSERT INTO tru_ftable (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_pk_ftable (SELECT x FROM generate_series(3,10) x);
+SELECT count(*) from tru_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+TRUNCATE tru_ftable, tru_pk_ftable CASCADE;
+SELECT count(*) from tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate with ONLY clause
+-- Since ONLY is specified, the table tru_ftable_child that inherits
+-- tru_ftable_parent locally is not truncated.
+TRUNCATE ONLY tru_ftable_parent;
+SELECT sum(id) FROM tru_ftable_parent; -- 126
+ sum
+-----
+ 126
+(1 row)
+
+TRUNCATE tru_ftable_parent;
+SELECT count(*) FROM tru_ftable_parent; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- in case when remote table has inherited children
+CREATE TABLE tru_rtable0_child () INHERITS (tru_rtable0);
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(5,9) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(10,14) x);
+SELECT sum(id) FROM tru_ftable; -- 95
+ sum
+-----
+ 95
+(1 row)
+
+-- Both parent and child tables in the foreign server are truncated
+-- even though ONLY is specified because ONLY has no effect
+-- when truncating a foreign table.
+TRUNCATE ONLY tru_ftable;
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(21,25) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(26,30) x);
+SELECT sum(id) FROM tru_ftable; -- 255
+ sum
+-----
+ 255
+(1 row)
+
+TRUNCATE tru_ftable; -- truncate both of parent and child
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- cleanup
+DROP FOREIGN TABLE tru_ftable_parent, tru_ftable_child, tru_pk_ftable,tru_ftable__p1,tru_ftable;
+DROP TABLE tru_rtable0, tru_rtable1, tru_ptable, tru_ptable__p0, tru_pk_table, tru_fk_table,
+tru_rtable_parent,tru_rtable_child, tru_rtable0_child;
+-- ===================================================================
+-- test IMPORT FOREIGN SCHEMA
+-- ===================================================================
+CREATE SCHEMA import_source;
+CREATE TABLE import_source.t1 (c1 int, c2 varchar NOT NULL);
+CREATE TABLE import_source.t2 (c1 int default 42, c2 varchar NULL, c3 text collate "POSIX");
+CREATE TYPE typ1 AS (m1 int, m2 varchar);
+CREATE TABLE import_source.t3 (c1 timestamptz default now(), c2 typ1);
+CREATE TABLE import_source."x 4" (c1 float8, "C 2" text, c3 varchar(42));
+CREATE TABLE import_source."x 5" (c1 float8);
+ALTER TABLE import_source."x 5" DROP COLUMN c1;
+CREATE TABLE import_source."x 6" (c1 int, c2 int generated always as (c1 * 2) stored);
+CREATE TABLE import_source.t4 (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE import_source.t4_part PARTITION OF import_source.t4
+ FOR VALUES FROM (1) TO (100);
+CREATE TABLE import_source.t4_part2 PARTITION OF import_source.t4
+ FOR VALUES FROM (100) TO (200);
+CREATE SCHEMA import_dest1;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest1;
+\det+ import_dest1.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest1 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest1 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest1 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest1 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest1 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest1 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest1 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest1.*
+ Foreign table "import_dest1.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest1.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest1.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest1.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest1.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest1.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest1.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Options
+CREATE SCHEMA import_dest2;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest2
+ OPTIONS (import_default 'true');
+\det+ import_dest2.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest2 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest2 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest2 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest2 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest2 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest2 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest2 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest2.*
+ Foreign table "import_dest2.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest2.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | 42 | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest2.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | now() | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest2.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest2.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest2.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest2.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+CREATE SCHEMA import_dest3;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest3
+ OPTIONS (import_collate 'false', import_generated 'false', import_not_null 'false');
+\det+ import_dest3.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest3 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest3 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest3 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest3 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest3 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest3 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest3 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest3.*
+ Foreign table "import_dest3.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest3.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest3.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest3.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest3.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest3.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest3.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Check LIMIT TO and EXCEPT
+CREATE SCHEMA import_dest4;
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t1, nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+(2 rows)
+
+IMPORT FOREIGN SCHEMA import_source EXCEPT (t1, "x 4", nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest4 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest4 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+ import_dest4 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest4 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+-- Assorted error cases
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest4;
+ERROR: relation "t1" already exists
+CONTEXT: importing foreign table "t1"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO import_dest4;
+ERROR: schema "nonesuch" is not present on foreign server "loopback"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO notthere;
+ERROR: schema "notthere" does not exist
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER nowhere INTO notthere;
+ERROR: server "nowhere" does not exist
+-- Check case of a type present only on the remote server.
+-- We can fake this by dropping the type locally in our transaction.
+CREATE TYPE "Colors" AS ENUM ('red', 'green', 'blue');
+CREATE TABLE import_source.t5 (c1 int, c2 text collate "C", "Col" "Colors");
+CREATE SCHEMA import_dest5;
+BEGIN;
+DROP TYPE "Colors" CASCADE;
+NOTICE: drop cascades to column Col of table import_source.t5
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t5)
+ FROM SERVER loopback INTO import_dest5; -- ERROR
+ERROR: type "public.Colors" does not exist
+LINE 4: "Col" public."Colors" OPTIONS (column_name 'Col')
+ ^
+QUERY: CREATE FOREIGN TABLE t5 (
+ c1 integer OPTIONS (column_name 'c1'),
+ c2 text OPTIONS (column_name 'c2') COLLATE pg_catalog."C",
+ "Col" public."Colors" OPTIONS (column_name 'Col')
+) SERVER loopback
+OPTIONS (schema_name 'import_source', table_name 't5');
+CONTEXT: importing foreign table "t5"
+ROLLBACK;
+BEGIN;
+CREATE SERVER fetch101 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( fetch_size '101' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER fetch101 OPTIONS( SET fetch_size '202' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=202'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30000 ( x int ) SERVER fetch101 OPTIONS ( fetch_size '30000' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '60000');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=60000'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- ===================================================================
+-- test partitionwise joins
+-- ===================================================================
+SET enable_partitionwise_join=on;
+CREATE TABLE fprt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE fprt1_p1 (LIKE fprt1);
+CREATE TABLE fprt1_p2 (LIKE fprt1);
+ALTER TABLE fprt1_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt1_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt1_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 2) i;
+INSERT INTO fprt1_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 2) i;
+CREATE FOREIGN TABLE ftprt1_p1 PARTITION OF fprt1 FOR VALUES FROM (0) TO (250)
+ SERVER loopback OPTIONS (table_name 'fprt1_p1', use_remote_estimate 'true');
+CREATE FOREIGN TABLE ftprt1_p2 PARTITION OF fprt1 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (TABLE_NAME 'fprt1_p2');
+ANALYZE fprt1;
+ANALYZE fprt1_p1;
+ANALYZE fprt1_p2;
+CREATE TABLE fprt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE fprt2_p1 (LIKE fprt2);
+CREATE TABLE fprt2_p2 (LIKE fprt2);
+ALTER TABLE fprt2_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt2_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt2_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 3) i;
+INSERT INTO fprt2_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 3) i;
+CREATE FOREIGN TABLE ftprt2_p1 (b int, c varchar, a int)
+ SERVER loopback OPTIONS (table_name 'fprt2_p1', use_remote_estimate 'true');
+ALTER TABLE fprt2 ATTACH PARTITION ftprt2_p1 FOR VALUES FROM (0) TO (250);
+CREATE FOREIGN TABLE ftprt2_p2 PARTITION OF fprt2 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (table_name 'fprt2_p2', use_remote_estimate 'true');
+ANALYZE fprt2;
+ANALYZE fprt2_p1;
+ANALYZE fprt2_p2;
+-- inner join three tables
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t3.c
+ -> Append
+ -> Foreign Scan
+ Relations: ((ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)) INNER JOIN (ftprt1_p1 t3_1)
+ -> Foreign Scan
+ Relations: ((ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)) INNER JOIN (ftprt1_p2 t3_2)
+(7 rows)
+
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0003
+ 250 | 250 | 0005
+ 400 | 400 | 0008
+(4 rows)
+
+-- left outer join + nullable clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.a, fprt2.b, fprt2.c
+ Relations: (public.ftprt1_p1 t1) LEFT JOIN (public.ftprt2_p1 fprt2)
+ Remote SQL: SELECT r5.a, r6.b, r6.c FROM (public.fprt1_p1 r5 LEFT JOIN public.fprt2_p1 r6 ON (((r5.a = r6.b)) AND ((r5.b = r6.a)) AND ((r6.a < 10)))) WHERE ((r5.a < 10)) ORDER BY r5.a ASC NULLS LAST, r6.b ASC NULLS LAST, r6.c ASC NULLS LAST
+(4 rows)
+
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ a | b | c
+---+---+------
+ 0 | 0 | 0000
+ 2 | |
+ 4 | |
+ 6 | 6 | 0000
+ 8 | |
+(5 rows)
+
+-- with whole-row reference; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ QUERY PLAN
+--------------------------------------------------------
+ Sort
+ Sort Key: ((t1.*)::fprt1), ((t2.*)::fprt2)
+ -> Hash Full Join
+ Hash Cond: (t1.a = t2.b)
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+(11 rows)
+
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ wr | wr
+----------------+----------------
+ (0,0,0000) | (0,0,0000)
+ (50,50,0001) |
+ (100,100,0002) |
+ (150,150,0003) | (150,150,0003)
+ (200,200,0004) |
+ (250,250,0005) | (250,250,0005)
+ (300,300,0006) |
+ (350,350,0007) |
+ (400,400,0008) | (400,400,0008)
+ (450,450,0009) |
+ | (75,75,0001)
+ | (225,225,0004)
+ | (325,325,0006)
+ | (475,475,0009)
+(14 rows)
+
+-- join with lateral reference
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t1.b
+ -> Append
+ -> Foreign Scan
+ Relations: (ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)
+ -> Foreign Scan
+ Relations: (ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)
+(7 rows)
+
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+-- with PHVs, partitionwise join selected but no join pushdown
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: fprt1.a, fprt2.b
+ -> Append
+ -> Hash Full Join
+ Hash Cond: (fprt1_1.a = fprt2_1.b)
+ -> Foreign Scan on ftprt1_p1 fprt1_1
+ -> Hash
+ -> Foreign Scan on ftprt2_p1 fprt2_1
+ -> Hash Full Join
+ Hash Cond: (fprt1_2.a = fprt2_2.b)
+ -> Foreign Scan on ftprt1_p2 fprt1_2
+ -> Hash
+ -> Foreign Scan on ftprt2_p2 fprt2_2
+(13 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | phv | b | phv
+-----+--------+-----+--------
+ 0 | t1_phv | 0 | t2_phv
+ 50 | t1_phv | |
+ 100 | t1_phv | |
+ 150 | t1_phv | 150 | t2_phv
+ 200 | t1_phv | |
+ 250 | t1_phv | 250 | t2_phv
+ 300 | t1_phv | |
+ 350 | t1_phv | |
+ 400 | t1_phv | 400 | t2_phv
+ 450 | t1_phv | |
+ | | 75 | t2_phv
+ | | 225 | t2_phv
+ | | 325 | t2_phv
+ | | 475 | t2_phv
+(14 rows)
+
+-- test FOR UPDATE; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ QUERY PLAN
+--------------------------------------------------------------
+ LockRows
+ -> Sort
+ Sort Key: t1.a
+ -> Hash Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+(12 rows)
+
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+RESET enable_partitionwise_join;
+-- ===================================================================
+-- test partitionwise aggregates
+-- ===================================================================
+CREATE TABLE pagg_tab (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE pagg_tab_p1 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p2 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p3 (LIKE pagg_tab);
+INSERT INTO pagg_tab_p1 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 10;
+INSERT INTO pagg_tab_p2 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 20 and (i % 30) >= 10;
+INSERT INTO pagg_tab_p3 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 30 and (i % 30) >= 20;
+-- Create foreign partitions
+CREATE FOREIGN TABLE fpagg_tab_p1 PARTITION OF pagg_tab FOR VALUES FROM (0) TO (10) SERVER loopback OPTIONS (table_name 'pagg_tab_p1');
+CREATE FOREIGN TABLE fpagg_tab_p2 PARTITION OF pagg_tab FOR VALUES FROM (10) TO (20) SERVER loopback OPTIONS (table_name 'pagg_tab_p2');
+CREATE FOREIGN TABLE fpagg_tab_p3 PARTITION OF pagg_tab FOR VALUES FROM (20) TO (30) SERVER loopback OPTIONS (table_name 'pagg_tab_p3');
+ANALYZE pagg_tab;
+ANALYZE fpagg_tab_p1;
+ANALYZE fpagg_tab_p2;
+ANALYZE fpagg_tab_p3;
+-- When GROUP BY clause matches with PARTITION KEY.
+-- Plan with partitionwise aggregates is disabled
+SET enable_partitionwise_aggregate TO false;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> HashAggregate
+ Group Key: pagg_tab.a
+ Filter: (avg(pagg_tab.b) < '22'::numeric)
+ -> Append
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab_1
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_2
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_3
+(9 rows)
+
+-- Plan with partitionwise aggregates is enabled
+SET enable_partitionwise_aggregate TO true;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> Append
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p1 pagg_tab)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p2 pagg_tab_1)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p3 pagg_tab_2)
+(9 rows)
+
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | sum | min | count
+----+------+-----+-------
+ 0 | 2000 | 0 | 100
+ 1 | 2100 | 1 | 100
+ 10 | 2000 | 0 | 100
+ 11 | 2100 | 1 | 100
+ 20 | 2000 | 0 | 100
+ 21 | 2100 | 1 | 100
+(6 rows)
+
+-- Check with whole-row reference
+-- Should have all the columns in the target list for the given relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, (count(((t1.*)::pagg_tab)))
+ Sort Key: t1.a
+ -> Append
+ -> HashAggregate
+ Output: t1.a, count(((t1.*)::pagg_tab))
+ Group Key: t1.a
+ Filter: (avg(t1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p1 t1
+ Output: t1.a, t1.*, t1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p1
+ -> HashAggregate
+ Output: t1_1.a, count(((t1_1.*)::pagg_tab))
+ Group Key: t1_1.a
+ Filter: (avg(t1_1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p2 t1_1
+ Output: t1_1.a, t1_1.*, t1_1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p2
+ -> HashAggregate
+ Output: t1_2.a, count(((t1_2.*)::pagg_tab))
+ Group Key: t1_2.a
+ Filter: (avg(t1_2.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p3 t1_2
+ Output: t1_2.a, t1_2.*, t1_2.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p3
+(25 rows)
+
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | count
+----+-------
+ 0 | 100
+ 1 | 100
+ 10 | 100
+ 11 | 100
+ 20 | 100
+ 21 | 100
+(6 rows)
+
+-- When GROUP BY clause does not match with PARTITION KEY.
+EXPLAIN (COSTS OFF)
+SELECT b, avg(a), max(a), count(*) FROM pagg_tab GROUP BY b HAVING sum(a) < 700 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.b
+ -> Finalize HashAggregate
+ Group Key: pagg_tab.b
+ Filter: (sum(pagg_tab.a) < 700)
+ -> Append
+ -> Partial HashAggregate
+ Group Key: pagg_tab.b
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab
+ -> Partial HashAggregate
+ Group Key: pagg_tab_1.b
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_1
+ -> Partial HashAggregate
+ Group Key: pagg_tab_2.b
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_2
+(15 rows)
+
+-- ===================================================================
+-- access rights and superuser
+-- ===================================================================
+-- Non-superuser cannot create a FDW without a password in the connstr
+CREATE ROLE regress_nosuper NOSUPERUSER;
+GRANT USAGE ON FOREIGN DATA WRAPPER postgres_fdw TO regress_nosuper;
+SET ROLE regress_nosuper;
+SHOW is_superuser;
+ is_superuser
+--------------
+ off
+(1 row)
+
+-- This will be OK, we can create the FDW
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback_nopw FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+-- But creation of user mappings for non-superusers should fail
+CREATE USER MAPPING FOR public SERVER loopback_nopw;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+CREATE FOREIGN TABLE pg_temp.ft1_nopw (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback_nopw OPTIONS (schema_name 'public', table_name 'ft1');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+-- If we add a password to the connstr it'll fail, because we don't allow passwords
+-- in connstrs only in user mappings.
+ALTER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+ERROR: invalid option "password"
+HINT: Perhaps you meant the option "passfile".
+-- If we add a password for our user mapping instead, we should get a different
+-- error because the password wasn't actually *used* when we run with trust auth.
+--
+-- This won't work with installcheck, but neither will most of the FDW checks.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+-- Unpriv user cannot make the mapping passwordless
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+ERROR: password_required=false is superuser-only
+HINT: User mappings with the password_required option set to false may only be created or modified by the superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+RESET ROLE;
+-- But the superuser can
+ALTER USER MAPPING FOR regress_nosuper SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+SET ROLE regress_nosuper;
+-- Should finally work now
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- unpriv user also cannot set sslcert / sslkey on the user mapping
+-- first set password_required so we see the right error messages
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (SET password_required 'true');
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslcert 'foo.crt');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslkey 'foo.key');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+-- We're done with the role named after a specific user and need to check the
+-- changes to the public mapping.
+DROP USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+-- This will fail again as it'll resolve the user mapping for public, which
+-- lacks password_required=false
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+RESET ROLE;
+-- The user mapping for public is passwordless and lacks the password_required=false
+-- mapping option, but will work because the current user is a superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- cleanup
+DROP USER MAPPING FOR public SERVER loopback_nopw;
+DROP OWNED BY regress_nosuper;
+DROP ROLE regress_nosuper;
+-- Clean-up
+RESET enable_partitionwise_aggregate;
+-- Two-phase transactions are not supported.
+BEGIN;
+SELECT count(*) FROM ft1;
+ count
+-------
+ 822
+(1 row)
+
+-- error here
+PREPARE TRANSACTION 'fdw_tpc';
+ERROR: cannot PREPARE a transaction that has operated on postgres_fdw foreign tables
+ROLLBACK;
+WARNING: there is no transaction in progress
+-- ===================================================================
+-- reestablish new connection
+-- ===================================================================
+-- Change application_name of remote connection to special one
+-- so that we can easily terminate the connection later.
+ALTER SERVER loopback OPTIONS (application_name 'fdw_retry_check');
+-- If debug_discard_caches is active, it results in
+-- dropping remote connections after every transaction, making it
+-- impossible to test termination meaningfully. So turn that off
+-- for this test.
+SET debug_discard_caches = 0;
+-- Make sure we have a remote connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- This query should detect the broken connection when starting new remote
+-- transaction, reestablish new connection, and then succeed.
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- If we detect the broken connection when starting a new remote
+-- subtransaction, we should fail instead of establishing a new connection.
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+SAVEPOINT s;
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT 1 FROM ft1 LIMIT 1; -- should fail
+ERROR: 08006
+\set VERBOSITY default
+COMMIT;
+RESET debug_discard_caches;
+-- =============================================================================
+-- test connection invalidation cases and postgres_fdw_get_connections function
+-- =============================================================================
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- This test case is for closing the connection in pgfdw_xact_callback
+BEGIN;
+-- Connection xact depth becomes 1 i.e. the connection is in midst of the xact.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT 1 FROM ft7 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback3 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback3
+(2 rows)
+
+-- Connections are not closed at the end of the alter and drop statements.
+-- That's because the connections are in midst of this xact,
+-- they are just marked as invalid in pgfdw_inval_callback.
+ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
+DROP SERVER loopback3 CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to user mapping for public on server loopback3
+drop cascades to foreign table ft7
+-- List all the existing cached connections. loopback and loopback3
+-- should be output as invalid connections. Also the server name for
+-- loopback3 should be NULL because the server was dropped.
+SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | valid
+-------------+-------
+ loopback | f
+ | f
+(2 rows)
+
+-- The invalid connections get closed in pgfdw_xact_callback during commit.
+COMMIT;
+-- All cached connections were closed while committing above xact, so no
+-- records should be output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+(0 rows)
+
+-- =======================================================================
+-- test postgres_fdw_disconnect and postgres_fdw_disconnect_all functions
+-- =======================================================================
+BEGIN;
+-- Ensure to cache loopback connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Ensure to cache loopback2 connection.
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Issue a warning and return false as loopback connection is still in use and
+-- can not be closed.
+SELECT postgres_fdw_disconnect('loopback');
+WARNING: cannot close connection for server "loopback" because it is still in use
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Return false as connections are still in use, warnings are issued.
+-- But disable warnings temporarily because the order of them is not stable.
+SET client_min_messages = 'ERROR';
+SELECT postgres_fdw_disconnect_all();
+ postgres_fdw_disconnect_all
+-----------------------------
+ f
+(1 row)
+
+RESET client_min_messages;
+COMMIT;
+-- Ensure that loopback2 connection is closed.
+SELECT 1 FROM postgres_fdw_disconnect('loopback2');
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT server_name FROM postgres_fdw_get_connections() WHERE server_name = 'loopback2';
+ server_name
+-------------
+(0 rows)
+
+-- Return false as loopback2 connection is closed already.
+SELECT postgres_fdw_disconnect('loopback2');
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- Return an error as there is no foreign server with given name.
+SELECT postgres_fdw_disconnect('unknownserver');
+ERROR: server "unknownserver" does not exist
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- =============================================================================
+-- test case for having multiple cached connections for a foreign server
+-- =============================================================================
+CREATE ROLE regress_multi_conn_user1 SUPERUSER;
+CREATE ROLE regress_multi_conn_user2 SUPERUSER;
+CREATE USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+CREATE USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+BEGIN;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user1
+SET ROLE regress_multi_conn_user1;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user2
+SET ROLE regress_multi_conn_user2;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Should output two connections for loopback server
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback
+(2 rows)
+
+COMMIT;
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- Clean up
+DROP USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+DROP USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+DROP ROLE regress_multi_conn_user1;
+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
+-- ===================================================================
+BEGIN;
+CREATE SERVER batch10 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( batch_size '10' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER batch10 OPTIONS( SET batch_size '20' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=20'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30 ( x int ) SERVER batch10 OPTIONS ( batch_size '30' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30 OPTIONS ( SET batch_size '40');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=40'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+CREATE TABLE batch_table ( x int );
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '10' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 10
+ -> Function Scan on pg_catalog.generate_series i
+ Output: i.i
+ Function Call: generate_series(1, 10)
+(6 rows)
+
+INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+INSERT INTO ftable SELECT * FROM generate_series(11, 31) i;
+INSERT INTO ftable VALUES (32);
+INSERT INTO ftable VALUES (33), (34);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 34
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- try if large batches exceed max number of bind parameters
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '100000' );
+INSERT INTO ftable SELECT * FROM generate_series(1, 70000) i;
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 70000
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- Disable batch insert
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '1' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (1), (2);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 2
+(1 row)
+
+-- Disable batch inserting into foreign tables with BEFORE ROW INSERT triggers
+-- even if the batch_size option is enabled.
+ALTER FOREIGN TABLE ftable OPTIONS ( SET batch_size '10' );
+CREATE TRIGGER trig_row_before BEFORE INSERT ON ftable
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (3), (4);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (3), (4);
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (3)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (4)
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 4
+(1 row)
+
+-- Clean up
+DROP TRIGGER trig_row_before ON ftable;
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+-- Use partitioning
+CREATE TABLE batch_table ( x int ) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0', batch_size '10');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1', batch_size '1');
+CREATE TABLE batch_table_p2
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 2);
+INSERT INTO batch_table SELECT * FROM generate_series(1, 66) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 66
+(1 row)
+
+-- Check that enabling batched inserts doesn't interfere with cross-partition
+-- updates
+CREATE TABLE batch_cp_upd_test (a int) PARTITION BY LIST (a);
+CREATE TABLE batch_cp_upd_test1 (LIKE batch_cp_upd_test);
+CREATE FOREIGN TABLE batch_cp_upd_test1_f
+ PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_cp_upd_test1', batch_size '10');
+CREATE TABLE batch_cp_up_test1 PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (2);
+INSERT INTO batch_cp_upd_test VALUES (1), (2);
+-- The following moves a row from the local partition to the foreign one
+UPDATE batch_cp_upd_test t SET a = 1 FROM (VALUES (1), (2)) s(a) WHERE t.a = s.a;
+ERROR: cannot route tuples into foreign table to be updated "batch_cp_upd_test1_f"
+SELECT tableoid::regclass, * FROM batch_cp_upd_test;
+ tableoid | a
+----------------------+---
+ batch_cp_upd_test1_f | 1
+ batch_cp_up_test1 | 2
+(2 rows)
+
+-- Clean up
+DROP TABLE batch_table, batch_cp_upd_test, batch_table_p0, batch_table_p1 CASCADE;
+-- Use partitioning
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+CREATE TABLE batch_table ( x int, field1 text, field2 text) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+ALTER TABLE batch_table_p0 ADD CONSTRAINT p0_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+ALTER TABLE batch_table_p1 ADD CONSTRAINT p1_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1');
+INSERT INTO batch_table SELECT i, 'test'||i, 'test'|| i FROM generate_series(1, 50) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 50
+(1 row)
+
+SELECT * FROM batch_table ORDER BY x;
+ x | field1 | field2
+----+--------+--------
+ 1 | test1 | test1
+ 2 | test2 | test2
+ 3 | test3 | test3
+ 4 | test4 | test4
+ 5 | test5 | test5
+ 6 | test6 | test6
+ 7 | test7 | test7
+ 8 | test8 | test8
+ 9 | test9 | test9
+ 10 | test10 | test10
+ 11 | test11 | test11
+ 12 | test12 | test12
+ 13 | test13 | test13
+ 14 | test14 | test14
+ 15 | test15 | test15
+ 16 | test16 | test16
+ 17 | test17 | test17
+ 18 | test18 | test18
+ 19 | test19 | test19
+ 20 | test20 | test20
+ 21 | test21 | test21
+ 22 | test22 | test22
+ 23 | test23 | test23
+ 24 | test24 | test24
+ 25 | test25 | test25
+ 26 | test26 | test26
+ 27 | test27 | test27
+ 28 | test28 | test28
+ 29 | test29 | test29
+ 30 | test30 | test30
+ 31 | test31 | test31
+ 32 | test32 | test32
+ 33 | test33 | test33
+ 34 | test34 | test34
+ 35 | test35 | test35
+ 36 | test36 | test36
+ 37 | test37 | test37
+ 38 | test38 | test38
+ 39 | test39 | test39
+ 40 | test40 | test40
+ 41 | test41 | test41
+ 42 | test42 | test42
+ 43 | test43 | test43
+ 44 | test44 | test44
+ 45 | test45 | test45
+ 46 | test46 | test46
+ 47 | test47 | test47
+ 48 | test48 | test48
+ 49 | test49 | test49
+ 50 | test50 | test50
+(50 rows)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+-- ===================================================================
+-- test asynchronous execution
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD async_capable 'true');
+ALTER SERVER loopback2 OPTIONS (ADD async_capable 'true');
+CREATE TABLE async_pt (a int, b int, c text) PARTITION BY RANGE (a);
+CREATE TABLE base_tbl1 (a int, b int, c text);
+CREATE TABLE base_tbl2 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p1 PARTITION OF async_pt FOR VALUES FROM (1000) TO (2000)
+ SERVER loopback OPTIONS (table_name 'base_tbl1');
+CREATE FOREIGN TABLE async_p2 PARTITION OF async_pt FOR VALUES FROM (2000) TO (3000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl2');
+INSERT INTO async_p1 SELECT 1000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+INSERT INTO async_p2 SELECT 2000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+-- simple queries
+CREATE TABLE result_tbl (a int, b int, c text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE (((b % 100) = 0))
+(8 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1000 | 0 | 0000
+ 1100 | 100 | 0100
+ 1200 | 200 | 0200
+ 1300 | 300 | 0300
+ 1400 | 400 | 0400
+ 1500 | 500 | 0500
+ 1600 | 600 | 0600
+ 1700 | 700 | 0700
+ 1800 | 800 | 0800
+ 1900 | 900 | 0900
+ 2000 | 0 | 0000
+ 2100 | 100 | 0100
+ 2200 | 200 | 0200
+ 2300 | 300 | 0300
+ 2400 | 400 | 0400
+ 2500 | 500 | 0500
+ 2600 | 600 | 0600
+ 2700 | 700 | 0700
+ 2800 | 800 | 0800
+ 2900 | 900 | 0900
+(20 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, ('AAA'::text || async_pt_1.c)
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, ('AAA'::text || async_pt_2.c)
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+---------
+ 1505 | 505 | AAA0505
+ 2505 | 505 | AAA0505
+(2 rows)
+
+DELETE FROM result_tbl;
+-- Check case where multiple partitions use the same connection
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl3');
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Async Foreign Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(14 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+DROP FOREIGN TABLE async_p3;
+DROP TABLE base_tbl3;
+-- Check case where the partitioned table has local/remote partitions
+CREATE TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000);
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+(13 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+-- partitionwise joins
+SET enable_partitionwise_join TO true;
+CREATE TABLE join_tbl (a1 int, b1 int, c1 text, a2 int, b2 int, c2 text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t2_1.b, t2_1.c
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t2_2.b, t2_2.c
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, t1_3.c, t2_3.a, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+ 2000 | 0 | 0000 | 2000 | 0 | 0000
+ 2100 | 100 | 0100 | 2100 | 100 | 0100
+ 2200 | 200 | 0200 | 2200 | 200 | 0200
+ 2300 | 300 | 0300 | 2300 | 300 | 0300
+ 2400 | 400 | 0400 | 2400 | 400 | 0400
+ 2500 | 500 | 0500 | 2500 | 500 | 0500
+ 2600 | 600 | 0600 | 2600 | 600 | 0600
+ 2700 | 700 | 0700 | 2700 | 700 | 0700
+ 2800 | 800 | 0800 | 2800 | 800 | 0800
+ 2900 | 900 | 0900 | 2900 | 900 | 0900
+ 3000 | 0 | 0000 | 3000 | 0 | 0000
+ 3100 | 100 | 0100 | 3100 | 100 | 0100
+ 3200 | 200 | 0200 | 3200 | 200 | 0200
+ 3300 | 300 | 0300 | 3300 | 300 | 0300
+ 3400 | 400 | 0400 | 3400 | 400 | 0400
+ 3500 | 500 | 0500 | 3500 | 500 | 0500
+ 3600 | 600 | 0600 | 3600 | 600 | 0600
+ 3700 | 700 | 0700 | 3700 | 700 | 0700
+ 3800 | 800 | 0800 | 3800 | 800 | 0800
+ 3900 | 900 | 0900 | 3900 | 900 | 0900
+(30 rows)
+
+DELETE FROM join_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, ('AAA'::text || t1_1.c), t2_1.a, t2_1.b, ('AAA'::text || t2_1.c)
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, ('AAA'::text || t1_2.c), t2_2.a, t2_2.b, ('AAA'::text || t2_2.c)
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, ('AAA'::text || t1_3.c), t2_3.a, t2_3.b, ('AAA'::text || t2_3.c)
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+---------+------+-----+---------
+ 1000 | 0 | AAA0000 | 1000 | 0 | AAA0000
+ 1100 | 100 | AAA0100 | 1100 | 100 | AAA0100
+ 1200 | 200 | AAA0200 | 1200 | 200 | AAA0200
+ 1300 | 300 | AAA0300 | 1300 | 300 | AAA0300
+ 1400 | 400 | AAA0400 | 1400 | 400 | AAA0400
+ 1500 | 500 | AAA0500 | 1500 | 500 | AAA0500
+ 1600 | 600 | AAA0600 | 1600 | 600 | AAA0600
+ 1700 | 700 | AAA0700 | 1700 | 700 | AAA0700
+ 1800 | 800 | AAA0800 | 1800 | 800 | AAA0800
+ 1900 | 900 | AAA0900 | 1900 | 900 | AAA0900
+ 2000 | 0 | AAA0000 | 2000 | 0 | AAA0000
+ 2100 | 100 | AAA0100 | 2100 | 100 | AAA0100
+ 2200 | 200 | AAA0200 | 2200 | 200 | AAA0200
+ 2300 | 300 | AAA0300 | 2300 | 300 | AAA0300
+ 2400 | 400 | AAA0400 | 2400 | 400 | AAA0400
+ 2500 | 500 | AAA0500 | 2500 | 500 | AAA0500
+ 2600 | 600 | AAA0600 | 2600 | 600 | AAA0600
+ 2700 | 700 | AAA0700 | 2700 | 700 | AAA0700
+ 2800 | 800 | AAA0800 | 2800 | 800 | AAA0800
+ 2900 | 900 | AAA0900 | 2900 | 900 | AAA0900
+ 3000 | 0 | AAA0000 | 3000 | 0 | AAA0000
+ 3100 | 100 | AAA0100 | 3100 | 100 | AAA0100
+ 3200 | 200 | AAA0200 | 3200 | 200 | AAA0200
+ 3300 | 300 | AAA0300 | 3300 | 300 | AAA0300
+ 3400 | 400 | AAA0400 | 3400 | 400 | AAA0400
+ 3500 | 500 | AAA0500 | 3500 | 500 | AAA0500
+ 3600 | 600 | AAA0600 | 3600 | 600 | AAA0600
+ 3700 | 700 | AAA0700 | 3700 | 700 | AAA0700
+ 3800 | 800 | AAA0800 | 3800 | 800 | AAA0800
+ 3900 | 900 | AAA0900 | 3900 | 900 | AAA0900
+(30 rows)
+
+DELETE FROM join_tbl;
+RESET enable_partitionwise_join;
+-- Test rescan of an async Append node with do_exec_prune=false
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: ((t1.a = t2.a) AND (t1.b = t2.b))
+ -> Foreign Scan on public.async_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t2_1
+ Output: t2_1.a, t2_1.b, t2_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t2_2
+ Output: t2_2.a, t2_2.b, t2_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+(16 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+(10 rows)
+
+DELETE FROM join_tbl;
+RESET enable_hashjoin;
+-- Test interaction of async execution with plan-time partition pruning
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 3000;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(7 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 2000;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Foreign Scan on public.async_p1 async_pt
+ Output: async_pt.a, async_pt.b, async_pt.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 2000))
+(3 rows)
+
+-- Test interaction of async execution with run-time partition pruning
+SET plan_cache_mode TO force_generic_plan;
+PREPARE async_pt_query (int, int) AS
+ INSERT INTO result_tbl SELECT * FROM async_pt WHERE a < $1 AND b === $2;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (3000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 1
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < $1::integer))
+(11 rows)
+
+EXECUTE async_pt_query (3000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (2000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 2
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+(7 rows)
+
+EXECUTE async_pt_query (2000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+(1 row)
+
+DELETE FROM result_tbl;
+RESET plan_cache_mode;
+CREATE TABLE local_tbl(a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo'), (2505, 505, 'bar');
+ANALYZE local_tbl;
+CREATE INDEX base_tbl1_idx ON base_tbl1 (a);
+CREATE INDEX base_tbl2_idx ON base_tbl2 (a);
+CREATE INDEX async_p3_idx ON async_p3 (a);
+ANALYZE base_tbl1;
+ANALYZE base_tbl2;
+ANALYZE async_p3;
+ALTER FOREIGN TABLE async_p1 OPTIONS (use_remote_estimate 'true');
+ALTER FOREIGN TABLE async_p2 OPTIONS (use_remote_estimate 'true');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: local_tbl.a, local_tbl.b, local_tbl.c, async_pt.a, async_pt.b, async_pt.c
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ Filter: (local_tbl.c = 'bar'::text)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a = $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a = $1::integer))
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.a = local_tbl.a)
+(15 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Nested Loop (actual rows=1 loops=1)
+ -> Seq Scan on local_tbl (actual rows=1 loops=1)
+ Filter: (c = 'bar'::text)
+ Rows Removed by Filter: 1
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (never executed)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=1 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (never executed)
+ Filter: (a = local_tbl.a)
+(9 rows)
+
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ a | b | c | a | b | c
+------+-----+-----+------+-----+------
+ 2505 | 505 | bar | 2505 | 505 | 0505
+(1 row)
+
+ALTER FOREIGN TABLE async_p1 OPTIONS (DROP use_remote_estimate);
+ALTER FOREIGN TABLE async_p2 OPTIONS (DROP use_remote_estimate);
+DROP TABLE local_tbl;
+DROP INDEX base_tbl1_idx;
+DROP INDEX base_tbl2_idx;
+DROP INDEX async_p3_idx;
+-- UNION queries
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> HashAggregate
+ Output: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ Group Key: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(11 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(8 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+-- Disable async execution if we use gating Result nodes for pseudoconstant
+-- quals
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Result
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+(18 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+(SELECT * FROM async_p1 WHERE CURRENT_USER = SESSION_USER)
+UNION ALL
+(SELECT * FROM async_p2 WHERE CURRENT_USER = SESSION_USER);
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(13 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ((SELECT * FROM async_p1 WHERE b < 10) UNION ALL (SELECT * FROM async_p2 WHERE b < 10)) s WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((b < 10))
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(13 rows)
+
+-- Test that pending requests are processed properly
+SET enable_mergejoin TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: (t1.a = t2.a)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+ -> Materialize
+ Output: t2.a, t2.b, t2.c
+ -> Foreign Scan on public.async_p2 t2
+ Output: t2.a, t2.b, t2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(20 rows)
+
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ a | b | c | a | b | c
+------+-----+------+------+-----+------
+ 2505 | 505 | 0505 | 2505 | 505 | 0505
+(1 row)
+
+CREATE TABLE local_tbl (a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo');
+ANALYZE local_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, async_pt.a, async_pt.b, async_pt.c, ($0)
+ Join Filter: (t1.a = async_pt.a)
+ InitPlan 1 (returns $0)
+ -> Aggregate
+ Output: count(*)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_4
+ Remote SQL: SELECT NULL FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_5
+ Remote SQL: SELECT NULL FROM public.base_tbl2 WHERE ((a < 3000))
+ -> Seq Scan on public.local_tbl t1
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(20 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Nested Loop Left Join (actual rows=1 loops=1)
+ Join Filter: (t1.a = async_pt.a)
+ Rows Removed by Join Filter: 399
+ InitPlan 1 (returns $0)
+ -> Aggregate (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_4 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_5 (actual rows=200 loops=1)
+ -> Seq Scan on local_tbl t1 (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=200 loops=1)
+(12 rows)
+
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ a | b | c | a | b | c | count
+------+-----+-----+------+-----+------+-------
+ 1505 | 505 | foo | 1505 | 505 | 0505 | 400
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+----------------------------------------------------------------
+ Limit
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+(14 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit (actual rows=1 loops=1)
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 t1_1 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Async Foreign Scan on async_p2 t1_2 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Seq Scan on async_p3 t1_3 (actual rows=1 loops=1)
+ Filter: (b === 505)
+ Rows Removed by Filter: 101
+(9 rows)
+
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ a | b | c
+------+-----+------
+ 3505 | 505 | 0505
+(1 row)
+
+-- Check with foreign modify
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE remote_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl3');
+INSERT INTO remote_tbl VALUES (2505, 505, 'bar');
+CREATE TABLE base_tbl4 (a int, b int, c text);
+CREATE FOREIGN TABLE insert_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl4');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Insert on public.insert_tbl
+ Remote SQL: INSERT INTO public.base_tbl4(a, b, c) VALUES ($1, $2, $3)
+ Batch Size: 1
+ -> Append
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ -> Async Foreign Scan on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(9 rows)
+
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+SELECT * FROM insert_tbl ORDER BY a;
+ a | b | c
+------+-----+-----
+ 1505 | 505 | foo
+ 2505 | 505 | bar
+(2 rows)
+
+-- Check with direct modify
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ CTE t
+ -> Update on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ -> Foreign Update on public.remote_tbl
+ Remote SQL: UPDATE public.base_tbl3 SET c = (c || c) RETURNING a, b, c
+ -> Nested Loop Left Join
+ Output: async_pt.a, async_pt.b, async_pt.c, t.a, t.b, t.c
+ Join Filter: ((async_pt.a = t.a) AND (async_pt.b = t.b))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ -> CTE Scan on t
+ Output: t.a, t.b, t.c
+(23 rows)
+
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+--------
+ 1505 | 505 | 0505 | | |
+ 2505 | 505 | 0505 | 2505 | 505 | barbar
+ 3505 | 505 | 0505 | | |
+(3 rows)
+
+DELETE FROM join_tbl;
+DROP TABLE local_tbl;
+DROP FOREIGN TABLE remote_tbl;
+DROP FOREIGN TABLE insert_tbl;
+DROP TABLE base_tbl3;
+DROP TABLE base_tbl4;
+RESET enable_mergejoin;
+RESET enable_hashjoin;
+-- Test that UPDATE/DELETE with inherited target works with async_capable enabled
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Update on public.async_p1 async_pt_1
+ Foreign Update on public.async_p2 async_pt_2
+ Update on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Update on public.async_p1 async_pt_1
+ Remote SQL: UPDATE public.base_tbl1 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Update on public.async_p2 async_pt_2
+ Remote SQL: UPDATE public.base_tbl2 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: (async_pt_3.c || async_pt_3.c), async_pt_3.tableoid, async_pt_3.ctid, NULL::record
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Delete on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Delete on public.async_p1 async_pt_1
+ Foreign Delete on public.async_p2 async_pt_2
+ Delete on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Delete on public.async_p1 async_pt_1
+ Remote SQL: DELETE FROM public.base_tbl1 WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Delete on public.async_p2 async_pt_2
+ Remote SQL: DELETE FROM public.base_tbl2 WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.tableoid, async_pt_3.ctid
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+-- Check EXPLAIN ANALYZE for a query that scans empty partitions asynchronously
+DELETE FROM async_p1;
+DELETE FROM async_p2;
+DELETE FROM async_p3;
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Append (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=0 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (actual rows=0 loops=1)
+(4 rows)
+
+-- Clean up
+DROP TABLE async_pt;
+DROP TABLE base_tbl1;
+DROP TABLE base_tbl2;
+DROP TABLE result_tbl;
+DROP TABLE join_tbl;
+-- Test that an asynchronous fetch is processed before restarting the scan in
+-- ReScanForeignScan
+CREATE TABLE base_tbl (a int, b int);
+INSERT INTO base_tbl VALUES (1, 11), (2, 22), (3, 33);
+CREATE FOREIGN TABLE foreign_tbl (b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE FOREIGN TABLE foreign_tbl2 () INHERITS (foreign_tbl)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Seq Scan on public.base_tbl
+ Output: base_tbl.a
+ Filter: (SubPlan 1)
+ SubPlan 1
+ -> Result
+ Output: base_tbl.a
+ -> Append
+ -> Async Foreign Scan on public.foreign_tbl foreign_tbl_1
+ Remote SQL: SELECT NULL FROM public.base_tbl
+ -> Async Foreign Scan on public.foreign_tbl2 foreign_tbl_2
+ Remote SQL: SELECT NULL FROM public.base_tbl
+(11 rows)
+
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ a
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+-- Clean up
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to foreign table foreign_tbl2
+DROP TABLE base_tbl;
+ALTER SERVER loopback OPTIONS (DROP async_capable);
+ALTER SERVER loopback2 OPTIONS (DROP async_capable);
+-- ===================================================================
+-- test invalid server, foreign table and foreign data wrapper options
+-- ===================================================================
+-- Invalid fdw_startup_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_startup_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_startup_cost": 100$%$#$#
+-- Invalid fdw_tuple_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_tuple_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_tuple_cost": 100$%$#$#
+-- Invalid fetch_size option
+CREATE FOREIGN TABLE inv_fsz (c1 int )
+ SERVER loopback OPTIONS (fetch_size '100$%$#$#');
+ERROR: invalid value for integer option "fetch_size": 100$%$#$#
+-- Invalid batch_size option
+CREATE FOREIGN TABLE inv_bsz (c1 int )
+ SERVER loopback OPTIONS (batch_size '100$%$#$#');
+ERROR: invalid value for integer option "batch_size": 100$%$#$#
+-- No option is allowed to be specified at foreign data wrapper level
+ALTER FOREIGN DATA WRAPPER postgres_fdw OPTIONS (nonexistent 'fdw');
+ERROR: invalid option "nonexistent"
+HINT: There are no valid options in this context.
+-- ===================================================================
+-- test postgres_fdw.application_name GUC
+-- ===================================================================
+--- Turn debug_discard_caches off for this test to make sure that
+--- the remote connection is alive when checking its application_name.
+SET debug_discard_caches = 0;
+-- Specify escape sequences in application_name option of a server
+-- object so as to test that they are replaced with status information
+-- expectedly.
+--
+-- Since pg_stat_activity.application_name may be truncated to less than
+-- NAMEDATALEN characters, note that substring() needs to be used
+-- at the condition of test query to make sure that the string consisting
+-- of database name and process ID is also less than that.
+ALTER SERVER loopback2 OPTIONS (application_name 'fdw_%d%p');
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_database() || pg_backend_pid() for
+ current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- postgres_fdw.application_name overrides application_name option
+-- of a server object if both settings are present.
+SET postgres_fdw.application_name TO 'fdw_%a%u%%';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('application_name') ||
+ CURRENT_USER || '%' for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- Test %c (session ID) and %C (cluster name) escape sequences.
+SET postgres_fdw.application_name TO 'fdw_%C%c';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('cluster_name') ||
+ to_hex(trunc(EXTRACT(EPOCH FROM (SELECT backend_start FROM
+ pg_stat_get_activity(pg_backend_pid()))))::integer) || '.' ||
+ to_hex(pg_backend_pid())
+ for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+--Clean up
+RESET postgres_fdw.application_name;
+RESET debug_discard_caches;
+-- ===================================================================
+-- test parallel commit
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (ADD parallel_commit 'true');
+ALTER SERVER loopback2 OPTIONS (ADD parallel_commit 'true');
+CREATE TABLE ploc1 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem1 (f1 int, f2 text)
+ SERVER loopback OPTIONS (table_name 'ploc1');
+CREATE TABLE ploc2 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem2 (f1 int, f2 text)
+ SERVER loopback2 OPTIONS (table_name 'ploc2');
+BEGIN;
+INSERT INTO prem1 VALUES (101, 'foo');
+INSERT INTO prem2 VALUES (201, 'bar');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+-----
+ 101 | foo
+(1 row)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+-----
+ 201 | bar
+(1 row)
+
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (102, 'foofoo');
+INSERT INTO prem2 VALUES (202, 'barbar');
+RELEASE SAVEPOINT s;
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+(2 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+(2 rows)
+
+-- This tests executing DEALLOCATE ALL against foreign servers in parallel
+-- during pre-commit
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (103, 'baz');
+INSERT INTO prem2 VALUES (203, 'qux');
+ROLLBACK TO SAVEPOINT s;
+RELEASE SAVEPOINT s;
+INSERT INTO prem1 VALUES (104, 'bazbaz');
+INSERT INTO prem2 VALUES (204, 'quxqux');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+ 104 | bazbaz
+(3 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+ 204 | quxqux
+(3 rows)
+
+ALTER SERVER loopback OPTIONS (DROP parallel_commit);
+ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- execute check function. This should return false on supported platforms,
+-- otherwise return true.
+SELECT postgres_fdw_verify_connection_states('loopback');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+(1 row)
+
+ABORT;
+WARNING: 08006
+\set VERBOSITY default
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index b0dbb41fb5..4450965b17 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3788,3 +3788,33 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+-- execute check function. This should return false on supported platforms,
+-- otherwise return true.
+SELECT postgres_fdw_verify_connection_states('loopback');
+ABORT;
+
+\set VERBOSITY default
+
+-- Clean up
+RESET debug_discard_caches;
--
2.27.0
Hi,
On 2022-11-25 11:41:45 +0000, Hayato Kuroda (Fujitsu) wrote:
Sorry for my late reply. I understood that we got agreement the basic design of first version. Thanks!
I attached new version patches.
This is failing on cfbot / CI, as have prior versions.
https://cirrus-ci.com/github/postgresql-cfbot/postgresql/commitfest%2F40%2F3388
diff -U3 /tmp/cirrus-ci-build/contrib/postgres_fdw/expected/postgres_fdw.out /tmp/cirrus-ci-build/build/testrun/postgres_fdw/regress/results/postgres_fdw.out
--- /tmp/cirrus-ci-build/contrib/postgres_fdw/expected/postgres_fdw.out 2022-12-06 05:21:33.906116000 +0000
+++ /tmp/cirrus-ci-build/build/testrun/postgres_fdw/regress/results/postgres_fdw.out 2022-12-06 05:27:24.929694000 +0000
@@ -11732,10 +11732,9 @@
-- execute check function. This should return false on supported platforms,
-- otherwise return true.
SELECT postgres_fdw_verify_connection_states('loopback');
-WARNING: 08006
postgres_fdw_verify_connection_states
---------------------------------------
- f
+ t
(1 row)
ABORT;
The failure happens everywhere except on linux, so presumably there's some
portability issue in the patch.
I've set the patch as waiting on author for now.
Note that you can test CI in your own repository, as explained in src/tools/ci/README
Greetings,
Andres Freund
Dear Andres,
This is failing on cfbot / CI, as have prior versions.
Thank you for notifying to me. I attached newer versions.
The failure happens everywhere except on linux, so presumably there's some
portability issue in the patch.
Yes, you are right. This feature can be used only for linux, and
previous patches seemed to have bad files.
Note that you can test CI in your own repository, as explained in
src/tools/ci/README
Thank you for your information. Actually I was in trouble because
I don't have such machines for developing postgres.
I have confirmed that newer patches could pass the test CI.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v20-0001-Add-PQConncheck-to-libpq.patchapplication/octet-stream; name=v20-0001-Add-PQConncheck-to-libpq.patchDownload
From 7d3b2c3f20da0f7b4460af9c6ea9916f049d051b Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:20 +0000
Subject: [PATCH v20 1/3] Add PQConncheck to libpq
This new libpq function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
---
doc/src/sgml/libpq.sgml | 24 ++++++++++++++++++
src/interfaces/libpq/exports.txt | 1 +
src/interfaces/libpq/fe-misc.c | 42 ++++++++++++++++++++++++++++++++
src/interfaces/libpq/libpq-fe.h | 3 +++
4 files changed, 70 insertions(+)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index f9558dec3b..d77c8d6f12 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,30 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQConncheck">
+ <term><function>PQConncheck</function><indexterm><primary>PQConncheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQConncheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQConncheck"/> returns <literal>1</literal>
+ if the remote peer seems to be closed, returns <literal>0</literal> if
+ the socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..3c4f946b51 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,4 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQConncheck 187
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 4159610f6c..e561b4e1ef 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -1218,6 +1218,48 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Helper function for PQconncheck().
+ *
+ * Return >0 if opposite side seems to be disconnected.
+ */
+static int
+pqConncheck_internal(int sock)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ struct pollfd input_fd;
+ int errflags = POLLHUP | POLLERR | POLLNVAL;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP | errflags;
+ input_fd.revents = 0;
+
+ poll(&input_fd, 1, 0);
+
+ return input_fd.revents & POLLRDHUP;
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad.
+ */
+int
+PQConncheck(PGconn *conn)
+{
+ /* quick exit if invalid connection has come */
+ if (conn == NULL ||
+ conn->sock == PGINVALID_SOCKET ||
+ conn->status != CONNECTION_OK)
+ return -1;
+
+ return pqConncheck_internal(conn->sock);
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index b7df3224c0..8b2d78f3ef 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,9 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQConncheck(PGconn *conn);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v20-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v20-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From 655fd1a387c79bd82fad90421ee18c1c99e6c00f Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:42 +0000
Subject: [PATCH v20 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQConncheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if checked connection is still valid, or the checking is
not supported on this platform. False is returned if the connection seems
to be closed.
---
contrib/postgres_fdw/connection.c | 100 ++++++++++++++++++
.../postgres_fdw/postgres_fdw--1.0--1.1.sql | 10 ++
doc/src/sgml/postgres-fdw.sgml | 49 +++++++++
3 files changed, 159 insertions(+)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index f0c45b00db..69959a0f12 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -86,6 +86,8 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -116,6 +118,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1862,3 +1865,100 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+
+ /* quick exit if connection cache has been not initialized yet. */
+ if (!ConnectionHash)
+ return true;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQConncheck(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so throw ereport(WARNING).
+ */
+ ForeignServer *server;
+
+ server = GetForeignServer(entry->serverid);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("could not connect to server \"%s\"",
+ server->servername),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of the server.")));
+
+ result = false;
+ }
+ }
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found, and this returns
+ * false only when the verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
diff --git a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
index ed4ca378d4..f1e2ee442f 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
@@ -18,3 +18,13 @@ CREATE FUNCTION postgres_fdw_disconnect_all ()
RETURNS bool
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 527f4deaaa..d535973237 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -790,6 +790,55 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if a checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports that
+ the connection is closed. This function is currently available only on
+ systems that support the non-standard <symbol>POLLRDHUP</symbol> extension
+ to the <symbol>poll</symbol> system call, including Linux. This returns
+ <literal>true</literal> if a lastly checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
</variablelist>
</sect2>
--
2.27.0
v20-0003-add-test.patchapplication/octet-stream; name=v20-0003-add-test.patchDownload
From 1a6a5f3c87f688dc198b3e6824031bee7b418c38 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v20 3/3] add test
Note that this test has two comparison files. Alternative comparison file is needed
because some platforms like Windows cannot check the status of the socket.
---
.../postgres_fdw/expected/postgres_fdw.out | 44 +
.../postgres_fdw/expected/postgres_fdw_1.out | 11744 ++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 30 +
3 files changed, 11818 insertions(+)
create mode 100644 contrib/postgres_fdw/expected/postgres_fdw_1.out
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 2ab3f1efaa..f88c7c69a3 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11699,3 +11699,47 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- execute check function. This should return false on supported platforms,
+-- otherwise return true.
+SELECT postgres_fdw_verify_connection_states('loopback');
+WARNING: 08006
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ f
+(1 row)
+
+ABORT;
+WARNING: 08006
+\set VERBOSITY default
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/expected/postgres_fdw_1.out b/contrib/postgres_fdw/expected/postgres_fdw_1.out
new file mode 100644
index 0000000000..12ba5a276a
--- /dev/null
+++ b/contrib/postgres_fdw/expected/postgres_fdw_1.out
@@ -0,0 +1,11744 @@
+-- ===================================================================
+-- create FDW objects
+-- ===================================================================
+CREATE EXTENSION postgres_fdw;
+CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw;
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback2 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback3 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+CREATE USER MAPPING FOR public SERVER testserver1
+ OPTIONS (user 'value', password 'value');
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback2;
+CREATE USER MAPPING FOR public SERVER loopback3;
+-- ===================================================================
+-- create objects used through FDW loopback server
+-- ===================================================================
+CREATE TYPE user_enum AS ENUM ('foo', 'bar', 'buz');
+CREATE SCHEMA "S 1";
+CREATE TABLE "S 1"."T 1" (
+ "C 1" int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10),
+ c8 user_enum,
+ CONSTRAINT t1_pkey PRIMARY KEY ("C 1")
+);
+CREATE TABLE "S 1"."T 2" (
+ c1 int NOT NULL,
+ c2 text,
+ CONSTRAINT t2_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 3" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t3_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 4" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t4_pkey PRIMARY KEY (c1)
+);
+-- Disable autovacuum for these tables to avoid unexpected effects of that
+ALTER TABLE "S 1"."T 1" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 2" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 3" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 4" SET (autovacuum_enabled = 'false');
+INSERT INTO "S 1"."T 1"
+ SELECT id,
+ id % 10,
+ to_char(id, 'FM00000'),
+ '1970-01-01'::timestamptz + ((id % 100) || ' days')::interval,
+ '1970-01-01'::timestamp + ((id % 100) || ' days')::interval,
+ id % 10,
+ id % 10,
+ 'foo'::user_enum
+ FROM generate_series(1, 1000) id;
+INSERT INTO "S 1"."T 2"
+ SELECT id,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+INSERT INTO "S 1"."T 3"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 3" WHERE c1 % 2 != 0; -- delete for outer join tests
+INSERT INTO "S 1"."T 4"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests
+ANALYZE "S 1"."T 1";
+ANALYZE "S 1"."T 2";
+ANALYZE "S 1"."T 3";
+ANALYZE "S 1"."T 4";
+-- ===================================================================
+-- create foreign tables
+-- ===================================================================
+CREATE FOREIGN TABLE ft1 (
+ c0 int,
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft1 DROP COLUMN c0;
+CREATE FOREIGN TABLE ft2 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ cx int,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft2',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft2 DROP COLUMN cx;
+CREATE FOREIGN TABLE ft4 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 3');
+CREATE FOREIGN TABLE ft5 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft6 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback2 OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft7 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback3 OPTIONS (schema_name 'S 1', table_name 'T 4');
+-- ===================================================================
+-- tests for validator
+-- ===================================================================
+-- requiressl and some other parameters are omitted because
+-- valid values for them depend on configure options
+ALTER SERVER testserver1 OPTIONS (
+ use_remote_estimate 'false',
+ updatable 'true',
+ fdw_startup_cost '123.456',
+ fdw_tuple_cost '0.123',
+ service 'value',
+ connect_timeout 'value',
+ dbname 'value',
+ host 'value',
+ hostaddr 'value',
+ port 'value',
+ --client_encoding 'value',
+ application_name 'value',
+ --fallback_application_name 'value',
+ keepalives 'value',
+ keepalives_idle 'value',
+ keepalives_interval 'value',
+ tcp_user_timeout 'value',
+ -- requiressl 'value',
+ sslcompression 'value',
+ sslmode 'value',
+ sslcert 'value',
+ sslkey 'value',
+ sslrootcert 'value',
+ sslcrl 'value',
+ --requirepeer 'value',
+ krbsrvname 'value',
+ gsslib 'value'
+ --replication 'value'
+);
+-- Error, invalid list syntax
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo; bar');
+ERROR: parameter "extensions" must be a list of extension names
+-- OK but gets a warning
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo, bar');
+WARNING: extension "foo" is not installed
+WARNING: extension "bar" is not installed
+ALTER SERVER testserver1 OPTIONS (DROP extensions);
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (DROP user, DROP password);
+-- Attempt to add a valid option that's not allowed in a user mapping
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslmode 'require');
+ERROR: invalid option "sslmode"
+-- But we can add valid ones fine
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslpassword 'dummy');
+-- Ensure valid options we haven't used in a user mapping yet are
+-- permitted to check validation.
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslkey 'value', ADD sslcert 'value');
+ALTER FOREIGN TABLE ft1 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft2 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+ALTER FOREIGN TABLE ft2 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+\det+
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------+-------+-----------+---------------------------------------+-------------
+ public | ft1 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft2 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft4 | loopback | (schema_name 'S 1', table_name 'T 3') |
+ public | ft5 | loopback | (schema_name 'S 1', table_name 'T 4') |
+ public | ft6 | loopback2 | (schema_name 'S 1', table_name 'T 4') |
+ public | ft7 | loopback3 | (schema_name 'S 1', table_name 'T 4') |
+(6 rows)
+
+-- Test that alteration of server options causes reconnection
+-- Remote's errors might be non-English, so hide them to ensure stable results
+\set VERBOSITY terse
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET dbname 'no such database');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+DO $d$
+ BEGIN
+ EXECUTE $$ALTER SERVER loopback
+ OPTIONS (SET dbname '$$||current_database()||$$')$$;
+ END;
+$d$;
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+-- Test that alteration of user mapping options causes reconnection
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (ADD user 'no such user');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (DROP user);
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+\set VERBOSITY default
+-- Now we should be able to run ANALYZE.
+-- To exercise multiple code paths, we use local stats on ft1
+-- and remote-estimate mode on ft2.
+ANALYZE ft1;
+ALTER FOREIGN TABLE ft2 OPTIONS (use_remote_estimate 'true');
+-- ===================================================================
+-- test error case for create publication on foreign table
+-- ===================================================================
+CREATE PUBLICATION testpub_ftbl FOR TABLE ft1; -- should fail
+ERROR: cannot add relation "ft1" to publication
+DETAIL: This operation is not supported for foreign tables.
+-- ===================================================================
+-- simple queries
+-- ===================================================================
+-- single table without alias
+EXPLAIN (COSTS OFF) SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------
+ Foreign Scan on ft1
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- single table with alias - also test that tableoid sort is not pushed to remote side
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ -> Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Sort Key: t1.c3, t1.c1, t1.tableoid
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(8 rows)
+
+SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF) SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: t1.*, c3, c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c3 ASC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(3 rows)
+
+SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ t1
+--------------------------------------------------------------------------------------------
+ (101,1,00101,"Fri Jan 02 00:00:00 1970 PST","Fri Jan 02 00:00:00 1970",1,"1 ",foo)
+ (102,2,00102,"Sat Jan 03 00:00:00 1970 PST","Sat Jan 03 00:00:00 1970",2,"2 ",foo)
+ (103,3,00103,"Sun Jan 04 00:00:00 1970 PST","Sun Jan 04 00:00:00 1970",3,"3 ",foo)
+ (104,4,00104,"Mon Jan 05 00:00:00 1970 PST","Mon Jan 05 00:00:00 1970",4,"4 ",foo)
+ (105,5,00105,"Tue Jan 06 00:00:00 1970 PST","Tue Jan 06 00:00:00 1970",5,"5 ",foo)
+ (106,6,00106,"Wed Jan 07 00:00:00 1970 PST","Wed Jan 07 00:00:00 1970",6,"6 ",foo)
+ (107,7,00107,"Thu Jan 08 00:00:00 1970 PST","Thu Jan 08 00:00:00 1970",7,"7 ",foo)
+ (108,8,00108,"Fri Jan 09 00:00:00 1970 PST","Fri Jan 09 00:00:00 1970",8,"8 ",foo)
+ (109,9,00109,"Sat Jan 10 00:00:00 1970 PST","Sat Jan 10 00:00:00 1970",9,"9 ",foo)
+ (110,0,00110,"Sun Jan 11 00:00:00 1970 PST","Sun Jan 11 00:00:00 1970",0,"0 ",foo)
+(10 rows)
+
+-- empty result
+SELECT * FROM ft1 WHERE false;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- with WHERE clause
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c7 >= '1')) AND (("C 1" = 101)) AND ((c6 = '1'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- with FOR UPDATE/SHARE
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 101)) FOR UPDATE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 102)) FOR SHARE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+-- aggregate
+SELECT COUNT(*) FROM ft1 t1;
+ count
+-------
+ 1000
+(1 row)
+
+-- subquery
+SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- subquery+MAX
+SELECT * FROM ft1 t1 WHERE t1.c3 = (SELECT MAX(c3) FROM ft2 t2) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+(1 row)
+
+-- used in CTE
+WITH t1 AS (SELECT * FROM ft1 WHERE c1 <= 10) SELECT t2.c1, t2.c2, t2.c3, t2.c4 FROM t1, ft2 t2 WHERE t1.c1 = t2.c1 ORDER BY t1.c1;
+ c1 | c2 | c3 | c4
+----+----+-------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+(10 rows)
+
+-- fixed values
+SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1;
+ ?column? | ?column?
+----------+----------
+ fixed |
+(1 row)
+
+-- Test forcing the remote server to produce sorted data for a merge join.
+SET enable_hashjoin TO false;
+SET enable_nestloop TO false;
+-- inner join; expressions in the clauses appear in the equivalence class list
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Left Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- A join between local table and foreign join. ORDER BY clause is added to the
+-- foreign join so that the local table can be joined using merge join strategy.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Merge Right Join
+ Output: t1."C 1"
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r3."C 1" FROM ("S 1"."T 1" r2 INNER JOIN "S 1"."T 1" r3 ON (((r3."C 1" = r2."C 1")))) ORDER BY r2."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- Test similar to above, except that the full join prevents any equivalence
+-- classes from being merged. This produces single relation equivalence classes
+-- included in join restrictions.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Right Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1, t2.c1
+ Relations: (public.ft2 t3) LEFT JOIN (public.ft1 t2)
+ Remote SQL: SELECT r3."C 1", r2."C 1" FROM ("S 1"."T 1" r3 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+-- Test similar to above with all full outer joins
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Full Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) FULL JOIN (public.ft2 t3)
+ Remote SQL: SELECT r2."C 1", r3."C 1" FROM ("S 1"."T 1" r2 FULL JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test executing assertion in estimate_path_cost_size() that makes sure that
+-- retrieved_rows for foreign rel re-used to cost pre-sorted foreign paths is
+-- a sensible value even when the rel has tuples=0
+CREATE TABLE loct_empty (c1 int NOT NULL, c2 text);
+CREATE FOREIGN TABLE ft_empty (c1 int NOT NULL, c2 text)
+ SERVER loopback OPTIONS (table_name 'loct_empty');
+INSERT INTO loct_empty
+ SELECT id, 'AAA' || to_char(id, 'FM000') FROM generate_series(1, 100) id;
+DELETE FROM loct_empty;
+ANALYZE ft_empty;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Foreign Scan on public.ft_empty
+ Output: c1, c2
+ Remote SQL: SELECT c1, c2 FROM public.loct_empty ORDER BY c1 ASC NULLS LAST
+(3 rows)
+
+-- ===================================================================
+-- WHERE with remotely-executable conditions
+-- ===================================================================
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1; -- Var, OpExpr(b), Const
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL; -- NullTest
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL; -- NullTest
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((round(abs("C 1"), 0) = 1::numeric))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1; -- OpExpr(l)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = (- "C 1")))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" IS NOT NULL) IS DISTINCT FROM ("C 1" IS NOT NULL)))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]); -- ScalarArrayOpExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ANY (ARRAY[c2, 1, ("C 1" + 0)])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1]; -- SubscriptingRef
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ((ARRAY["C 1", c2, 3])[1])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar'; -- check special chars
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c6 = E'foo''s\\bar'))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c8 = 'foo'; -- can't be sent to remote
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- parameterized remote path for foreign table
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM "S 1"."T 1" a, ft2 b WHERE a."C 1" = 47 AND b.c1 = a.c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Index Scan using t1_pkey on "S 1"."T 1" a
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Index Cond: (a."C 1" = 47)
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(8 rows)
+
+SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 47 | 7 | 00047 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo | 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+(1 row)
+
+-- check both safe and unsafe join conditions
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 a, ft2 b
+ WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Foreign Scan on public.ft2 a
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Filter: (a.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c2 = 6))
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Filter: ((b.c7)::text = upper((a.c7)::text))
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(10 rows)
+
+SELECT * FROM ft2 a, ft2 b
+WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+(100 rows)
+
+-- bug before 9.3.5 due to sloppy handling of remote-estimate parameters
+SELECT * FROM ft1 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft2 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+SELECT * FROM ft2 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft1 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+-- we should not push order by clause with volatile expressions or unsafe
+-- collations
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, random();
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, (random())
+ Sort Key: ft2.c1, (random())
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, random()
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, ft2.c3 collate "C";
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, ((c3)::text)
+ Sort Key: ft2.c1, ft2.c3 COLLATE "C"
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- user-defined operator/function
+CREATE FUNCTION postgres_fdw_abs(int) RETURNS int AS $$
+BEGIN
+RETURN abs($1);
+END
+$$ LANGUAGE plpgsql IMMUTABLE;
+CREATE OPERATOR === (
+ LEFTARG = int,
+ RIGHTARG = int,
+ PROCEDURE = int4eq,
+ COMMUTATOR = ===
+);
+-- built-in operators and functions can be shipped for remote execution
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ QUERY PLAN
+----------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- by default, user-defined ones cannot
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 = postgres_fdw_abs(t1.c2))
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- ORDER BY can be shipped, though
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- but let's put them in an extension ...
+ALTER EXTENSION postgres_fdw ADD FUNCTION postgres_fdw_abs(int);
+ALTER EXTENSION postgres_fdw ADD OPERATOR === (int, int);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- ... now they can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- and both ORDER BY and LIMIT can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2)) ORDER BY c2 ASC NULLS LAST LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- Test CASE pushdown
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE WHEN ("C 1" > 990) THEN "C 1" ELSE NULL::integer END) < 1000)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ c1 | c2 | c3
+-----+----+-------
+ 991 | 1 | 00991
+ 992 | 2 | 00992
+ 993 | 3 | 00993
+ 994 | 4 | 00994
+ 995 | 5 | 00995
+ 996 | 6 | 00996
+ 997 | 7 | 00997
+ 998 | 8 | 00998
+ 999 | 9 | 00999
+(9 rows)
+
+-- Nested CASE
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE (CASE WHEN (c2 > 0) THEN c2 ELSE NULL::integer END) WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END) > 600)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ c1 | c2 | c3
+----+----+----
+(0 rows)
+
+-- CASE arg WHEN
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE mod(c1, 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" > (CASE mod("C 1", 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)))
+(3 rows)
+
+-- CASE cannot be pushed down because of unshippable arg clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE random()::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (ft1.c1 > CASE (random())::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- these are shippable
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c6 WHEN 'foo' THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c6 WHEN 'foo'::text THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c3 WHEN c6 THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+-- but this is not because of collation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 COLLATE "C" WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: CASE (ft1.c3)::text WHEN ft1.c6 THEN true ELSE (ft1.c3 < 'bar'::text) END
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- a regconfig constant referring to this text search configuration
+-- is initially unshippable
+CREATE TEXT SEARCH CONFIGURATION public.custom_search
+ (COPY = pg_catalog.english);
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Filter: (length(to_tsvector('custom_search'::regconfig, ft1.c3)) > 0)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642))
+(4 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- but if it's in a shippable extension, it can be shipped
+ALTER EXTENSION postgres_fdw ADD TEXT SEARCH CONFIGURATION public.custom_search;
+-- however, that doesn't flush the shippability cache, so do a quick reconnect
+\c -
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642)) AND ((length(to_tsvector('public.custom_search'::regconfig, c3)) > 0))
+(3 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- ===================================================================
+-- JOIN queries
+-- ===================================================================
+-- Analyze ft4 and ft5 so that we have better statistics. These tables do not
+-- have use_remote_estimate set.
+ANALYZE ft4;
+ANALYZE ft5;
+-- join two tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3, t1.c3
+ Relations: ((public.ft1 t1) INNER JOIN (public.ft2 t2)) INNER JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3, r1.c3 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) INNER JOIN "S 1"."T 3" r4 ON (((r1."C 1" = r4.c1)))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 22 |
+ 24 | 24
+ 26 |
+ 28 |
+ 30 | 30
+ 32 |
+ 34 |
+ 36 | 36
+ 38 |
+ 40 |
+(10 rows)
+
+-- left outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + placement of clauses.
+-- clauses within the nullable side are not pulled up, but top level clause on
+-- non-nullable side is pushed into non-nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- clauses within the nullable side are not pulled up, but the top level clause
+-- on nullable side is not pushed down into nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE (((r4.c1 < 10) OR (r4.c1 IS NULL))) AND ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t2) LEFT JOIN (public.ft5 t1)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r1 ON (((r1.c1 = r2.c1)))) ORDER BY r2.c1 ASC NULLS LAST, r1.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ | 22
+ 24 | 24
+ | 26
+ | 28
+ 30 | 30
+ | 32
+ | 34
+ 36 | 36
+ | 38
+ | 40
+(10 rows)
+
+-- right outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 45::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ c1 | c1
+-----+----
+ 92 |
+ 94 |
+ 96 | 96
+ 98 |
+ 100 |
+ | 3
+ | 9
+ | 15
+ | 21
+ | 27
+(10 rows)
+
+-- full outer join with restrictions on the joining relations
+-- a. the joining relations are both base relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s4.c1, s5.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s5.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ c1 | c1
+----+----
+ 50 |
+ 52 |
+ 54 | 54
+ 56 |
+ 58 |
+ 60 | 60
+ | 51
+ | 57
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: 1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT NULL FROM ((SELECT NULL FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4 FULL JOIN (SELECT NULL FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5 ON (TRUE)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ ?column?
+----------
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- b. one of the joining relations is a base relation and the other is a join
+-- relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c1, t3.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 t2) LEFT JOIN (public.ft5 t3))
+ Remote SQL: SELECT s4.c1, s8.c1, s8.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT r5.c1, r6.c1 FROM ("S 1"."T 3" r5 LEFT JOIN "S 1"."T 4" r6 ON (((r5.c1 = r6.c1)))) WHERE ((r5.c1 >= 50)) AND ((r5.c1 <= 60))) s8(c1, c2) ON (((s4.c1 = s8.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s8.c1 ASC NULLS LAST, s8.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+(6 rows)
+
+-- c. test deparsing the remote query as nested subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft4_1.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 ft4_1) FULL JOIN (public.ft5))
+ Remote SQL: SELECT s4.c1, s10.c1, s10.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT s8.c1, s9.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL)))) s10(c1, c2) ON (((s4.c1 = s10.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s10.c1 ASC NULLS LAST, s10.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+ | | 51
+ | | 57
+(8 rows)
+
+-- d. test deparsing rowmarked relations as subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Nested Loop
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Foreign Scan
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s8.c1, s8.c2, s9.c1, s9.c2 FROM ((SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1, c2) FULL JOIN (SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1, c2) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL))) ORDER BY s8.c1 ASC NULLS LAST, s9.c1 ASC NULLS LAST
+ -> Sort
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Full Join
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Hash Cond: (ft4.c1 = ft5.c1)
+ Filter: ((ft4.c1 IS NULL) OR (ft4.c1 IS NOT NULL))
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Hash
+ Output: ft5.c1, ft5.*
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Materialize
+ Output: "T 3".c1, "T 3".ctid
+ -> Seq Scan on "S 1"."T 3"
+ Output: "T 3".c1, "T 3".ctid
+ Filter: ("T 3".c1 = 50)
+(28 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 50 | 52 |
+ 50 | 54 | 54
+ 50 | 56 |
+ 50 | 58 |
+ 50 | 60 | 60
+ 50 | | 51
+ 50 | | 57
+(8 rows)
+
+-- full outer join + inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t3.c1
+ Relations: ((public.ft4 t1) INNER JOIN (public.ft5 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1.c1, r2.c1, r4.c1 FROM (("S 1"."T 3" r1 INNER JOIN "S 1"."T 4" r2 ON (((r1.c1 = (r2.c1 + 1))) AND ((r1.c1 >= 50)) AND ((r1.c1 <= 60)))) FULL JOIN "S 1"."T 3" r4 ON (((r2.c1 = r4.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST, r4.c1 ASC NULLS LAST LIMIT 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ c1 | c1 | c1
+----+----+----
+ 52 | 51 |
+ 58 | 57 |
+ | | 2
+ | | 4
+ | | 6
+ | | 8
+ | | 10
+ | | 12
+ | | 14
+ | | 16
+(10 rows)
+
+-- full outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- right outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+SET enable_memoize TO off;
+-- right outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+RESET enable_memoize;
+-- left outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: (public.ft4 t3) LEFT JOIN ((public.ft2 t1) INNER JOIN (public.ft2 t2))
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM ("S 1"."T 3" r4 LEFT JOIN ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join + WHERE clause, only matched rows
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 = r2.c1) OR (r1.c1 IS NULL)))
+(9 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 66 | 66
+ 72 | 72
+ 78 | 78
+ 84 | 84
+ 90 | 90
+ 96 | 96
+ | 3
+ | 9
+ | 15
+ | 21
+(10 rows)
+
+-- full outer join + WHERE clause with shippable extensions set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) WHERE ((public.postgres_fdw_abs(r1."C 1") > 0)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+-- full outer join + WHERE clause with shippable extensions not set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c2, t1.c3
+ -> Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Filter: (postgres_fdw_abs(t1.c1) > 0)
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- join two tables with FOR UPDATE clause
+-- tests whole-row reference for row marks
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1 FOR UPDATE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join two tables with FOR SHARE clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1 FOR SHARE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join in CTE
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t.c1_1, t.c2_1, t.c1_3
+ CTE t
+ -> Foreign Scan
+ Output: t1.c1, t1.c3, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r1.c3, r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+ -> Sort
+ Output: t.c1_1, t.c2_1, t.c1_3
+ Sort Key: t.c1_3, t.c1_1
+ -> CTE Scan on t
+ Output: t.c1_1, t.c2_1, t.c1_3
+(12 rows)
+
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ c1_1 | c2_1
+------+------
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- ctid with whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.ctid, t1.*, t2.*, t1.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r1."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+-- SEMI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Semi Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c1)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- ANTI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Anti Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c2)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 110
+ 111
+ 112
+ 113
+ 114
+ 115
+ 116
+ 117
+ 118
+ 119
+(10 rows)
+
+-- CROSS JOIN can be pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (TRUE)) ORDER BY r1."C 1" ASC NULLS LAST, r2."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- different server, not pushed down. No result expected.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Merge Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft6 t2
+ Output: t2.c1, t2.c2, t2.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+ -> Materialize
+ Output: t1.c1, t1.c2, t1.c3
+ -> Foreign Scan on public.ft5 t1
+ Output: t1.c1, t1.c2, t1.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+(13 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+----
+(0 rows)
+
+-- unsafe join conditions (c8 has a UDT), not pushed down. Practically a CROSS
+-- JOIN since c8 in both tables has same value.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Merge Left Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t1.c8 = t2.c8)
+ -> Sort
+ Output: t1.c1, t1.c8
+ Sort Key: t1.c8
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+ -> Sort
+ Output: t2.c1, t2.c8
+ Sort Key: t2.c8
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1, t2.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+(20 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- unsafe conditions on one side (c8 has a UDT), not pushed down.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Hash Right Join
+ Output: t1.c1, t2.c1, t1.c3
+ Hash Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+ -> Hash
+ Output: t1.c1, t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c3
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c3, c8 FROM "S 1"."T 1"
+(17 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join where unsafe to pushdown condition in WHERE clause has a column not
+-- in the SELECT clause. In this test unsafe clause needs to have column
+-- references from both joining sides so that the clause is not pushed down
+-- into one of the joining sides.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Filter: (t1.c8 = t2.c8)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, r1.c8, r2.c8 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(10 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- Aggregate after UNION, for testing setrefs
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ -> Sort
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ Sort Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, avg((t1.c1 + t2.c1))
+ Group Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, t2.c1
+ Group Key: t1.c1, t2.c1
+ -> Append
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+ -> Foreign Scan
+ Output: t1_1.c1, t2_1.c1
+ Relations: (public.ft1 t1_1) INNER JOIN (public.ft2 t2_1)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(20 rows)
+
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ t1c1 | avg
+------+----------------------
+ 101 | 202.0000000000000000
+ 102 | 204.0000000000000000
+ 103 | 206.0000000000000000
+ 104 | 208.0000000000000000
+ 105 | 210.0000000000000000
+ 106 | 212.0000000000000000
+ 107 | 214.0000000000000000
+ 108 | 216.0000000000000000
+ 109 | 218.0000000000000000
+ 110 | 220.0000000000000000
+(10 rows)
+
+-- join with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Nested Loop
+ Output: t1."C 1"
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ -> Memoize
+ Cache Key: t1.c2
+ Cache Mode: binary
+ -> Subquery Scan on q
+ -> HashAggregate
+ Output: t2.c1, t3.c1
+ Group Key: t2.c1, t3.c1
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")) AND ((r1.c2 = $1::integer))))
+(17 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ C 1
+-----
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- non-Var items in targetlist of the nullable rel of a join preventing
+-- push-down in some cases
+-- unable to push {ft1, ft2}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: (13), ft2.c1
+ Join Filter: (13 = ft2.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" WHERE (("C 1" >= 10)) AND (("C 1" <= 15)) ORDER BY "C 1" ASC NULLS LAST
+ -> Materialize
+ Output: (13)
+ -> Foreign Scan on public.ft1
+ Output: 13
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 13))
+(11 rows)
+
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ a | c1
+----+----
+ | 10
+ | 11
+ | 12
+ 13 | 13
+ | 14
+ | 15
+(6 rows)
+
+-- ok to push {ft1, ft2} but not {ft1, ft2, ft4}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: ft4.c1, (13), ft1.c1, ft2.c1
+ Join Filter: (ft4.c1 = ft1.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
+ -> Materialize
+ Output: ft1.c1, ft2.c1, (13)
+ -> Foreign Scan
+ Output: ft1.c1, ft2.c1, 13
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r5."C 1" FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = 12)) AND ((r4."C 1" = 12)))) ORDER BY r4."C 1" ASC NULLS LAST
+(12 rows)
+
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ c1 | a | b | c
+----+----+----+----
+ 10 | | |
+ 12 | 13 | 12 | 12
+ 14 | | |
+(3 rows)
+
+-- join with nullable side with some columns with null values
+UPDATE ft5 SET c3 = null where c1 % 9 = 0;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2
+ Relations: (public.ft5) INNER JOIN (public.ft4)
+ Remote SQL: SELECT CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1.c1, r1.c2, r1.c3) END, r1.c1, r1.c2, r1.c3, r2.c1, r2.c2 FROM ("S 1"."T 4" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c1 = r2.c1)) AND ((r2.c1 >= 10)) AND ((r2.c1 <= 30)))) ORDER BY r1.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ ft5 | c1 | c2 | c3 | c1 | c2
+----------------+----+----+--------+----+----
+ (12,13,AAA012) | 12 | 13 | AAA012 | 12 | 13
+ (18,19,) | 18 | 19 | | 18 | 19
+ (24,25,AAA024) | 24 | 25 | AAA024 | 24 | 25
+ (30,31,AAA030) | 30 | 31 | AAA030 | 30 | 31
+(4 rows)
+
+-- multi-way join involving multiple merge joins
+-- (this case used to have EPQ-related planning problems)
+CREATE TABLE local_tbl (c1 int NOT NULL, c2 int NOT NULL, c3 text, CONSTRAINT local_tbl_pkey PRIMARY KEY (c1));
+INSERT INTO local_tbl SELECT id, id % 10, to_char(id, 'FM0000') FROM generate_series(1, 1000) id;
+ANALYZE local_tbl;
+SET enable_nestloop TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ Inner Unique: true
+ Merge Cond: (ft1.c2 = local_tbl.c1)
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Relations: (((public.ft1) INNER JOIN (public.ft2)) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r3.c1, r3.c2, r3.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r4.c1, r4.c2, r4.c3, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4.c1, r4.c2, r4.c3) END FROM ((("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")) AND ((r2."C 1" < 100)) AND ((r1."C 1" < 100)))) INNER JOIN "S 1"."T 3" r3 ON (((r1.c2 = r3.c1)))) INNER JOIN "S 1"."T 4" r4 ON (((r1.c2 = r4.c1)))) ORDER BY r1.c2 ASC NULLS LAST FOR UPDATE OF r1 FOR UPDATE OF r2 FOR UPDATE OF r3 FOR UPDATE OF r4
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Merge Cond: (ft1.c2 = ft5.c1)
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Merge Cond: (ft1.c2 = ft4.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Sort Key: ft1.c2
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Merge Cond: (ft1.c1 = ft2.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) FOR UPDATE
+ -> Materialize
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Sort
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Sort Key: ft4.c1
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" FOR UPDATE
+ -> Sort
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Sort Key: ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" FOR UPDATE
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+(47 rows)
+
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3 | c1 | c2 | c3
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+--------+----+----+--------+----+----+------
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+(10 rows)
+
+RESET enable_nestloop;
+RESET enable_hashjoin;
+-- test that add_paths_with_pathkeys_for_rel() arranges for the epq_path to
+-- return columns needed by the parent ForeignScan node
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.*, COALESCE(ft1.c3 || ft2.c3, 'foobar') FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100)) ss ON (local_tbl.c1 = ss.c1) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ -> Merge Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ Merge Cond: (local_tbl.c1 = ft1.c1)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text))
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c3 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = r4."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4."C 1" ASC NULLS LAST
+ -> Result
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c3
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), ft2.c3
+ Sort Key: ft1.c1
+ -> Hash Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text), ft2.c3
+ Hash Cond: (ft1.c1 = ft2.c1)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Hash
+ Output: ft2.*, ft2.c1, ft2.c3
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(29 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD fdw_startup_cost '10000.0');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.* FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100 AND ft1.c1 = postgres_fdw_abs(ft2.c2))) ss ON (local_tbl.c3 = ss.c3) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ -> Nested Loop Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ Join Filter: (local_tbl.c3 = ft1.c3)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ Filter: (ft1.c1 = postgres_fdw_abs(ft2.c2))
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c2 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = r4."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4.c3 ASC NULLS LAST
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Sort Key: ft1.c3
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Merge Cond: ((ft1.c1 = (postgres_fdw_abs(ft2.c2))) AND (ft1.c1 = ft2.c1))
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Sort
+ Output: ft2.*, ft2.c1, ft2.c2, (postgres_fdw_abs(ft2.c2))
+ Sort Key: (postgres_fdw_abs(ft2.c2)), ft2.c1
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, postgres_fdw_abs(ft2.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(32 rows)
+
+ALTER SERVER loopback OPTIONS (DROP fdw_startup_cost);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+DROP TABLE local_tbl;
+-- check join pushdown in situations where multiple userids are involved
+CREATE ROLE regress_view_owner SUPERUSER;
+CREATE USER MAPPING FOR regress_view_owner SERVER loopback;
+GRANT SELECT ON ft4 TO regress_view_owner;
+GRANT SELECT ON ft5 TO regress_view_owner;
+CREATE VIEW v4 AS SELECT * FROM ft4;
+CREATE VIEW v5 AS SELECT * FROM ft5;
+ALTER VIEW v5 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, different view owners
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, ft5.c2, ft5.c1
+ -> Sort
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Left Join
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.c2, ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c2, ft5.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r6.c1, r9.c2, r9.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r9 ON (((r6.c1 = r9.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r9.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, view owner not current user
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, t2.c2, t2.c1
+ -> Sort
+ Output: ft4.c1, t2.c2, t2.c1
+ Sort Key: ft4.c1, t2.c1
+ -> Hash Left Join
+ Output: ft4.c1, t2.c2, t2.c1
+ Hash Cond: (ft4.c1 = t2.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: t2.c2, t2.c1
+ -> Foreign Scan on public.ft5 t2
+ Output: t2.c2, t2.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO CURRENT_USER;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c2, t2.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r6.c1, r2.c2, r2.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r2 ON (((r6.c1 = r2.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+-- cleanup
+DROP OWNED BY regress_view_owner;
+DROP ROLE regress_view_owner;
+-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+------+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+ 100 | 49700 | 497.0000000000000000 | 2 | 992 | 0 | 49700
+ 100 | 49800 | 498.0000000000000000 | 3 | 993 | 0 | 49800
+ 100 | 49900 | 499.0000000000000000 | 4 | 994 | 0 | 49900
+ 100 | 50500 | 505.0000000000000000 | 0 | 1000 | 0 | 50500
+(5 rows)
+
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST LIMIT 1::bigint
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+-----+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+(1 row)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * (random() <= 1)::int) as sum, avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Aggregate
+ Output: sum((c1 * ((random() <= '1'::double precision))::integer)), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT count(*), sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ count | sum | avg
+-------+---------+----------------------
+ 10000 | 5010000 | 501.0000000000000000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where ((t1.c1 * t2.c1)/(t1.c1 * t2.c1)) * random() <= 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(t1.c1), count(t2.c1)
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Filter: (((((t1.c1 * t2.c1) / (t1.c1 * t2.c1)))::double precision * random()) <= '1'::double precision)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(7 rows)
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY 1 ORDER BY (c2 / 2) ASC NULLS LAST
+(4 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 500
+ 2 | 1800
+ 3 | 3900
+ 4 | 6800
+(5 rows)
+
+-- Aggregates in subquery are pushed down.
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 ORDER BY c2 ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(6 rows)
+
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+------
+ 1000 | 4500
+(1 row)
+
+-- Aggregate is still pushed down by taking unshippable expression out
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer)), ((sum(c1) * c2)), c2
+ Sort Key: ((ft1.c2 * ((random() <= '1'::double precision))::integer)), ((sum(ft1.c1) * ft1.c2))
+ -> Foreign Scan
+ Output: (c2 * ((random() <= '1'::double precision))::integer), ((sum(c1) * c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum("C 1") * c2), c2 FROM "S 1"."T 1" GROUP BY 2
+(7 rows)
+
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ sum1 | sum2
+------+--------
+ 0 | 0
+ 1 | 49600
+ 2 | 99400
+ 3 | 149400
+ 4 | 199600
+ 5 | 250000
+ 6 | 300600
+ 7 | 351400
+ 8 | 402400
+ 9 | 453600
+(10 rows)
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::int order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Sort Key: ((ft2.c2 * ((random() <= '1'::double precision))::integer))
+ -> HashAggregate
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Group Key: (ft2.c2 * ((random() <= '1'::double precision))::integer)
+ -> Foreign Scan on public.ft2
+ Output: (c2 * ((random() <= '1'::double precision))::integer)
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- GROUP BY clause in various forms, cardinal, alias and constant expression
+explain (verbose, costs off)
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), c2, 5, 7.0, 9 FROM "S 1"."T 1" GROUP BY 2, 3, 5
+(7 rows)
+
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ w | x | y | z
+-----+---+---+-----
+ 100 | 0 | 5 | 7.0
+ 100 | 1 | 5 | 7.0
+ 100 | 2 | 5 | 7.0
+ 100 | 3 | 5 | 7.0
+ 100 | 4 | 5 | 7.0
+ 100 | 5 | 5 | 7.0
+ 100 | 6 | 5 | 7.0
+ 100 | 7 | 5 | 7.0
+ 100 | 8 | 5 | 7.0
+ 100 | 9 | 5 | 7.0
+(10 rows)
+
+-- GROUP BY clause referring to same column multiple times
+-- Also, ORDER BY contains an aggregate function
+explain (verbose, costs off)
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, c2, (sum(c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, c2, sum("C 1") FROM "S 1"."T 1" WHERE ((c2 > 6)) GROUP BY 1, 2 ORDER BY sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ c2 | c2
+----+----
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(3 rows)
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 49800)) ORDER BY c2 ASC NULLS LAST
+(4 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ c2 | sum
+----+-------
+ 1 | 49600
+ 2 | 49700
+(2 rows)
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, NULL::bigint, (sqrt((ft1.c2)::double precision))
+ Filter: (((((avg(ft1.c1)) / (avg(ft1.c1))))::double precision * random()) <= '1'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ count
+-------
+ 49
+(1 row)
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * (random() <= 1)::int) > 100 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1)), c2
+ Sort Key: (sum(ft1.c1))
+ -> HashAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Filter: (avg((ft1.c1 * ((random() <= '1'::double precision))::integer)) > '100'::numeric)
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(10 rows)
+
+-- Remote aggregate in combination with a local Param (for the output
+-- of an initplan) can be trouble, per bug #15781
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ QUERY PLAN
+--------------------------------------------------
+ Foreign Scan
+ Output: $0, (sum(ft1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1"
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+(6 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ QUERY PLAN
+---------------------------------------------------
+ GroupAggregate
+ Output: ($0), sum(ft1.c1)
+ Group Key: $0
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+ -> Foreign Scan on public.ft1
+ Output: $0, ft1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(8 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY 2 ORDER BY array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1,11,21,31,41,51,61,71,81,91}
+ {2,12,22,32,42,52,62,72,82,92}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {5,15,25,35,45,55,65,75,85,95}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+(10 rows)
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5)) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY 2 ORDER BY sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))) ASC NULLS LAST
+(4 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+(10 rows)
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3) ORDER BY (("C 1" % 3)) ASC NULLS LAST) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY 3
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft2 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where (c1 / c1) * random() <= 1) from ft1 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((((ft1.c1 / ft1.c1))::double precision * random()) <= '1'::double precision)))
+ -> HashAggregate
+ Output: sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST), percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
+(7 rows)
+
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | rank | percentile_cont
+----+------+-----------------
+ 0 | 101 | 10
+ 1 | 101 | 100
+ 2 | 1 | 200
+ 3 | 1 | 300
+ 4 | 1 | 400
+(5 rows)
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY 1, 3
+(4 rows)
+
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ c1 | rank
+----+------
+ 6 | 1
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Disable hash aggregation for plan stability.
+set enable_hashagg to false;
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY 1
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 0 | 10
+ 1 | 1
+ 2 | 2
+ 3 | 3
+ 4 | 4
+ 5 | 5
+ 6 | 6
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(10 rows)
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Cleanup
+reset enable_hashagg;
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+create operator family my_op_family using btree;
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- This should not be pushed either.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- Update local stats on ft2
+ANALYZE ft2;
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now this will be pushed as sort operator is part of the extension.
+alter server loopback options (add fdw_tuple_cost '0.5');
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY 2
+(4 rows)
+
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+alter server loopback options (drop fdw_tuple_cost);
+-- This should be pushed too.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST
+(3 rows)
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft2 t1 left join ft2 t2 on (t1.c1 = random() * t2.c2);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop Left Join
+ Output: t1.c3
+ Join Filter: ((t1.c1)::double precision = (random() * (t2.c2)::double precision))
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c3, t1.c1
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1"
+ -> Materialize
+ Output: t2.c2
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(13 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Inner Unique: true
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1 ft1_1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1
+(21 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 100 | 49600
+ 100 | 49700
+ 100 | 49800
+ 100 | 49900
+ 100 | 50000
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(10 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY 3 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL))) ORDER BY avg(r1.c1) ASC NULLS LAST, sum(r2.c1) ASC NULLS LAST
+(4 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- Aggregate over FULL join needing to deparse the joining relations as
+-- subqueries.
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(ft4.c1)), (avg(ft5.c1))
+ Relations: Aggregate on ((public.ft4) FULL JOIN (public.ft5))
+ Remote SQL: SELECT count(*), sum(s4.c1), avg(s5.c1) FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ count | sum | avg
+-------+-----+---------------------
+ 8 | 330 | 55.5000000000000000
+(1 row)
+
+-- ORDER BY expression is part of the target list but not pushed down to
+-- foreign server.
+explain (verbose, costs off)
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: (((sum(c2)) * ((random() <= '1'::double precision))::integer))
+ Sort Key: (((sum(ft1.c2)) * ((random() <= '1'::double precision))::integer))
+ -> Foreign Scan
+ Output: ((sum(c2)) * ((random() <= '1'::double precision))::integer)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
+(7 rows)
+
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ sum
+------
+ 4500
+(1 row)
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c2, qry.sum
+ Sort Key: t1.c2
+ -> Nested Loop
+ Output: t1.c2, qry.sum
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Index Cond: (t1."C 1" < 100)
+ Filter: (t1.c2 < 3)
+ -> Subquery Scan on qry
+ Output: qry.sum, t2.c1
+ Filter: ((t1.c2 * 2) = qry.sum)
+ -> Foreign Scan
+ Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY 2
+(16 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ c2 | sum
+----+-----
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+reset enable_hashagg;
+-- bug #15613: bad plan for foreign table scan with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: ref_0.c2, ref_0."C 1", (ref_0.c2), ref_1.c3, ref_0."C 1"
+ -> Nested Loop
+ Output: ref_0.c2, ref_0."C 1", ref_1.c3, (ref_0.c2)
+ -> Index Scan using t1_pkey on "S 1"."T 1" ref_0
+ Output: ref_0."C 1", ref_0.c2, ref_0.c3, ref_0.c4, ref_0.c5, ref_0.c6, ref_0.c7, ref_0.c8
+ Index Cond: (ref_0."C 1" < 10)
+ -> Foreign Scan on public.ft1 ref_1
+ Output: ref_1.c3, ref_0.c2
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+ -> Materialize
+ Output: ref_3.c3
+ -> Foreign Scan on public.ft2 ref_3
+ Output: ref_3.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+(15 rows)
+
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ c2 | c1 | c2 | c3
+----+----+----+-------
+ 1 | 1 | 1 | 00001
+ 2 | 2 | 2 | 00001
+ 3 | 3 | 3 | 00001
+ 4 | 4 | 4 | 00001
+ 5 | 5 | 5 | 00001
+ 6 | 6 | 6 | 00001
+ 7 | 7 | 7 | 00001
+ 8 | 8 | 8 | 00001
+ 9 | 9 | 9 | 00001
+(9 rows)
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(q.a), count(q.b)
+ -> Nested Loop Left Join
+ Output: q.a, q.b
+ Inner Unique: true
+ Join Filter: ((ft4.c1)::numeric <= q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Materialize
+ Output: q.a, q.b
+ -> Subquery Scan on q
+ Output: q.a, q.b
+ -> Foreign Scan
+ Output: 13, (avg(ft1.c1)), NULL::bigint
+ Relations: Aggregate on ((public.ft2) LEFT JOIN (public.ft1))
+ Remote SQL: SELECT 13, avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1"))))
+(17 rows)
+
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ sum | count
+-----+-------
+ 650 | 50
+(1 row)
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: c2, c6, (sum(c1))
+ Sort Key: ft1.c2, ft1.c6
+ -> HashAggregate
+ Output: c2, c6, sum(c1)
+ Hash Key: ft1.c2
+ Hash Key: ft1.c6
+ -> Foreign Scan on public.ft1
+ Output: c2, c6, c1
+ Remote SQL: SELECT "C 1", c2, c6 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 0 | | 50500
+ 1 | | 49600
+ 2 | | 49700
+ | 0 | 50500
+ | 1 | 49600
+ | 2 | 49700
+(6 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1)), (GROUPING(c2))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, sum(c1), GROUPING(c2)
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(9 rows)
+
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 0 | 50500 | 0
+ 1 | 49600 | 0
+ 2 | 49700 | 0
+(3 rows)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((sum(c1) / 1000)), c2
+ -> Sort
+ Output: ((sum(c1) / 1000)), c2
+ Sort Key: ((sum(ft2.c1) / 1000))
+ -> Foreign Scan
+ Output: ((sum(c1) / 1000)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT (sum("C 1") / 1000), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY 2
+(9 rows)
+
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ s
+----
+ 49
+ 50
+(2 rows)
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2)), (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, (sum(c2)), count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ c2 | sum | count
+----+-----+-------
+ 0 | 0 | 5
+ 1 | 100 | 5
+ 2 | 200 | 5
+ 3 | 300 | 5
+ 4 | 400 | 5
+ 5 | 500 | 5
+ 6 | 600 | 5
+ 7 | 700 | 5
+ 8 | 800 | 5
+ 9 | 900 | 5
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2 DESC
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {8,6,4,2,0}
+ 1 | {9,7,5,3,1}
+ 2 | {8,6,4,2}
+ 3 | {9,7,5,3}
+ 4 | {8,6,4}
+ 5 | {9,7,5}
+ 6 | {8,6}
+ 7 | {9,7}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {0,2,4,6,8}
+ 1 | {1,3,5,7,9}
+ 2 | {2,4,6,8}
+ 3 | {3,5,7,9}
+ 4 | {4,6,8}
+ 5 | {5,7,9}
+ 6 | {6,8}
+ 7 | {7,9}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+-- ===================================================================
+-- parameterized queries
+-- ===================================================================
+-- simple join
+PREPARE st1(int, int) AS SELECT t1.c3, t2.c3 FROM ft1 t1, ft2 t2 WHERE t1.c1 = $1 AND t2.c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st1(1, 2);
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c3, t2.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.c3, r2.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 2)) AND ((r1."C 1" = 1))))
+(4 rows)
+
+EXECUTE st1(1, 1);
+ c3 | c3
+-------+-------
+ 00001 | 00001
+(1 row)
+
+EXECUTE st1(101, 101);
+ c3 | c3
+-------+-------
+ 00101 | 00101
+(1 row)
+
+-- subquery using stable function (can't be sent to remote)
+PREPARE st2(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c4) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st2(10, 20);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t2.c3 = t1.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Filter: (date(t2.c4) = '01-17-1970'::date)
+ Remote SQL: SELECT c3, c4 FROM "S 1"."T 1" WHERE (("C 1" > 10))
+(15 rows)
+
+EXECUTE st2(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st2(101, 121);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+-- subquery using immutable function (can be sent to remote)
+PREPARE st3(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c5) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st3(10, 20);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t2.c3 = t1.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" > 10)) AND ((date(c5) = '1970-01-17'::date))
+(14 rows)
+
+EXECUTE st3(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st3(20, 30);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- custom plan should be chosen initially
+PREPARE st4(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 = $1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+-- once we try it enough times, should switch to generic plan
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(3 rows)
+
+-- value of $1 should not be sent to remote
+PREPARE st5(user_enum,int) AS SELECT * FROM ft1 t1 WHERE c8 = $1 and c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = $1)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(4 rows)
+
+EXECUTE st5('foo', 1);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- altering FDW options requires replanning
+PREPARE st6 AS SELECT * FROM ft1 t1 WHERE t1.c1 = t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(3 rows)
+
+PREPARE st7 AS INSERT INTO ft1 (c1,c2,c3) VALUES (1001,101,'foo');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 1" RENAME TO "T 0";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 0');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 0" WHERE (("C 1" = c2))
+(3 rows)
+
+EXECUTE st6;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 0"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 0" RENAME TO "T 1";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 1');
+PREPARE st8 AS SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+EXECUTE st8;
+ count
+-------
+ 9
+(1 row)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- cleanup
+DEALLOCATE st1;
+DEALLOCATE st2;
+DEALLOCATE st3;
+DEALLOCATE st4;
+DEALLOCATE st5;
+DEALLOCATE st6;
+DEALLOCATE st7;
+DEALLOCATE st8;
+-- System columns, except ctid and oid, should not be sent to remote
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'pg_class'::regclass LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.tableoid = '1259'::oid)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'ft1'::regclass LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: (tableoid)::regclass, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ tableoid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ ft1 | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((ctid = '(0,2)'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: ctid, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ ctid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ (0,1) | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- ===================================================================
+-- used in PL/pgSQL function
+-- ===================================================================
+CREATE OR REPLACE FUNCTION f_test(p_c1 int) RETURNS int AS $$
+DECLARE
+ v_c1 int;
+BEGIN
+ SELECT c1 INTO v_c1 FROM ft1 WHERE c1 = p_c1 LIMIT 1;
+ PERFORM c1 FROM ft1 WHERE c1 = p_c1 AND p_c1 = v_c1 LIMIT 1;
+ RETURN v_c1;
+END;
+$$ LANGUAGE plpgsql;
+SELECT f_test(100);
+ f_test
+--------
+ 100
+(1 row)
+
+DROP FUNCTION f_test(int);
+-- ===================================================================
+-- REINDEX
+-- ===================================================================
+-- remote table is not created here
+CREATE FOREIGN TABLE reindex_foreign (c1 int, c2 int)
+ SERVER loopback2 OPTIONS (table_name 'reindex_local');
+REINDEX TABLE reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+REINDEX TABLE CONCURRENTLY reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+DROP FOREIGN TABLE reindex_foreign;
+-- partitions and foreign tables
+CREATE TABLE reind_fdw_parent (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE reind_fdw_0_10 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (0) TO (10);
+CREATE FOREIGN TABLE reind_fdw_10_20 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (10) TO (20)
+ SERVER loopback OPTIONS (table_name 'reind_local_10_20');
+REINDEX TABLE reind_fdw_parent; -- ok
+REINDEX TABLE CONCURRENTLY reind_fdw_parent; -- ok
+DROP TABLE reind_fdw_parent;
+-- ===================================================================
+-- conversion error
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int;
+SELECT * FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8) WHERE x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx.x8 FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: whole-row reference to foreign table "ftx"
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: processing expression at position 2 in select list
+ANALYZE ft1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "c8" of foreign table "ft1"
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- local type can be different from remote type in some cases,
+-- in particular if similarly-named operators do equivalent things
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE text;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 = 'foo')) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (('foo' = c8)) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- we declared c8 to be text locally, but it's still the same type on
+-- the remote which will balk if we try to do anything incompatible
+-- with that remote type
+SELECT * FROM ft1 WHERE c8 LIKE 'foo' LIMIT 1; -- ERROR
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+SELECT * FROM ft1 WHERE c8::text LIKE 'foo' LIMIT 1; -- ERROR; cast not pushed down
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- subtransaction
+-- + local/remote error doesn't break cursor
+-- ===================================================================
+BEGIN;
+DECLARE c CURSOR FOR SELECT * FROM ft1 ORDER BY c1;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+SAVEPOINT s;
+ERROR OUT; -- ERROR
+ERROR: syntax error at or near "ERROR"
+LINE 1: ERROR OUT;
+ ^
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+SAVEPOINT s;
+SELECT * FROM ft1 WHERE 1 / (c1 - 1) > 0; -- ERROR
+ERROR: division by zero
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (((1 / ("C 1" - 1)) > 0))
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c1 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+COMMIT;
+-- ===================================================================
+-- test handling of collations
+-- ===================================================================
+create table loct3 (f1 text collate "C" unique, f2 text, f3 varchar(10) unique);
+create foreign table ft3 (f1 text collate "C", f2 text, f3 varchar(10))
+ server loopback options (table_name 'loct3', use_remote_estimate 'true');
+-- can be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "C" = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f2 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f3 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 and l.f1 = 'foo';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = $1::character varying(10)))
+(8 rows)
+
+-- can't be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "POSIX" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f1)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f1 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 COLLATE "C" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f2)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f2 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 COLLATE "POSIX" and l.f1 = 'foo';
+ QUERY PLAN
+-------------------------------------------------------------
+ Hash Join
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ Inner Unique: true
+ Hash Cond: ((f.f3)::text = (l.f3)::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+ -> Hash
+ Output: l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+(12 rows)
+
+-- ===================================================================
+-- test writable foreign table stuff
+-- ===================================================================
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Subquery Scan on "*SELECT*"
+ Output: "*SELECT*"."?column?", "*SELECT*"."?column?_1", NULL::integer, "*SELECT*"."?column?_2", NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+ -> Foreign Scan on public.ft2 ft2_1
+ Output: (ft2_1.c1 + 1000), (ft2_1.c2 + 100), (ft2_1.c3 || ft2_1.c3)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" LIMIT 20::bigint
+(8 rows)
+
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+INSERT INTO ft2 (c1,c2,c3)
+ VALUES (1101,201,'aaa'), (1102,202,'bbb'), (1103,203,'ccc') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----+----+----+----+------------+----
+ 1101 | 201 | aaa | | | | ft2 |
+ 1102 | 202 | bbb | | | | ft2 |
+ 1103 | 203 | ccc | | | | ft2 |
+(3 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1104,204,'ddd'), (1105,205,'eee');
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 300), c3 = (c3 || '_update3') WHERE ((("C 1" % 10) = 3))
+(3 rows)
+
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 400), c3 = (c3 || '_update7') WHERE ((("C 1" % 10) = 7)) RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+(4 rows)
+
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+----+------------+-----
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 1007 | 507 | 0000700007_update7 | | | | ft2 |
+ 1017 | 507 | 0001700017_update7 | | | | ft2 |
+(102 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9; -- can be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c2 = (r1.c2 + 500), c3 = (r1.c3 || '_update9'), c7 = 'ft2 '::character(10) FROM "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 9))
+(3 rows)
+
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9;
+EXPLAIN (verbose, costs off)
+ DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: c1, c4
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 5)) RETURNING "C 1", c4
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4;
+ c1 | c4
+------+------------------------------
+ 5 | Tue Jan 06 00:00:00 1970 PST
+ 15 | Fri Jan 16 00:00:00 1970 PST
+ 25 | Mon Jan 26 00:00:00 1970 PST
+ 35 | Thu Feb 05 00:00:00 1970 PST
+ 45 | Sun Feb 15 00:00:00 1970 PST
+ 55 | Wed Feb 25 00:00:00 1970 PST
+ 65 | Sat Mar 07 00:00:00 1970 PST
+ 75 | Tue Mar 17 00:00:00 1970 PST
+ 85 | Fri Mar 27 00:00:00 1970 PST
+ 95 | Mon Apr 06 00:00:00 1970 PST
+ 105 | Tue Jan 06 00:00:00 1970 PST
+ 115 | Fri Jan 16 00:00:00 1970 PST
+ 125 | Mon Jan 26 00:00:00 1970 PST
+ 135 | Thu Feb 05 00:00:00 1970 PST
+ 145 | Sun Feb 15 00:00:00 1970 PST
+ 155 | Wed Feb 25 00:00:00 1970 PST
+ 165 | Sat Mar 07 00:00:00 1970 PST
+ 175 | Tue Mar 17 00:00:00 1970 PST
+ 185 | Fri Mar 27 00:00:00 1970 PST
+ 195 | Mon Apr 06 00:00:00 1970 PST
+ 205 | Tue Jan 06 00:00:00 1970 PST
+ 215 | Fri Jan 16 00:00:00 1970 PST
+ 225 | Mon Jan 26 00:00:00 1970 PST
+ 235 | Thu Feb 05 00:00:00 1970 PST
+ 245 | Sun Feb 15 00:00:00 1970 PST
+ 255 | Wed Feb 25 00:00:00 1970 PST
+ 265 | Sat Mar 07 00:00:00 1970 PST
+ 275 | Tue Mar 17 00:00:00 1970 PST
+ 285 | Fri Mar 27 00:00:00 1970 PST
+ 295 | Mon Apr 06 00:00:00 1970 PST
+ 305 | Tue Jan 06 00:00:00 1970 PST
+ 315 | Fri Jan 16 00:00:00 1970 PST
+ 325 | Mon Jan 26 00:00:00 1970 PST
+ 335 | Thu Feb 05 00:00:00 1970 PST
+ 345 | Sun Feb 15 00:00:00 1970 PST
+ 355 | Wed Feb 25 00:00:00 1970 PST
+ 365 | Sat Mar 07 00:00:00 1970 PST
+ 375 | Tue Mar 17 00:00:00 1970 PST
+ 385 | Fri Mar 27 00:00:00 1970 PST
+ 395 | Mon Apr 06 00:00:00 1970 PST
+ 405 | Tue Jan 06 00:00:00 1970 PST
+ 415 | Fri Jan 16 00:00:00 1970 PST
+ 425 | Mon Jan 26 00:00:00 1970 PST
+ 435 | Thu Feb 05 00:00:00 1970 PST
+ 445 | Sun Feb 15 00:00:00 1970 PST
+ 455 | Wed Feb 25 00:00:00 1970 PST
+ 465 | Sat Mar 07 00:00:00 1970 PST
+ 475 | Tue Mar 17 00:00:00 1970 PST
+ 485 | Fri Mar 27 00:00:00 1970 PST
+ 495 | Mon Apr 06 00:00:00 1970 PST
+ 505 | Tue Jan 06 00:00:00 1970 PST
+ 515 | Fri Jan 16 00:00:00 1970 PST
+ 525 | Mon Jan 26 00:00:00 1970 PST
+ 535 | Thu Feb 05 00:00:00 1970 PST
+ 545 | Sun Feb 15 00:00:00 1970 PST
+ 555 | Wed Feb 25 00:00:00 1970 PST
+ 565 | Sat Mar 07 00:00:00 1970 PST
+ 575 | Tue Mar 17 00:00:00 1970 PST
+ 585 | Fri Mar 27 00:00:00 1970 PST
+ 595 | Mon Apr 06 00:00:00 1970 PST
+ 605 | Tue Jan 06 00:00:00 1970 PST
+ 615 | Fri Jan 16 00:00:00 1970 PST
+ 625 | Mon Jan 26 00:00:00 1970 PST
+ 635 | Thu Feb 05 00:00:00 1970 PST
+ 645 | Sun Feb 15 00:00:00 1970 PST
+ 655 | Wed Feb 25 00:00:00 1970 PST
+ 665 | Sat Mar 07 00:00:00 1970 PST
+ 675 | Tue Mar 17 00:00:00 1970 PST
+ 685 | Fri Mar 27 00:00:00 1970 PST
+ 695 | Mon Apr 06 00:00:00 1970 PST
+ 705 | Tue Jan 06 00:00:00 1970 PST
+ 715 | Fri Jan 16 00:00:00 1970 PST
+ 725 | Mon Jan 26 00:00:00 1970 PST
+ 735 | Thu Feb 05 00:00:00 1970 PST
+ 745 | Sun Feb 15 00:00:00 1970 PST
+ 755 | Wed Feb 25 00:00:00 1970 PST
+ 765 | Sat Mar 07 00:00:00 1970 PST
+ 775 | Tue Mar 17 00:00:00 1970 PST
+ 785 | Fri Mar 27 00:00:00 1970 PST
+ 795 | Mon Apr 06 00:00:00 1970 PST
+ 805 | Tue Jan 06 00:00:00 1970 PST
+ 815 | Fri Jan 16 00:00:00 1970 PST
+ 825 | Mon Jan 26 00:00:00 1970 PST
+ 835 | Thu Feb 05 00:00:00 1970 PST
+ 845 | Sun Feb 15 00:00:00 1970 PST
+ 855 | Wed Feb 25 00:00:00 1970 PST
+ 865 | Sat Mar 07 00:00:00 1970 PST
+ 875 | Tue Mar 17 00:00:00 1970 PST
+ 885 | Fri Mar 27 00:00:00 1970 PST
+ 895 | Mon Apr 06 00:00:00 1970 PST
+ 905 | Tue Jan 06 00:00:00 1970 PST
+ 915 | Fri Jan 16 00:00:00 1970 PST
+ 925 | Mon Jan 26 00:00:00 1970 PST
+ 935 | Thu Feb 05 00:00:00 1970 PST
+ 945 | Sun Feb 15 00:00:00 1970 PST
+ 955 | Wed Feb 25 00:00:00 1970 PST
+ 965 | Sat Mar 07 00:00:00 1970 PST
+ 975 | Tue Mar 17 00:00:00 1970 PST
+ 985 | Fri Mar 27 00:00:00 1970 PST
+ 995 | Mon Apr 06 00:00:00 1970 PST
+ 1005 |
+ 1015 |
+ 1105 |
+(103 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 2))
+(3 rows)
+
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2;
+SELECT c1,c2,c3,c4 FROM ft2 ORDER BY c1;
+ c1 | c2 | c3 | c4
+------+-----+--------------------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 3 | 303 | 00003_update3 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+ 11 | 1 | 00011 | Mon Jan 12 00:00:00 1970 PST
+ 13 | 303 | 00013_update3 | Wed Jan 14 00:00:00 1970 PST
+ 14 | 4 | 00014 | Thu Jan 15 00:00:00 1970 PST
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST
+ 18 | 8 | 00018 | Mon Jan 19 00:00:00 1970 PST
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST
+ 20 | 0 | 00020 | Wed Jan 21 00:00:00 1970 PST
+ 21 | 1 | 00021 | Thu Jan 22 00:00:00 1970 PST
+ 23 | 303 | 00023_update3 | Sat Jan 24 00:00:00 1970 PST
+ 24 | 4 | 00024 | Sun Jan 25 00:00:00 1970 PST
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST
+ 28 | 8 | 00028 | Thu Jan 29 00:00:00 1970 PST
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST
+ 30 | 0 | 00030 | Sat Jan 31 00:00:00 1970 PST
+ 31 | 1 | 00031 | Sun Feb 01 00:00:00 1970 PST
+ 33 | 303 | 00033_update3 | Tue Feb 03 00:00:00 1970 PST
+ 34 | 4 | 00034 | Wed Feb 04 00:00:00 1970 PST
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST
+ 38 | 8 | 00038 | Sun Feb 08 00:00:00 1970 PST
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST
+ 40 | 0 | 00040 | Tue Feb 10 00:00:00 1970 PST
+ 41 | 1 | 00041 | Wed Feb 11 00:00:00 1970 PST
+ 43 | 303 | 00043_update3 | Fri Feb 13 00:00:00 1970 PST
+ 44 | 4 | 00044 | Sat Feb 14 00:00:00 1970 PST
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST
+ 48 | 8 | 00048 | Wed Feb 18 00:00:00 1970 PST
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST
+ 50 | 0 | 00050 | Fri Feb 20 00:00:00 1970 PST
+ 51 | 1 | 00051 | Sat Feb 21 00:00:00 1970 PST
+ 53 | 303 | 00053_update3 | Mon Feb 23 00:00:00 1970 PST
+ 54 | 4 | 00054 | Tue Feb 24 00:00:00 1970 PST
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST
+ 58 | 8 | 00058 | Sat Feb 28 00:00:00 1970 PST
+ 59 | 509 | 00059_update9 | Sun Mar 01 00:00:00 1970 PST
+ 60 | 0 | 00060 | Mon Mar 02 00:00:00 1970 PST
+ 61 | 1 | 00061 | Tue Mar 03 00:00:00 1970 PST
+ 63 | 303 | 00063_update3 | Thu Mar 05 00:00:00 1970 PST
+ 64 | 4 | 00064 | Fri Mar 06 00:00:00 1970 PST
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST
+ 68 | 8 | 00068 | Tue Mar 10 00:00:00 1970 PST
+ 69 | 509 | 00069_update9 | Wed Mar 11 00:00:00 1970 PST
+ 70 | 0 | 00070 | Thu Mar 12 00:00:00 1970 PST
+ 71 | 1 | 00071 | Fri Mar 13 00:00:00 1970 PST
+ 73 | 303 | 00073_update3 | Sun Mar 15 00:00:00 1970 PST
+ 74 | 4 | 00074 | Mon Mar 16 00:00:00 1970 PST
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST
+ 78 | 8 | 00078 | Fri Mar 20 00:00:00 1970 PST
+ 79 | 509 | 00079_update9 | Sat Mar 21 00:00:00 1970 PST
+ 80 | 0 | 00080 | Sun Mar 22 00:00:00 1970 PST
+ 81 | 1 | 00081 | Mon Mar 23 00:00:00 1970 PST
+ 83 | 303 | 00083_update3 | Wed Mar 25 00:00:00 1970 PST
+ 84 | 4 | 00084 | Thu Mar 26 00:00:00 1970 PST
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST
+ 88 | 8 | 00088 | Mon Mar 30 00:00:00 1970 PST
+ 89 | 509 | 00089_update9 | Tue Mar 31 00:00:00 1970 PST
+ 90 | 0 | 00090 | Wed Apr 01 00:00:00 1970 PST
+ 91 | 1 | 00091 | Thu Apr 02 00:00:00 1970 PST
+ 93 | 303 | 00093_update3 | Sat Apr 04 00:00:00 1970 PST
+ 94 | 4 | 00094 | Sun Apr 05 00:00:00 1970 PST
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST
+ 98 | 8 | 00098 | Thu Apr 09 00:00:00 1970 PST
+ 99 | 509 | 00099_update9 | Fri Apr 10 00:00:00 1970 PST
+ 100 | 0 | 00100 | Thu Jan 01 00:00:00 1970 PST
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST
+ 103 | 303 | 00103_update3 | Sun Jan 04 00:00:00 1970 PST
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST
+ 109 | 509 | 00109_update9 | Sat Jan 10 00:00:00 1970 PST
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST
+ 111 | 1 | 00111 | Mon Jan 12 00:00:00 1970 PST
+ 113 | 303 | 00113_update3 | Wed Jan 14 00:00:00 1970 PST
+ 114 | 4 | 00114 | Thu Jan 15 00:00:00 1970 PST
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST
+ 118 | 8 | 00118 | Mon Jan 19 00:00:00 1970 PST
+ 119 | 509 | 00119_update9 | Tue Jan 20 00:00:00 1970 PST
+ 120 | 0 | 00120 | Wed Jan 21 00:00:00 1970 PST
+ 121 | 1 | 00121 | Thu Jan 22 00:00:00 1970 PST
+ 123 | 303 | 00123_update3 | Sat Jan 24 00:00:00 1970 PST
+ 124 | 4 | 00124 | Sun Jan 25 00:00:00 1970 PST
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST
+ 128 | 8 | 00128 | Thu Jan 29 00:00:00 1970 PST
+ 129 | 509 | 00129_update9 | Fri Jan 30 00:00:00 1970 PST
+ 130 | 0 | 00130 | Sat Jan 31 00:00:00 1970 PST
+ 131 | 1 | 00131 | Sun Feb 01 00:00:00 1970 PST
+ 133 | 303 | 00133_update3 | Tue Feb 03 00:00:00 1970 PST
+ 134 | 4 | 00134 | Wed Feb 04 00:00:00 1970 PST
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST
+ 138 | 8 | 00138 | Sun Feb 08 00:00:00 1970 PST
+ 139 | 509 | 00139_update9 | Mon Feb 09 00:00:00 1970 PST
+ 140 | 0 | 00140 | Tue Feb 10 00:00:00 1970 PST
+ 141 | 1 | 00141 | Wed Feb 11 00:00:00 1970 PST
+ 143 | 303 | 00143_update3 | Fri Feb 13 00:00:00 1970 PST
+ 144 | 4 | 00144 | Sat Feb 14 00:00:00 1970 PST
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST
+ 148 | 8 | 00148 | Wed Feb 18 00:00:00 1970 PST
+ 149 | 509 | 00149_update9 | Thu Feb 19 00:00:00 1970 PST
+ 150 | 0 | 00150 | Fri Feb 20 00:00:00 1970 PST
+ 151 | 1 | 00151 | Sat Feb 21 00:00:00 1970 PST
+ 153 | 303 | 00153_update3 | Mon Feb 23 00:00:00 1970 PST
+ 154 | 4 | 00154 | Tue Feb 24 00:00:00 1970 PST
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST
+ 158 | 8 | 00158 | Sat Feb 28 00:00:00 1970 PST
+ 159 | 509 | 00159_update9 | Sun Mar 01 00:00:00 1970 PST
+ 160 | 0 | 00160 | Mon Mar 02 00:00:00 1970 PST
+ 161 | 1 | 00161 | Tue Mar 03 00:00:00 1970 PST
+ 163 | 303 | 00163_update3 | Thu Mar 05 00:00:00 1970 PST
+ 164 | 4 | 00164 | Fri Mar 06 00:00:00 1970 PST
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST
+ 168 | 8 | 00168 | Tue Mar 10 00:00:00 1970 PST
+ 169 | 509 | 00169_update9 | Wed Mar 11 00:00:00 1970 PST
+ 170 | 0 | 00170 | Thu Mar 12 00:00:00 1970 PST
+ 171 | 1 | 00171 | Fri Mar 13 00:00:00 1970 PST
+ 173 | 303 | 00173_update3 | Sun Mar 15 00:00:00 1970 PST
+ 174 | 4 | 00174 | Mon Mar 16 00:00:00 1970 PST
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST
+ 178 | 8 | 00178 | Fri Mar 20 00:00:00 1970 PST
+ 179 | 509 | 00179_update9 | Sat Mar 21 00:00:00 1970 PST
+ 180 | 0 | 00180 | Sun Mar 22 00:00:00 1970 PST
+ 181 | 1 | 00181 | Mon Mar 23 00:00:00 1970 PST
+ 183 | 303 | 00183_update3 | Wed Mar 25 00:00:00 1970 PST
+ 184 | 4 | 00184 | Thu Mar 26 00:00:00 1970 PST
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST
+ 188 | 8 | 00188 | Mon Mar 30 00:00:00 1970 PST
+ 189 | 509 | 00189_update9 | Tue Mar 31 00:00:00 1970 PST
+ 190 | 0 | 00190 | Wed Apr 01 00:00:00 1970 PST
+ 191 | 1 | 00191 | Thu Apr 02 00:00:00 1970 PST
+ 193 | 303 | 00193_update3 | Sat Apr 04 00:00:00 1970 PST
+ 194 | 4 | 00194 | Sun Apr 05 00:00:00 1970 PST
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST
+ 198 | 8 | 00198 | Thu Apr 09 00:00:00 1970 PST
+ 199 | 509 | 00199_update9 | Fri Apr 10 00:00:00 1970 PST
+ 200 | 0 | 00200 | Thu Jan 01 00:00:00 1970 PST
+ 201 | 1 | 00201 | Fri Jan 02 00:00:00 1970 PST
+ 203 | 303 | 00203_update3 | Sun Jan 04 00:00:00 1970 PST
+ 204 | 4 | 00204 | Mon Jan 05 00:00:00 1970 PST
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST
+ 208 | 8 | 00208 | Fri Jan 09 00:00:00 1970 PST
+ 209 | 509 | 00209_update9 | Sat Jan 10 00:00:00 1970 PST
+ 210 | 0 | 00210 | Sun Jan 11 00:00:00 1970 PST
+ 211 | 1 | 00211 | Mon Jan 12 00:00:00 1970 PST
+ 213 | 303 | 00213_update3 | Wed Jan 14 00:00:00 1970 PST
+ 214 | 4 | 00214 | Thu Jan 15 00:00:00 1970 PST
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST
+ 218 | 8 | 00218 | Mon Jan 19 00:00:00 1970 PST
+ 219 | 509 | 00219_update9 | Tue Jan 20 00:00:00 1970 PST
+ 220 | 0 | 00220 | Wed Jan 21 00:00:00 1970 PST
+ 221 | 1 | 00221 | Thu Jan 22 00:00:00 1970 PST
+ 223 | 303 | 00223_update3 | Sat Jan 24 00:00:00 1970 PST
+ 224 | 4 | 00224 | Sun Jan 25 00:00:00 1970 PST
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST
+ 228 | 8 | 00228 | Thu Jan 29 00:00:00 1970 PST
+ 229 | 509 | 00229_update9 | Fri Jan 30 00:00:00 1970 PST
+ 230 | 0 | 00230 | Sat Jan 31 00:00:00 1970 PST
+ 231 | 1 | 00231 | Sun Feb 01 00:00:00 1970 PST
+ 233 | 303 | 00233_update3 | Tue Feb 03 00:00:00 1970 PST
+ 234 | 4 | 00234 | Wed Feb 04 00:00:00 1970 PST
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST
+ 238 | 8 | 00238 | Sun Feb 08 00:00:00 1970 PST
+ 239 | 509 | 00239_update9 | Mon Feb 09 00:00:00 1970 PST
+ 240 | 0 | 00240 | Tue Feb 10 00:00:00 1970 PST
+ 241 | 1 | 00241 | Wed Feb 11 00:00:00 1970 PST
+ 243 | 303 | 00243_update3 | Fri Feb 13 00:00:00 1970 PST
+ 244 | 4 | 00244 | Sat Feb 14 00:00:00 1970 PST
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST
+ 248 | 8 | 00248 | Wed Feb 18 00:00:00 1970 PST
+ 249 | 509 | 00249_update9 | Thu Feb 19 00:00:00 1970 PST
+ 250 | 0 | 00250 | Fri Feb 20 00:00:00 1970 PST
+ 251 | 1 | 00251 | Sat Feb 21 00:00:00 1970 PST
+ 253 | 303 | 00253_update3 | Mon Feb 23 00:00:00 1970 PST
+ 254 | 4 | 00254 | Tue Feb 24 00:00:00 1970 PST
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST
+ 258 | 8 | 00258 | Sat Feb 28 00:00:00 1970 PST
+ 259 | 509 | 00259_update9 | Sun Mar 01 00:00:00 1970 PST
+ 260 | 0 | 00260 | Mon Mar 02 00:00:00 1970 PST
+ 261 | 1 | 00261 | Tue Mar 03 00:00:00 1970 PST
+ 263 | 303 | 00263_update3 | Thu Mar 05 00:00:00 1970 PST
+ 264 | 4 | 00264 | Fri Mar 06 00:00:00 1970 PST
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST
+ 268 | 8 | 00268 | Tue Mar 10 00:00:00 1970 PST
+ 269 | 509 | 00269_update9 | Wed Mar 11 00:00:00 1970 PST
+ 270 | 0 | 00270 | Thu Mar 12 00:00:00 1970 PST
+ 271 | 1 | 00271 | Fri Mar 13 00:00:00 1970 PST
+ 273 | 303 | 00273_update3 | Sun Mar 15 00:00:00 1970 PST
+ 274 | 4 | 00274 | Mon Mar 16 00:00:00 1970 PST
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST
+ 278 | 8 | 00278 | Fri Mar 20 00:00:00 1970 PST
+ 279 | 509 | 00279_update9 | Sat Mar 21 00:00:00 1970 PST
+ 280 | 0 | 00280 | Sun Mar 22 00:00:00 1970 PST
+ 281 | 1 | 00281 | Mon Mar 23 00:00:00 1970 PST
+ 283 | 303 | 00283_update3 | Wed Mar 25 00:00:00 1970 PST
+ 284 | 4 | 00284 | Thu Mar 26 00:00:00 1970 PST
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST
+ 288 | 8 | 00288 | Mon Mar 30 00:00:00 1970 PST
+ 289 | 509 | 00289_update9 | Tue Mar 31 00:00:00 1970 PST
+ 290 | 0 | 00290 | Wed Apr 01 00:00:00 1970 PST
+ 291 | 1 | 00291 | Thu Apr 02 00:00:00 1970 PST
+ 293 | 303 | 00293_update3 | Sat Apr 04 00:00:00 1970 PST
+ 294 | 4 | 00294 | Sun Apr 05 00:00:00 1970 PST
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST
+ 298 | 8 | 00298 | Thu Apr 09 00:00:00 1970 PST
+ 299 | 509 | 00299_update9 | Fri Apr 10 00:00:00 1970 PST
+ 300 | 0 | 00300 | Thu Jan 01 00:00:00 1970 PST
+ 301 | 1 | 00301 | Fri Jan 02 00:00:00 1970 PST
+ 303 | 303 | 00303_update3 | Sun Jan 04 00:00:00 1970 PST
+ 304 | 4 | 00304 | Mon Jan 05 00:00:00 1970 PST
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST
+ 308 | 8 | 00308 | Fri Jan 09 00:00:00 1970 PST
+ 309 | 509 | 00309_update9 | Sat Jan 10 00:00:00 1970 PST
+ 310 | 0 | 00310 | Sun Jan 11 00:00:00 1970 PST
+ 311 | 1 | 00311 | Mon Jan 12 00:00:00 1970 PST
+ 313 | 303 | 00313_update3 | Wed Jan 14 00:00:00 1970 PST
+ 314 | 4 | 00314 | Thu Jan 15 00:00:00 1970 PST
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST
+ 318 | 8 | 00318 | Mon Jan 19 00:00:00 1970 PST
+ 319 | 509 | 00319_update9 | Tue Jan 20 00:00:00 1970 PST
+ 320 | 0 | 00320 | Wed Jan 21 00:00:00 1970 PST
+ 321 | 1 | 00321 | Thu Jan 22 00:00:00 1970 PST
+ 323 | 303 | 00323_update3 | Sat Jan 24 00:00:00 1970 PST
+ 324 | 4 | 00324 | Sun Jan 25 00:00:00 1970 PST
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST
+ 328 | 8 | 00328 | Thu Jan 29 00:00:00 1970 PST
+ 329 | 509 | 00329_update9 | Fri Jan 30 00:00:00 1970 PST
+ 330 | 0 | 00330 | Sat Jan 31 00:00:00 1970 PST
+ 331 | 1 | 00331 | Sun Feb 01 00:00:00 1970 PST
+ 333 | 303 | 00333_update3 | Tue Feb 03 00:00:00 1970 PST
+ 334 | 4 | 00334 | Wed Feb 04 00:00:00 1970 PST
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST
+ 338 | 8 | 00338 | Sun Feb 08 00:00:00 1970 PST
+ 339 | 509 | 00339_update9 | Mon Feb 09 00:00:00 1970 PST
+ 340 | 0 | 00340 | Tue Feb 10 00:00:00 1970 PST
+ 341 | 1 | 00341 | Wed Feb 11 00:00:00 1970 PST
+ 343 | 303 | 00343_update3 | Fri Feb 13 00:00:00 1970 PST
+ 344 | 4 | 00344 | Sat Feb 14 00:00:00 1970 PST
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST
+ 348 | 8 | 00348 | Wed Feb 18 00:00:00 1970 PST
+ 349 | 509 | 00349_update9 | Thu Feb 19 00:00:00 1970 PST
+ 350 | 0 | 00350 | Fri Feb 20 00:00:00 1970 PST
+ 351 | 1 | 00351 | Sat Feb 21 00:00:00 1970 PST
+ 353 | 303 | 00353_update3 | Mon Feb 23 00:00:00 1970 PST
+ 354 | 4 | 00354 | Tue Feb 24 00:00:00 1970 PST
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST
+ 358 | 8 | 00358 | Sat Feb 28 00:00:00 1970 PST
+ 359 | 509 | 00359_update9 | Sun Mar 01 00:00:00 1970 PST
+ 360 | 0 | 00360 | Mon Mar 02 00:00:00 1970 PST
+ 361 | 1 | 00361 | Tue Mar 03 00:00:00 1970 PST
+ 363 | 303 | 00363_update3 | Thu Mar 05 00:00:00 1970 PST
+ 364 | 4 | 00364 | Fri Mar 06 00:00:00 1970 PST
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST
+ 368 | 8 | 00368 | Tue Mar 10 00:00:00 1970 PST
+ 369 | 509 | 00369_update9 | Wed Mar 11 00:00:00 1970 PST
+ 370 | 0 | 00370 | Thu Mar 12 00:00:00 1970 PST
+ 371 | 1 | 00371 | Fri Mar 13 00:00:00 1970 PST
+ 373 | 303 | 00373_update3 | Sun Mar 15 00:00:00 1970 PST
+ 374 | 4 | 00374 | Mon Mar 16 00:00:00 1970 PST
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST
+ 378 | 8 | 00378 | Fri Mar 20 00:00:00 1970 PST
+ 379 | 509 | 00379_update9 | Sat Mar 21 00:00:00 1970 PST
+ 380 | 0 | 00380 | Sun Mar 22 00:00:00 1970 PST
+ 381 | 1 | 00381 | Mon Mar 23 00:00:00 1970 PST
+ 383 | 303 | 00383_update3 | Wed Mar 25 00:00:00 1970 PST
+ 384 | 4 | 00384 | Thu Mar 26 00:00:00 1970 PST
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST
+ 388 | 8 | 00388 | Mon Mar 30 00:00:00 1970 PST
+ 389 | 509 | 00389_update9 | Tue Mar 31 00:00:00 1970 PST
+ 390 | 0 | 00390 | Wed Apr 01 00:00:00 1970 PST
+ 391 | 1 | 00391 | Thu Apr 02 00:00:00 1970 PST
+ 393 | 303 | 00393_update3 | Sat Apr 04 00:00:00 1970 PST
+ 394 | 4 | 00394 | Sun Apr 05 00:00:00 1970 PST
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST
+ 398 | 8 | 00398 | Thu Apr 09 00:00:00 1970 PST
+ 399 | 509 | 00399_update9 | Fri Apr 10 00:00:00 1970 PST
+ 400 | 0 | 00400 | Thu Jan 01 00:00:00 1970 PST
+ 401 | 1 | 00401 | Fri Jan 02 00:00:00 1970 PST
+ 403 | 303 | 00403_update3 | Sun Jan 04 00:00:00 1970 PST
+ 404 | 4 | 00404 | Mon Jan 05 00:00:00 1970 PST
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST
+ 408 | 8 | 00408 | Fri Jan 09 00:00:00 1970 PST
+ 409 | 509 | 00409_update9 | Sat Jan 10 00:00:00 1970 PST
+ 410 | 0 | 00410 | Sun Jan 11 00:00:00 1970 PST
+ 411 | 1 | 00411 | Mon Jan 12 00:00:00 1970 PST
+ 413 | 303 | 00413_update3 | Wed Jan 14 00:00:00 1970 PST
+ 414 | 4 | 00414 | Thu Jan 15 00:00:00 1970 PST
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST
+ 418 | 8 | 00418 | Mon Jan 19 00:00:00 1970 PST
+ 419 | 509 | 00419_update9 | Tue Jan 20 00:00:00 1970 PST
+ 420 | 0 | 00420 | Wed Jan 21 00:00:00 1970 PST
+ 421 | 1 | 00421 | Thu Jan 22 00:00:00 1970 PST
+ 423 | 303 | 00423_update3 | Sat Jan 24 00:00:00 1970 PST
+ 424 | 4 | 00424 | Sun Jan 25 00:00:00 1970 PST
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST
+ 428 | 8 | 00428 | Thu Jan 29 00:00:00 1970 PST
+ 429 | 509 | 00429_update9 | Fri Jan 30 00:00:00 1970 PST
+ 430 | 0 | 00430 | Sat Jan 31 00:00:00 1970 PST
+ 431 | 1 | 00431 | Sun Feb 01 00:00:00 1970 PST
+ 433 | 303 | 00433_update3 | Tue Feb 03 00:00:00 1970 PST
+ 434 | 4 | 00434 | Wed Feb 04 00:00:00 1970 PST
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST
+ 438 | 8 | 00438 | Sun Feb 08 00:00:00 1970 PST
+ 439 | 509 | 00439_update9 | Mon Feb 09 00:00:00 1970 PST
+ 440 | 0 | 00440 | Tue Feb 10 00:00:00 1970 PST
+ 441 | 1 | 00441 | Wed Feb 11 00:00:00 1970 PST
+ 443 | 303 | 00443_update3 | Fri Feb 13 00:00:00 1970 PST
+ 444 | 4 | 00444 | Sat Feb 14 00:00:00 1970 PST
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST
+ 448 | 8 | 00448 | Wed Feb 18 00:00:00 1970 PST
+ 449 | 509 | 00449_update9 | Thu Feb 19 00:00:00 1970 PST
+ 450 | 0 | 00450 | Fri Feb 20 00:00:00 1970 PST
+ 451 | 1 | 00451 | Sat Feb 21 00:00:00 1970 PST
+ 453 | 303 | 00453_update3 | Mon Feb 23 00:00:00 1970 PST
+ 454 | 4 | 00454 | Tue Feb 24 00:00:00 1970 PST
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST
+ 458 | 8 | 00458 | Sat Feb 28 00:00:00 1970 PST
+ 459 | 509 | 00459_update9 | Sun Mar 01 00:00:00 1970 PST
+ 460 | 0 | 00460 | Mon Mar 02 00:00:00 1970 PST
+ 461 | 1 | 00461 | Tue Mar 03 00:00:00 1970 PST
+ 463 | 303 | 00463_update3 | Thu Mar 05 00:00:00 1970 PST
+ 464 | 4 | 00464 | Fri Mar 06 00:00:00 1970 PST
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST
+ 468 | 8 | 00468 | Tue Mar 10 00:00:00 1970 PST
+ 469 | 509 | 00469_update9 | Wed Mar 11 00:00:00 1970 PST
+ 470 | 0 | 00470 | Thu Mar 12 00:00:00 1970 PST
+ 471 | 1 | 00471 | Fri Mar 13 00:00:00 1970 PST
+ 473 | 303 | 00473_update3 | Sun Mar 15 00:00:00 1970 PST
+ 474 | 4 | 00474 | Mon Mar 16 00:00:00 1970 PST
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST
+ 478 | 8 | 00478 | Fri Mar 20 00:00:00 1970 PST
+ 479 | 509 | 00479_update9 | Sat Mar 21 00:00:00 1970 PST
+ 480 | 0 | 00480 | Sun Mar 22 00:00:00 1970 PST
+ 481 | 1 | 00481 | Mon Mar 23 00:00:00 1970 PST
+ 483 | 303 | 00483_update3 | Wed Mar 25 00:00:00 1970 PST
+ 484 | 4 | 00484 | Thu Mar 26 00:00:00 1970 PST
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST
+ 488 | 8 | 00488 | Mon Mar 30 00:00:00 1970 PST
+ 489 | 509 | 00489_update9 | Tue Mar 31 00:00:00 1970 PST
+ 490 | 0 | 00490 | Wed Apr 01 00:00:00 1970 PST
+ 491 | 1 | 00491 | Thu Apr 02 00:00:00 1970 PST
+ 493 | 303 | 00493_update3 | Sat Apr 04 00:00:00 1970 PST
+ 494 | 4 | 00494 | Sun Apr 05 00:00:00 1970 PST
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST
+ 498 | 8 | 00498 | Thu Apr 09 00:00:00 1970 PST
+ 499 | 509 | 00499_update9 | Fri Apr 10 00:00:00 1970 PST
+ 500 | 0 | 00500 | Thu Jan 01 00:00:00 1970 PST
+ 501 | 1 | 00501 | Fri Jan 02 00:00:00 1970 PST
+ 503 | 303 | 00503_update3 | Sun Jan 04 00:00:00 1970 PST
+ 504 | 4 | 00504 | Mon Jan 05 00:00:00 1970 PST
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST
+ 508 | 8 | 00508 | Fri Jan 09 00:00:00 1970 PST
+ 509 | 509 | 00509_update9 | Sat Jan 10 00:00:00 1970 PST
+ 510 | 0 | 00510 | Sun Jan 11 00:00:00 1970 PST
+ 511 | 1 | 00511 | Mon Jan 12 00:00:00 1970 PST
+ 513 | 303 | 00513_update3 | Wed Jan 14 00:00:00 1970 PST
+ 514 | 4 | 00514 | Thu Jan 15 00:00:00 1970 PST
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST
+ 518 | 8 | 00518 | Mon Jan 19 00:00:00 1970 PST
+ 519 | 509 | 00519_update9 | Tue Jan 20 00:00:00 1970 PST
+ 520 | 0 | 00520 | Wed Jan 21 00:00:00 1970 PST
+ 521 | 1 | 00521 | Thu Jan 22 00:00:00 1970 PST
+ 523 | 303 | 00523_update3 | Sat Jan 24 00:00:00 1970 PST
+ 524 | 4 | 00524 | Sun Jan 25 00:00:00 1970 PST
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST
+ 528 | 8 | 00528 | Thu Jan 29 00:00:00 1970 PST
+ 529 | 509 | 00529_update9 | Fri Jan 30 00:00:00 1970 PST
+ 530 | 0 | 00530 | Sat Jan 31 00:00:00 1970 PST
+ 531 | 1 | 00531 | Sun Feb 01 00:00:00 1970 PST
+ 533 | 303 | 00533_update3 | Tue Feb 03 00:00:00 1970 PST
+ 534 | 4 | 00534 | Wed Feb 04 00:00:00 1970 PST
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST
+ 538 | 8 | 00538 | Sun Feb 08 00:00:00 1970 PST
+ 539 | 509 | 00539_update9 | Mon Feb 09 00:00:00 1970 PST
+ 540 | 0 | 00540 | Tue Feb 10 00:00:00 1970 PST
+ 541 | 1 | 00541 | Wed Feb 11 00:00:00 1970 PST
+ 543 | 303 | 00543_update3 | Fri Feb 13 00:00:00 1970 PST
+ 544 | 4 | 00544 | Sat Feb 14 00:00:00 1970 PST
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST
+ 548 | 8 | 00548 | Wed Feb 18 00:00:00 1970 PST
+ 549 | 509 | 00549_update9 | Thu Feb 19 00:00:00 1970 PST
+ 550 | 0 | 00550 | Fri Feb 20 00:00:00 1970 PST
+ 551 | 1 | 00551 | Sat Feb 21 00:00:00 1970 PST
+ 553 | 303 | 00553_update3 | Mon Feb 23 00:00:00 1970 PST
+ 554 | 4 | 00554 | Tue Feb 24 00:00:00 1970 PST
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST
+ 558 | 8 | 00558 | Sat Feb 28 00:00:00 1970 PST
+ 559 | 509 | 00559_update9 | Sun Mar 01 00:00:00 1970 PST
+ 560 | 0 | 00560 | Mon Mar 02 00:00:00 1970 PST
+ 561 | 1 | 00561 | Tue Mar 03 00:00:00 1970 PST
+ 563 | 303 | 00563_update3 | Thu Mar 05 00:00:00 1970 PST
+ 564 | 4 | 00564 | Fri Mar 06 00:00:00 1970 PST
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST
+ 568 | 8 | 00568 | Tue Mar 10 00:00:00 1970 PST
+ 569 | 509 | 00569_update9 | Wed Mar 11 00:00:00 1970 PST
+ 570 | 0 | 00570 | Thu Mar 12 00:00:00 1970 PST
+ 571 | 1 | 00571 | Fri Mar 13 00:00:00 1970 PST
+ 573 | 303 | 00573_update3 | Sun Mar 15 00:00:00 1970 PST
+ 574 | 4 | 00574 | Mon Mar 16 00:00:00 1970 PST
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST
+ 578 | 8 | 00578 | Fri Mar 20 00:00:00 1970 PST
+ 579 | 509 | 00579_update9 | Sat Mar 21 00:00:00 1970 PST
+ 580 | 0 | 00580 | Sun Mar 22 00:00:00 1970 PST
+ 581 | 1 | 00581 | Mon Mar 23 00:00:00 1970 PST
+ 583 | 303 | 00583_update3 | Wed Mar 25 00:00:00 1970 PST
+ 584 | 4 | 00584 | Thu Mar 26 00:00:00 1970 PST
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST
+ 588 | 8 | 00588 | Mon Mar 30 00:00:00 1970 PST
+ 589 | 509 | 00589_update9 | Tue Mar 31 00:00:00 1970 PST
+ 590 | 0 | 00590 | Wed Apr 01 00:00:00 1970 PST
+ 591 | 1 | 00591 | Thu Apr 02 00:00:00 1970 PST
+ 593 | 303 | 00593_update3 | Sat Apr 04 00:00:00 1970 PST
+ 594 | 4 | 00594 | Sun Apr 05 00:00:00 1970 PST
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST
+ 598 | 8 | 00598 | Thu Apr 09 00:00:00 1970 PST
+ 599 | 509 | 00599_update9 | Fri Apr 10 00:00:00 1970 PST
+ 600 | 0 | 00600 | Thu Jan 01 00:00:00 1970 PST
+ 601 | 1 | 00601 | Fri Jan 02 00:00:00 1970 PST
+ 603 | 303 | 00603_update3 | Sun Jan 04 00:00:00 1970 PST
+ 604 | 4 | 00604 | Mon Jan 05 00:00:00 1970 PST
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST
+ 608 | 8 | 00608 | Fri Jan 09 00:00:00 1970 PST
+ 609 | 509 | 00609_update9 | Sat Jan 10 00:00:00 1970 PST
+ 610 | 0 | 00610 | Sun Jan 11 00:00:00 1970 PST
+ 611 | 1 | 00611 | Mon Jan 12 00:00:00 1970 PST
+ 613 | 303 | 00613_update3 | Wed Jan 14 00:00:00 1970 PST
+ 614 | 4 | 00614 | Thu Jan 15 00:00:00 1970 PST
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST
+ 618 | 8 | 00618 | Mon Jan 19 00:00:00 1970 PST
+ 619 | 509 | 00619_update9 | Tue Jan 20 00:00:00 1970 PST
+ 620 | 0 | 00620 | Wed Jan 21 00:00:00 1970 PST
+ 621 | 1 | 00621 | Thu Jan 22 00:00:00 1970 PST
+ 623 | 303 | 00623_update3 | Sat Jan 24 00:00:00 1970 PST
+ 624 | 4 | 00624 | Sun Jan 25 00:00:00 1970 PST
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST
+ 628 | 8 | 00628 | Thu Jan 29 00:00:00 1970 PST
+ 629 | 509 | 00629_update9 | Fri Jan 30 00:00:00 1970 PST
+ 630 | 0 | 00630 | Sat Jan 31 00:00:00 1970 PST
+ 631 | 1 | 00631 | Sun Feb 01 00:00:00 1970 PST
+ 633 | 303 | 00633_update3 | Tue Feb 03 00:00:00 1970 PST
+ 634 | 4 | 00634 | Wed Feb 04 00:00:00 1970 PST
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST
+ 638 | 8 | 00638 | Sun Feb 08 00:00:00 1970 PST
+ 639 | 509 | 00639_update9 | Mon Feb 09 00:00:00 1970 PST
+ 640 | 0 | 00640 | Tue Feb 10 00:00:00 1970 PST
+ 641 | 1 | 00641 | Wed Feb 11 00:00:00 1970 PST
+ 643 | 303 | 00643_update3 | Fri Feb 13 00:00:00 1970 PST
+ 644 | 4 | 00644 | Sat Feb 14 00:00:00 1970 PST
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST
+ 648 | 8 | 00648 | Wed Feb 18 00:00:00 1970 PST
+ 649 | 509 | 00649_update9 | Thu Feb 19 00:00:00 1970 PST
+ 650 | 0 | 00650 | Fri Feb 20 00:00:00 1970 PST
+ 651 | 1 | 00651 | Sat Feb 21 00:00:00 1970 PST
+ 653 | 303 | 00653_update3 | Mon Feb 23 00:00:00 1970 PST
+ 654 | 4 | 00654 | Tue Feb 24 00:00:00 1970 PST
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST
+ 658 | 8 | 00658 | Sat Feb 28 00:00:00 1970 PST
+ 659 | 509 | 00659_update9 | Sun Mar 01 00:00:00 1970 PST
+ 660 | 0 | 00660 | Mon Mar 02 00:00:00 1970 PST
+ 661 | 1 | 00661 | Tue Mar 03 00:00:00 1970 PST
+ 663 | 303 | 00663_update3 | Thu Mar 05 00:00:00 1970 PST
+ 664 | 4 | 00664 | Fri Mar 06 00:00:00 1970 PST
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST
+ 668 | 8 | 00668 | Tue Mar 10 00:00:00 1970 PST
+ 669 | 509 | 00669_update9 | Wed Mar 11 00:00:00 1970 PST
+ 670 | 0 | 00670 | Thu Mar 12 00:00:00 1970 PST
+ 671 | 1 | 00671 | Fri Mar 13 00:00:00 1970 PST
+ 673 | 303 | 00673_update3 | Sun Mar 15 00:00:00 1970 PST
+ 674 | 4 | 00674 | Mon Mar 16 00:00:00 1970 PST
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST
+ 678 | 8 | 00678 | Fri Mar 20 00:00:00 1970 PST
+ 679 | 509 | 00679_update9 | Sat Mar 21 00:00:00 1970 PST
+ 680 | 0 | 00680 | Sun Mar 22 00:00:00 1970 PST
+ 681 | 1 | 00681 | Mon Mar 23 00:00:00 1970 PST
+ 683 | 303 | 00683_update3 | Wed Mar 25 00:00:00 1970 PST
+ 684 | 4 | 00684 | Thu Mar 26 00:00:00 1970 PST
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST
+ 688 | 8 | 00688 | Mon Mar 30 00:00:00 1970 PST
+ 689 | 509 | 00689_update9 | Tue Mar 31 00:00:00 1970 PST
+ 690 | 0 | 00690 | Wed Apr 01 00:00:00 1970 PST
+ 691 | 1 | 00691 | Thu Apr 02 00:00:00 1970 PST
+ 693 | 303 | 00693_update3 | Sat Apr 04 00:00:00 1970 PST
+ 694 | 4 | 00694 | Sun Apr 05 00:00:00 1970 PST
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST
+ 698 | 8 | 00698 | Thu Apr 09 00:00:00 1970 PST
+ 699 | 509 | 00699_update9 | Fri Apr 10 00:00:00 1970 PST
+ 700 | 0 | 00700 | Thu Jan 01 00:00:00 1970 PST
+ 701 | 1 | 00701 | Fri Jan 02 00:00:00 1970 PST
+ 703 | 303 | 00703_update3 | Sun Jan 04 00:00:00 1970 PST
+ 704 | 4 | 00704 | Mon Jan 05 00:00:00 1970 PST
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST
+ 708 | 8 | 00708 | Fri Jan 09 00:00:00 1970 PST
+ 709 | 509 | 00709_update9 | Sat Jan 10 00:00:00 1970 PST
+ 710 | 0 | 00710 | Sun Jan 11 00:00:00 1970 PST
+ 711 | 1 | 00711 | Mon Jan 12 00:00:00 1970 PST
+ 713 | 303 | 00713_update3 | Wed Jan 14 00:00:00 1970 PST
+ 714 | 4 | 00714 | Thu Jan 15 00:00:00 1970 PST
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST
+ 718 | 8 | 00718 | Mon Jan 19 00:00:00 1970 PST
+ 719 | 509 | 00719_update9 | Tue Jan 20 00:00:00 1970 PST
+ 720 | 0 | 00720 | Wed Jan 21 00:00:00 1970 PST
+ 721 | 1 | 00721 | Thu Jan 22 00:00:00 1970 PST
+ 723 | 303 | 00723_update3 | Sat Jan 24 00:00:00 1970 PST
+ 724 | 4 | 00724 | Sun Jan 25 00:00:00 1970 PST
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST
+ 728 | 8 | 00728 | Thu Jan 29 00:00:00 1970 PST
+ 729 | 509 | 00729_update9 | Fri Jan 30 00:00:00 1970 PST
+ 730 | 0 | 00730 | Sat Jan 31 00:00:00 1970 PST
+ 731 | 1 | 00731 | Sun Feb 01 00:00:00 1970 PST
+ 733 | 303 | 00733_update3 | Tue Feb 03 00:00:00 1970 PST
+ 734 | 4 | 00734 | Wed Feb 04 00:00:00 1970 PST
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST
+ 738 | 8 | 00738 | Sun Feb 08 00:00:00 1970 PST
+ 739 | 509 | 00739_update9 | Mon Feb 09 00:00:00 1970 PST
+ 740 | 0 | 00740 | Tue Feb 10 00:00:00 1970 PST
+ 741 | 1 | 00741 | Wed Feb 11 00:00:00 1970 PST
+ 743 | 303 | 00743_update3 | Fri Feb 13 00:00:00 1970 PST
+ 744 | 4 | 00744 | Sat Feb 14 00:00:00 1970 PST
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST
+ 748 | 8 | 00748 | Wed Feb 18 00:00:00 1970 PST
+ 749 | 509 | 00749_update9 | Thu Feb 19 00:00:00 1970 PST
+ 750 | 0 | 00750 | Fri Feb 20 00:00:00 1970 PST
+ 751 | 1 | 00751 | Sat Feb 21 00:00:00 1970 PST
+ 753 | 303 | 00753_update3 | Mon Feb 23 00:00:00 1970 PST
+ 754 | 4 | 00754 | Tue Feb 24 00:00:00 1970 PST
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST
+ 758 | 8 | 00758 | Sat Feb 28 00:00:00 1970 PST
+ 759 | 509 | 00759_update9 | Sun Mar 01 00:00:00 1970 PST
+ 760 | 0 | 00760 | Mon Mar 02 00:00:00 1970 PST
+ 761 | 1 | 00761 | Tue Mar 03 00:00:00 1970 PST
+ 763 | 303 | 00763_update3 | Thu Mar 05 00:00:00 1970 PST
+ 764 | 4 | 00764 | Fri Mar 06 00:00:00 1970 PST
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST
+ 768 | 8 | 00768 | Tue Mar 10 00:00:00 1970 PST
+ 769 | 509 | 00769_update9 | Wed Mar 11 00:00:00 1970 PST
+ 770 | 0 | 00770 | Thu Mar 12 00:00:00 1970 PST
+ 771 | 1 | 00771 | Fri Mar 13 00:00:00 1970 PST
+ 773 | 303 | 00773_update3 | Sun Mar 15 00:00:00 1970 PST
+ 774 | 4 | 00774 | Mon Mar 16 00:00:00 1970 PST
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST
+ 778 | 8 | 00778 | Fri Mar 20 00:00:00 1970 PST
+ 779 | 509 | 00779_update9 | Sat Mar 21 00:00:00 1970 PST
+ 780 | 0 | 00780 | Sun Mar 22 00:00:00 1970 PST
+ 781 | 1 | 00781 | Mon Mar 23 00:00:00 1970 PST
+ 783 | 303 | 00783_update3 | Wed Mar 25 00:00:00 1970 PST
+ 784 | 4 | 00784 | Thu Mar 26 00:00:00 1970 PST
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST
+ 788 | 8 | 00788 | Mon Mar 30 00:00:00 1970 PST
+ 789 | 509 | 00789_update9 | Tue Mar 31 00:00:00 1970 PST
+ 790 | 0 | 00790 | Wed Apr 01 00:00:00 1970 PST
+ 791 | 1 | 00791 | Thu Apr 02 00:00:00 1970 PST
+ 793 | 303 | 00793_update3 | Sat Apr 04 00:00:00 1970 PST
+ 794 | 4 | 00794 | Sun Apr 05 00:00:00 1970 PST
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST
+ 798 | 8 | 00798 | Thu Apr 09 00:00:00 1970 PST
+ 799 | 509 | 00799_update9 | Fri Apr 10 00:00:00 1970 PST
+ 800 | 0 | 00800 | Thu Jan 01 00:00:00 1970 PST
+ 801 | 1 | 00801 | Fri Jan 02 00:00:00 1970 PST
+ 803 | 303 | 00803_update3 | Sun Jan 04 00:00:00 1970 PST
+ 804 | 4 | 00804 | Mon Jan 05 00:00:00 1970 PST
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST
+ 808 | 8 | 00808 | Fri Jan 09 00:00:00 1970 PST
+ 809 | 509 | 00809_update9 | Sat Jan 10 00:00:00 1970 PST
+ 810 | 0 | 00810 | Sun Jan 11 00:00:00 1970 PST
+ 811 | 1 | 00811 | Mon Jan 12 00:00:00 1970 PST
+ 813 | 303 | 00813_update3 | Wed Jan 14 00:00:00 1970 PST
+ 814 | 4 | 00814 | Thu Jan 15 00:00:00 1970 PST
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST
+ 818 | 8 | 00818 | Mon Jan 19 00:00:00 1970 PST
+ 819 | 509 | 00819_update9 | Tue Jan 20 00:00:00 1970 PST
+ 820 | 0 | 00820 | Wed Jan 21 00:00:00 1970 PST
+ 821 | 1 | 00821 | Thu Jan 22 00:00:00 1970 PST
+ 823 | 303 | 00823_update3 | Sat Jan 24 00:00:00 1970 PST
+ 824 | 4 | 00824 | Sun Jan 25 00:00:00 1970 PST
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST
+ 828 | 8 | 00828 | Thu Jan 29 00:00:00 1970 PST
+ 829 | 509 | 00829_update9 | Fri Jan 30 00:00:00 1970 PST
+ 830 | 0 | 00830 | Sat Jan 31 00:00:00 1970 PST
+ 831 | 1 | 00831 | Sun Feb 01 00:00:00 1970 PST
+ 833 | 303 | 00833_update3 | Tue Feb 03 00:00:00 1970 PST
+ 834 | 4 | 00834 | Wed Feb 04 00:00:00 1970 PST
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST
+ 838 | 8 | 00838 | Sun Feb 08 00:00:00 1970 PST
+ 839 | 509 | 00839_update9 | Mon Feb 09 00:00:00 1970 PST
+ 840 | 0 | 00840 | Tue Feb 10 00:00:00 1970 PST
+ 841 | 1 | 00841 | Wed Feb 11 00:00:00 1970 PST
+ 843 | 303 | 00843_update3 | Fri Feb 13 00:00:00 1970 PST
+ 844 | 4 | 00844 | Sat Feb 14 00:00:00 1970 PST
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST
+ 848 | 8 | 00848 | Wed Feb 18 00:00:00 1970 PST
+ 849 | 509 | 00849_update9 | Thu Feb 19 00:00:00 1970 PST
+ 850 | 0 | 00850 | Fri Feb 20 00:00:00 1970 PST
+ 851 | 1 | 00851 | Sat Feb 21 00:00:00 1970 PST
+ 853 | 303 | 00853_update3 | Mon Feb 23 00:00:00 1970 PST
+ 854 | 4 | 00854 | Tue Feb 24 00:00:00 1970 PST
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST
+ 858 | 8 | 00858 | Sat Feb 28 00:00:00 1970 PST
+ 859 | 509 | 00859_update9 | Sun Mar 01 00:00:00 1970 PST
+ 860 | 0 | 00860 | Mon Mar 02 00:00:00 1970 PST
+ 861 | 1 | 00861 | Tue Mar 03 00:00:00 1970 PST
+ 863 | 303 | 00863_update3 | Thu Mar 05 00:00:00 1970 PST
+ 864 | 4 | 00864 | Fri Mar 06 00:00:00 1970 PST
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST
+ 868 | 8 | 00868 | Tue Mar 10 00:00:00 1970 PST
+ 869 | 509 | 00869_update9 | Wed Mar 11 00:00:00 1970 PST
+ 870 | 0 | 00870 | Thu Mar 12 00:00:00 1970 PST
+ 871 | 1 | 00871 | Fri Mar 13 00:00:00 1970 PST
+ 873 | 303 | 00873_update3 | Sun Mar 15 00:00:00 1970 PST
+ 874 | 4 | 00874 | Mon Mar 16 00:00:00 1970 PST
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST
+ 878 | 8 | 00878 | Fri Mar 20 00:00:00 1970 PST
+ 879 | 509 | 00879_update9 | Sat Mar 21 00:00:00 1970 PST
+ 880 | 0 | 00880 | Sun Mar 22 00:00:00 1970 PST
+ 881 | 1 | 00881 | Mon Mar 23 00:00:00 1970 PST
+ 883 | 303 | 00883_update3 | Wed Mar 25 00:00:00 1970 PST
+ 884 | 4 | 00884 | Thu Mar 26 00:00:00 1970 PST
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST
+ 888 | 8 | 00888 | Mon Mar 30 00:00:00 1970 PST
+ 889 | 509 | 00889_update9 | Tue Mar 31 00:00:00 1970 PST
+ 890 | 0 | 00890 | Wed Apr 01 00:00:00 1970 PST
+ 891 | 1 | 00891 | Thu Apr 02 00:00:00 1970 PST
+ 893 | 303 | 00893_update3 | Sat Apr 04 00:00:00 1970 PST
+ 894 | 4 | 00894 | Sun Apr 05 00:00:00 1970 PST
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST
+ 898 | 8 | 00898 | Thu Apr 09 00:00:00 1970 PST
+ 899 | 509 | 00899_update9 | Fri Apr 10 00:00:00 1970 PST
+ 900 | 0 | 00900 | Thu Jan 01 00:00:00 1970 PST
+ 901 | 1 | 00901 | Fri Jan 02 00:00:00 1970 PST
+ 903 | 303 | 00903_update3 | Sun Jan 04 00:00:00 1970 PST
+ 904 | 4 | 00904 | Mon Jan 05 00:00:00 1970 PST
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST
+ 908 | 8 | 00908 | Fri Jan 09 00:00:00 1970 PST
+ 909 | 509 | 00909_update9 | Sat Jan 10 00:00:00 1970 PST
+ 910 | 0 | 00910 | Sun Jan 11 00:00:00 1970 PST
+ 911 | 1 | 00911 | Mon Jan 12 00:00:00 1970 PST
+ 913 | 303 | 00913_update3 | Wed Jan 14 00:00:00 1970 PST
+ 914 | 4 | 00914 | Thu Jan 15 00:00:00 1970 PST
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST
+ 918 | 8 | 00918 | Mon Jan 19 00:00:00 1970 PST
+ 919 | 509 | 00919_update9 | Tue Jan 20 00:00:00 1970 PST
+ 920 | 0 | 00920 | Wed Jan 21 00:00:00 1970 PST
+ 921 | 1 | 00921 | Thu Jan 22 00:00:00 1970 PST
+ 923 | 303 | 00923_update3 | Sat Jan 24 00:00:00 1970 PST
+ 924 | 4 | 00924 | Sun Jan 25 00:00:00 1970 PST
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST
+ 928 | 8 | 00928 | Thu Jan 29 00:00:00 1970 PST
+ 929 | 509 | 00929_update9 | Fri Jan 30 00:00:00 1970 PST
+ 930 | 0 | 00930 | Sat Jan 31 00:00:00 1970 PST
+ 931 | 1 | 00931 | Sun Feb 01 00:00:00 1970 PST
+ 933 | 303 | 00933_update3 | Tue Feb 03 00:00:00 1970 PST
+ 934 | 4 | 00934 | Wed Feb 04 00:00:00 1970 PST
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST
+ 938 | 8 | 00938 | Sun Feb 08 00:00:00 1970 PST
+ 939 | 509 | 00939_update9 | Mon Feb 09 00:00:00 1970 PST
+ 940 | 0 | 00940 | Tue Feb 10 00:00:00 1970 PST
+ 941 | 1 | 00941 | Wed Feb 11 00:00:00 1970 PST
+ 943 | 303 | 00943_update3 | Fri Feb 13 00:00:00 1970 PST
+ 944 | 4 | 00944 | Sat Feb 14 00:00:00 1970 PST
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST
+ 948 | 8 | 00948 | Wed Feb 18 00:00:00 1970 PST
+ 949 | 509 | 00949_update9 | Thu Feb 19 00:00:00 1970 PST
+ 950 | 0 | 00950 | Fri Feb 20 00:00:00 1970 PST
+ 951 | 1 | 00951 | Sat Feb 21 00:00:00 1970 PST
+ 953 | 303 | 00953_update3 | Mon Feb 23 00:00:00 1970 PST
+ 954 | 4 | 00954 | Tue Feb 24 00:00:00 1970 PST
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST
+ 958 | 8 | 00958 | Sat Feb 28 00:00:00 1970 PST
+ 959 | 509 | 00959_update9 | Sun Mar 01 00:00:00 1970 PST
+ 960 | 0 | 00960 | Mon Mar 02 00:00:00 1970 PST
+ 961 | 1 | 00961 | Tue Mar 03 00:00:00 1970 PST
+ 963 | 303 | 00963_update3 | Thu Mar 05 00:00:00 1970 PST
+ 964 | 4 | 00964 | Fri Mar 06 00:00:00 1970 PST
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST
+ 968 | 8 | 00968 | Tue Mar 10 00:00:00 1970 PST
+ 969 | 509 | 00969_update9 | Wed Mar 11 00:00:00 1970 PST
+ 970 | 0 | 00970 | Thu Mar 12 00:00:00 1970 PST
+ 971 | 1 | 00971 | Fri Mar 13 00:00:00 1970 PST
+ 973 | 303 | 00973_update3 | Sun Mar 15 00:00:00 1970 PST
+ 974 | 4 | 00974 | Mon Mar 16 00:00:00 1970 PST
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST
+ 978 | 8 | 00978 | Fri Mar 20 00:00:00 1970 PST
+ 979 | 509 | 00979_update9 | Sat Mar 21 00:00:00 1970 PST
+ 980 | 0 | 00980 | Sun Mar 22 00:00:00 1970 PST
+ 981 | 1 | 00981 | Mon Mar 23 00:00:00 1970 PST
+ 983 | 303 | 00983_update3 | Wed Mar 25 00:00:00 1970 PST
+ 984 | 4 | 00984 | Thu Mar 26 00:00:00 1970 PST
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST
+ 988 | 8 | 00988 | Mon Mar 30 00:00:00 1970 PST
+ 989 | 509 | 00989_update9 | Tue Mar 31 00:00:00 1970 PST
+ 990 | 0 | 00990 | Wed Apr 01 00:00:00 1970 PST
+ 991 | 1 | 00991 | Thu Apr 02 00:00:00 1970 PST
+ 993 | 303 | 00993_update3 | Sat Apr 04 00:00:00 1970 PST
+ 994 | 4 | 00994 | Sun Apr 05 00:00:00 1970 PST
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST
+ 998 | 8 | 00998 | Thu Apr 09 00:00:00 1970 PST
+ 999 | 509 | 00999_update9 | Fri Apr 10 00:00:00 1970 PST
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST
+ 1001 | 101 | 0000100001 |
+ 1003 | 403 | 0000300003_update3 |
+ 1004 | 104 | 0000400004 |
+ 1006 | 106 | 0000600006 |
+ 1007 | 507 | 0000700007_update7 |
+ 1008 | 108 | 0000800008 |
+ 1009 | 609 | 0000900009_update9 |
+ 1010 | 100 | 0001000010 |
+ 1011 | 101 | 0001100011 |
+ 1013 | 403 | 0001300013_update3 |
+ 1014 | 104 | 0001400014 |
+ 1016 | 106 | 0001600016 |
+ 1017 | 507 | 0001700017_update7 |
+ 1018 | 108 | 0001800018 |
+ 1019 | 609 | 0001900019_update9 |
+ 1020 | 100 | 0002000020 |
+ 1101 | 201 | aaa |
+ 1103 | 503 | ccc_update3 |
+ 1104 | 204 | ddd |
+(819 rows)
+
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Output: (ft2.tableoid)::regclass
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: 1200, 999, NULL::integer, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+(6 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = 'bar'::text WHERE (("C 1" = 1200))
+(4 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------
+ Delete on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE (("C 1" = 1200))
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+-- Test UPDATE/DELETE with RETURNING on a three-table join
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id - 1200, to_char(id, 'FM00000') FROM generate_series(1201, 1300) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.*, ft4.c1, ft4.c2, ft4.c3
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c3 = 'foo'::text FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (TRUE)) WHERE ((r2.c1 = r3.c1)) AND ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) RETURNING r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3
+(4 rows)
+
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*;
+ ft2 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | ft4 | c1 | c2 | c3
+--------------------------------+------+----+-----+----+----+----+------------+----+----------------+----+----+--------
+ (1206,6,foo,,,,"ft2 ",) | 1206 | 6 | foo | | | | ft2 | | (6,7,AAA006) | 6 | 7 | AAA006
+ (1212,12,foo,,,,"ft2 ",) | 1212 | 12 | foo | | | | ft2 | | (12,13,AAA012) | 12 | 13 | AAA012
+ (1218,18,foo,,,,"ft2 ",) | 1218 | 18 | foo | | | | ft2 | | (18,19,AAA018) | 18 | 19 | AAA018
+ (1224,24,foo,,,,"ft2 ",) | 1224 | 24 | foo | | | | ft2 | | (24,25,AAA024) | 24 | 25 | AAA024
+ (1230,30,foo,,,,"ft2 ",) | 1230 | 30 | foo | | | | ft2 | | (30,31,AAA030) | 30 | 31 | AAA030
+ (1236,36,foo,,,,"ft2 ",) | 1236 | 36 | foo | | | | ft2 | | (36,37,AAA036) | 36 | 37 | AAA036
+ (1242,42,foo,,,,"ft2 ",) | 1242 | 42 | foo | | | | ft2 | | (42,43,AAA042) | 42 | 43 | AAA042
+ (1248,48,foo,,,,"ft2 ",) | 1248 | 48 | foo | | | | ft2 | | (48,49,AAA048) | 48 | 49 | AAA048
+ (1254,54,foo,,,,"ft2 ",) | 1254 | 54 | foo | | | | ft2 | | (54,55,AAA054) | 54 | 55 | AAA054
+ (1260,60,foo,,,,"ft2 ",) | 1260 | 60 | foo | | | | ft2 | | (60,61,AAA060) | 60 | 61 | AAA060
+ (1266,66,foo,,,,"ft2 ",) | 1266 | 66 | foo | | | | ft2 | | (66,67,AAA066) | 66 | 67 | AAA066
+ (1272,72,foo,,,,"ft2 ",) | 1272 | 72 | foo | | | | ft2 | | (72,73,AAA072) | 72 | 73 | AAA072
+ (1278,78,foo,,,,"ft2 ",) | 1278 | 78 | foo | | | | ft2 | | (78,79,AAA078) | 78 | 79 | AAA078
+ (1284,84,foo,,,,"ft2 ",) | 1284 | 84 | foo | | | | ft2 | | (84,85,AAA084) | 84 | 85 | AAA084
+ (1290,90,foo,,,,"ft2 ",) | 1290 | 90 | foo | | | | ft2 | | (90,91,AAA090) | 90 | 91 | AAA090
+ (1296,96,foo,,,,"ft2 ",) | 1296 | 96 | foo | | | | ft2 | | (96,97,AAA096) | 96 | 97 | AAA096
+(16 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: 100
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1)))) WHERE ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) AND (((r1."C 1" % 10) = 0))
+(4 rows)
+
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100;
+ ?column?
+----------
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+(10 rows)
+
+DELETE FROM ft2 WHERE ft2.c1 > 1200;
+-- Test UPDATE with a MULTIEXPR sub-select
+-- (maybe someday this'll be remotely executable, but not today)
+EXPLAIN (verbose, costs off)
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 target
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2, c7 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.ft2 target
+ Output: $1, $2, (SubPlan 1 (returns $1,$2)), target.ctid, target.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1100)) FOR UPDATE
+ SubPlan 1 (returns $1,$2)
+ -> Foreign Scan on public.ft2 src
+ Output: (src.c2 * 10), src.c7
+ Remote SQL: SELECT c2, c7 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(9 rows)
+
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+UPDATE ft2 AS target SET (c2) = (
+ SELECT c2 / 10
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+-- Test UPDATE involving a join that can be pushed down,
+-- but a SET clause that can't be
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 d
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2 WHERE ctid = $1
+ -> Foreign Scan
+ Output: CASE WHEN (random() >= '0'::double precision) THEN d.c2 ELSE 0 END, d.ctid, d.*, t.*
+ Relations: (public.ft2 d) INNER JOIN (public.ft2 t)
+ Remote SQL: SELECT r1.c2, r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r1."C 1" > 1000)))) FOR UPDATE OF r1
+ -> Hash Join
+ Output: d.c2, d.ctid, d.*, t.*
+ Hash Cond: (d.c1 = t.c1)
+ -> Foreign Scan on public.ft2 d
+ Output: d.c2, d.ctid, d.*, d.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1000)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Hash
+ Output: t.*, t.c1
+ -> Foreign Scan on public.ft2 t
+ Output: t.*, t.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(17 rows)
+
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+-- Test UPDATE/DELETE with WHERE or JOIN/ON conditions containing
+-- user-defined operators/functions
+ALTER SERVER loopback OPTIONS (DROP extensions);
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id % 10, to_char(id, 'FM00000') FROM generate_series(2001, 2010) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft2
+ Output: 'bar'::text, ctid, ft2.*
+ Filter: (postgres_fdw_abs(ft2.c1) > 2000)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" FOR UPDATE
+(7 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-----+----+----+----+------------+----
+ 2001 | 1 | bar | | | | ft2 |
+ 2002 | 2 | bar | | | | ft2 |
+ 2003 | 3 | bar | | | | ft2 |
+ 2004 | 4 | bar | | | | ft2 |
+ 2005 | 5 | bar | | | | ft2 |
+ 2006 | 6 | bar | | | | ft2 |
+ 2007 | 7 | bar | | | | ft2 |
+ 2008 | 8 | bar | | | | ft2 |
+ 2009 | 9 | bar | | | | ft2 |
+ 2010 | 0 | bar | | | | ft2 |
+(10 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Nested Loop
+ Output: 'baz'::text, ft2.ctid, ft2.*, ft4.*, ft5.*, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Join Filter: (ft2.c2 === ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.*, ft2.c2
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Relations: (public.ft4) INNER JOIN (public.ft5)
+ Remote SQL: SELECT CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r3.c1, r3.c2, r3.c3 FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1))))
+ -> Hash Join
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(24 rows)
+
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3
+------+----+-----+----+----+----+------------+----+----+----+--------+----+----+--------
+ 2006 | 6 | baz | | | | ft2 | | 6 | 7 | AAA006 | 6 | 7 | AAA006
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ctid = $1 RETURNING "C 1", c2, c3
+ -> Foreign Scan
+ Output: ft2.ctid, ft4.*, ft5.*
+ Filter: (ft4.c1 === ft5.c1)
+ Relations: ((public.ft2) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r2.c1, r3.c1 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c2 = r2.c1)) AND ((r1."C 1" > 2000)))) INNER JOIN "S 1"."T 4" r3 ON (TRUE)) FOR UPDATE OF r1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft5.*, ft4.c1, ft5.c1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft4.c1
+ Join Filter: (ft2.c2 = ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.c2
+ Remote SQL: SELECT c2, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(22 rows)
+
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3;
+ c1 | c2 | c3
+------+----+-----
+ 2006 | 6 | baz
+(1 row)
+
+DELETE FROM ft2 WHERE ft2.c1 > 2000;
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- Test that trigger on remote table works as expected
+CREATE OR REPLACE FUNCTION "S 1".F_BRTRIG() RETURNS trigger AS $$
+BEGIN
+ NEW.c3 = NEW.c3 || '_trig_update';
+ RETURN NEW;
+END;
+$$ LANGUAGE plpgsql;
+CREATE TRIGGER t1_br_insert BEFORE INSERT OR UPDATE
+ ON "S 1"."T 1" FOR EACH ROW EXECUTE PROCEDURE "S 1".F_BRTRIG();
+INSERT INTO ft2 (c1,c2,c3) VALUES (1208, 818, 'fff') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+----+------------+----
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+(1 row)
+
+INSERT INTO ft2 (c1,c2,c3,c6) VALUES (1218, 818, 'ggg', '(--;') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+------+------------+----
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+(1 row)
+
+UPDATE ft2 SET c2 = c2 + 600 WHERE c1 % 10 = 8 AND c1 < 1200 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+------------------------+------------------------------+--------------------------+----+------------+-----
+ 8 | 608 | 00008_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 18 | 608 | 00018_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 28 | 608 | 00028_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 38 | 608 | 00038_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 48 | 608 | 00048_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 58 | 608 | 00058_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 68 | 608 | 00068_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 78 | 608 | 00078_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 88 | 608 | 00088_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 98 | 608 | 00098_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 108 | 608 | 00108_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 118 | 608 | 00118_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 128 | 608 | 00128_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 138 | 608 | 00138_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 148 | 608 | 00148_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 158 | 608 | 00158_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 168 | 608 | 00168_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 178 | 608 | 00178_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 188 | 608 | 00188_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 198 | 608 | 00198_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 208 | 608 | 00208_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 218 | 608 | 00218_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 228 | 608 | 00228_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 238 | 608 | 00238_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 248 | 608 | 00248_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 258 | 608 | 00258_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 268 | 608 | 00268_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 278 | 608 | 00278_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 288 | 608 | 00288_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 298 | 608 | 00298_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 308 | 608 | 00308_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 318 | 608 | 00318_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 328 | 608 | 00328_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 338 | 608 | 00338_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 348 | 608 | 00348_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 358 | 608 | 00358_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 368 | 608 | 00368_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 378 | 608 | 00378_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 388 | 608 | 00388_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 398 | 608 | 00398_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 408 | 608 | 00408_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 418 | 608 | 00418_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 428 | 608 | 00428_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 438 | 608 | 00438_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 448 | 608 | 00448_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 458 | 608 | 00458_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 468 | 608 | 00468_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 478 | 608 | 00478_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 488 | 608 | 00488_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 498 | 608 | 00498_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 508 | 608 | 00508_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 518 | 608 | 00518_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 528 | 608 | 00528_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 538 | 608 | 00538_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 548 | 608 | 00548_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 558 | 608 | 00558_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 568 | 608 | 00568_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 578 | 608 | 00578_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 588 | 608 | 00588_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 598 | 608 | 00598_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 608 | 608 | 00608_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 618 | 608 | 00618_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 628 | 608 | 00628_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 638 | 608 | 00638_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 648 | 608 | 00648_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 658 | 608 | 00658_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 668 | 608 | 00668_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 678 | 608 | 00678_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 688 | 608 | 00688_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 698 | 608 | 00698_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 708 | 608 | 00708_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 718 | 608 | 00718_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 728 | 608 | 00728_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 738 | 608 | 00738_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 748 | 608 | 00748_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 758 | 608 | 00758_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 768 | 608 | 00768_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 778 | 608 | 00778_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 788 | 608 | 00788_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 798 | 608 | 00798_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 808 | 608 | 00808_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 818 | 608 | 00818_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 828 | 608 | 00828_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 838 | 608 | 00838_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 848 | 608 | 00848_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 858 | 608 | 00858_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 868 | 608 | 00868_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 878 | 608 | 00878_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 888 | 608 | 00888_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 898 | 608 | 00898_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 908 | 608 | 00908_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 918 | 608 | 00918_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 928 | 608 | 00928_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 938 | 608 | 00938_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 948 | 608 | 00948_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 958 | 608 | 00958_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 968 | 608 | 00968_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 978 | 608 | 00978_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 988 | 608 | 00988_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 998 | 608 | 00998_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 1008 | 708 | 0000800008_trig_update | | | | ft2 |
+ 1018 | 708 | 0001800018_trig_update | | | | ft2 |
+(102 rows)
+
+-- Test errors thrown on remote side during update
+ALTER TABLE "S 1"."T 1" ADD CONSTRAINT c2positive CHECK (c2 >= 0);
+INSERT INTO ft1(c1, c2) VALUES(11, 12); -- duplicate key
+ERROR: duplicate key value violates unique constraint "t1_pkey"
+DETAIL: Key ("C 1")=(11) already exists.
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT DO NOTHING; -- works
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO NOTHING; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO UPDATE SET c3 = 'ffg'; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+-- Test savepoint/rollback behavior
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+begin;
+update ft2 set c2 = 42 where c2 = 0;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 42 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s1;
+update ft2 set c2 = 44 where c2 = 4;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s1;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s2;
+update ft2 set c2 = 46 where c2 = 6;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 42 | 100
+ 44 | 100
+ 46 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+rollback to savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s3;
+update ft2 set c2 = -2 where c2 = 42 and c1 = 10; -- fail on remote side
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (10, -2, 00010_trig_update_trig_update, 1970-01-11 08:00:00+00, 1970-01-11 00:00:00, 0, 0 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (-2) WHERE ((c2 = 42)) AND (("C 1" = 10))
+rollback to savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+-- none of the above is committed yet remotely
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+commit;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+VACUUM ANALYZE "S 1"."T 1";
+-- Above DMLs add data with c6 as NULL in ft1, so test ORDER BY NULLS LAST and NULLs
+-- FIRST behavior here.
+-- ORDER BY DESC NULLS LAST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 795::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+------+------------+-----
+ 960 | 42 | 00960_trig_update | Mon Mar 02 00:00:00 1970 PST | Mon Mar 02 00:00:00 1970 | 0 | 0 | foo
+ 970 | 42 | 00970_trig_update | Thu Mar 12 00:00:00 1970 PST | Thu Mar 12 00:00:00 1970 | 0 | 0 | foo
+ 980 | 42 | 00980_trig_update | Sun Mar 22 00:00:00 1970 PST | Sun Mar 22 00:00:00 1970 | 0 | 0 | foo
+ 990 | 42 | 00990_trig_update | Wed Apr 01 00:00:00 1970 PST | Wed Apr 01 00:00:00 1970 | 0 | 0 | foo
+ 1000 | 42 | 01000_trig_update | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 1001 | 101 | 0000100001 | | | | ft2 |
+ 1003 | 403 | 0000300003_update3 | | | | ft2 |
+ 1004 | 104 | 0000400004 | | | | ft2 |
+ 1006 | 106 | 0000600006 | | | | ft2 |
+(10 rows)
+
+-- ORDER BY DESC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+------------------------------+--------------------------+----+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | ft2 | foo
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST | Tue Jan 20 00:00:00 1970 | 9 | ft2 | foo
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST | Fri Jan 30 00:00:00 1970 | 9 | ft2 | foo
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST | Mon Feb 09 00:00:00 1970 | 9 | ft2 | foo
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST | Thu Feb 19 00:00:00 1970 | 9 | ft2 | foo
+(10 rows)
+
+-- ORDER BY ASC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 ASC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-------------------+------------------------------+--------------------------+------+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 10 | 42 | 00010_trig_update | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+ 20 | 42 | 00020_trig_update | Wed Jan 21 00:00:00 1970 PST | Wed Jan 21 00:00:00 1970 | 0 | 0 | foo
+ 30 | 42 | 00030_trig_update | Sat Jan 31 00:00:00 1970 PST | Sat Jan 31 00:00:00 1970 | 0 | 0 | foo
+ 40 | 42 | 00040_trig_update | Tue Feb 10 00:00:00 1970 PST | Tue Feb 10 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- ===================================================================
+-- test check constraints
+-- ===================================================================
+-- Consistent check constraints provide consistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- check constraint is enforced on the remote side, not locally
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
+-- But inconsistent check constraints provide inconsistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 821
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- local check constraint is not actually enforced
+INSERT INTO ft1(c1, c2) VALUES(1111, 2);
+UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
+-- ===================================================================
+-- test WITH CHECK OPTION constraints
+-- ===================================================================
+CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
+CREATE TABLE base_tbl (a int, b int);
+ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE VIEW rw_view AS SELECT * FROM foreign_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT foreign_tbl.a,
+ foreign_tbl.b
+ FROM foreign_tbl
+ WHERE foreign_tbl.a < foreign_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 5
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 15
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 5), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 15), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP TRIGGER row_before_insupd_trigger ON base_tbl;
+DROP TABLE base_tbl;
+-- test WCO for partitions
+CREATE TABLE child_tbl (a int, b int);
+ALTER TABLE child_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON child_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'child_tbl');
+CREATE TABLE parent_tbl (a int, b int) PARTITION BY RANGE(a);
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+-- Detach and re-attach once, to stress the concurrent detach case.
+ALTER TABLE parent_tbl DETACH PARTITION foreign_tbl CONCURRENTLY;
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+CREATE VIEW rw_view AS SELECT * FROM parent_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT parent_tbl.a,
+ parent_tbl.b
+ FROM parent_tbl
+ WHERE parent_tbl.a < parent_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 5
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 15
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 5), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 15), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------
+ Insert on public.parent_tbl
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+DROP TRIGGER row_before_insupd_trigger ON child_tbl;
+DROP TABLE parent_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP FUNCTION row_before_insupd_trigfunc;
+-- ===================================================================
+-- test serial columns (ie, sequence-based defaults)
+-- ===================================================================
+create table loc1 (f1 serial, f2 text);
+alter table loc1 set (autovacuum_enabled = 'false');
+create foreign table rem1 (f1 serial, f2 text)
+ server loopback options(table_name 'loc1');
+select pg_catalog.setval('rem1_f1_seq', 10, false);
+ setval
+--------
+ 10
+(1 row)
+
+insert into loc1(f2) values('hi');
+insert into rem1(f2) values('hi remote');
+insert into loc1(f2) values('bye');
+insert into rem1(f2) values('bye remote');
+select * from loc1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+select * from rem1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+-- ===================================================================
+-- test generated columns
+-- ===================================================================
+create table gloc1 (
+ a int,
+ b int generated always as (a * 2) stored);
+alter table gloc1 set (autovacuum_enabled = 'false');
+create foreign table grem1 (
+ a int,
+ b int generated always as (a * 2) stored)
+ server loopback options(table_name 'gloc1');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+explain (verbose, costs off)
+update grem1 set a = 22 where a = 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.grem1
+ Remote SQL: UPDATE public.gloc1 SET a = $2, b = DEFAULT WHERE ctid = $1
+ -> Foreign Scan on public.grem1
+ Output: 22, ctid, grem1.*
+ Remote SQL: SELECT a, b, ctid FROM public.gloc1 WHERE ((a = 2)) FOR UPDATE
+(5 rows)
+
+update grem1 set a = 22 where a = 2;
+select * from gloc1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+select * from grem1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+delete from grem1;
+-- test copy from
+copy grem1 from stdin;
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+-- test batch insert
+alter server loopback options (add batch_size '10');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 10
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test local triggers
+-- ===================================================================
+-- Trigger functions "borrowed" from triggers regress test.
+CREATE FUNCTION trigger_func() RETURNS trigger LANGUAGE plpgsql AS $$
+BEGIN
+ RAISE NOTICE 'trigger_func(%) called: action = %, when = %, level = %',
+ TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN NULL;
+END;$$;
+CREATE TRIGGER trig_stmt_before BEFORE DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE TRIGGER trig_stmt_after AFTER DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE OR REPLACE FUNCTION trigger_data() RETURNS trigger
+LANGUAGE plpgsql AS $$
+
+declare
+ oldnew text[];
+ relid text;
+ argstr text;
+begin
+
+ relid := TG_relid::regclass;
+ argstr := '';
+ for i in 0 .. TG_nargs - 1 loop
+ if i > 0 then
+ argstr := argstr || ', ';
+ end if;
+ argstr := argstr || TG_argv[i];
+ end loop;
+
+ RAISE NOTICE '%(%) % % % ON %',
+ tg_name, argstr, TG_when, TG_level, TG_OP, relid;
+ oldnew := '{}'::text[];
+ if TG_OP != 'INSERT' then
+ oldnew := array_append(oldnew, format('OLD: %s', OLD));
+ end if;
+
+ if TG_OP != 'DELETE' then
+ oldnew := array_append(oldnew, format('NEW: %s', NEW));
+ end if;
+
+ RAISE NOTICE '%', array_to_string(oldnew, ',');
+
+ if TG_OP = 'DELETE' then
+ return OLD;
+ else
+ return NEW;
+ end if;
+end;
+$$;
+-- Test basic functionality
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+delete from rem1;
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = AFTER, level = STATEMENT
+insert into rem1 values(1,'insert');
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+update rem1 set f2 = f2 || f2;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+truncate rem1;
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = BEFORE, level = STATEMENT
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = AFTER, level = STATEMENT
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_stmt_before ON rem1;
+DROP TRIGGER trig_stmt_after ON rem1;
+DELETE from rem1;
+-- Test multiple AFTER ROW triggers on a foreign table
+CREATE TRIGGER trig_row_after1
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after2
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+insert into rem1 values(1,'insert');
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+update rem1 set f2 = f2 || f2;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+delete from rem1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+-- cleanup
+DROP TRIGGER trig_row_after1 ON rem1;
+DROP TRIGGER trig_row_after2 ON rem1;
+-- Test WHEN conditions
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_insupd
+AFTER INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Insert or update not matching: nothing happens
+INSERT INTO rem1 values(1, 'insert');
+UPDATE rem1 set f2 = 'test';
+-- Insert or update matching: triggers are fired
+INSERT INTO rem1 values(2, 'update');
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+UPDATE rem1 set f2 = 'update update' where f1 = '2';
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Trigger is fired for f1=2, not for f1=1
+DELETE FROM rem1;
+NOTICE: trig_row_before_delete(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+NOTICE: trig_row_after_delete(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+-- cleanup
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_after_insupd ON rem1;
+DROP TRIGGER trig_row_before_delete ON rem1;
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- Test various RETURN statements in BEFORE triggers.
+CREATE FUNCTION trig_row_before_insupdate() RETURNS TRIGGER AS $$
+ BEGIN
+ NEW.f2 := NEW.f2 || ' triggered !';
+ RETURN NEW;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+-- The new values should have 'triggered' appended
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------
+ insert triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+ 2 | insert triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------
+ 1 | triggered !
+ 2 | triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------
+ skidoo triggered !
+ skidoo triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | skidoo triggered !
+ 2 | skidoo triggered !
+(2 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f1 = 10; -- all columns should be transmitted
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: 10, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+UPDATE rem1 set f1 = 10;
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 10 | skidoo triggered ! triggered !
+ 10 | skidoo triggered ! triggered !
+(2 rows)
+
+DELETE FROM rem1;
+-- Add a second trigger, to check that the changes are propagated correctly
+-- from trigger to trigger
+CREATE TRIGGER trig_row_before_insupd2
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------------------
+ insert triggered ! triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+ 2 | insert triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------
+ 1 | triggered ! triggered !
+ 2 | triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------------------
+ skidoo triggered ! triggered !
+ skidoo triggered ! triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | skidoo triggered ! triggered !
+ 2 | skidoo triggered ! triggered !
+(2 rows)
+
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_before_insupd2 ON rem1;
+DELETE from rem1;
+INSERT INTO rem1 VALUES (1, 'test');
+-- Test with a trigger returning NULL
+CREATE FUNCTION trig_null() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_null
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_null();
+-- Nothing should have changed.
+INSERT INTO rem1 VALUES (2, 'test2');
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+UPDATE rem1 SET f2 = 'test2';
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DELETE from rem1;
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DROP TRIGGER trig_null ON rem1;
+DELETE from rem1;
+-- Test a combination of local and remote triggers
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_local_before BEFORE INSERT OR UPDATE ON loc1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1(f2) VALUES ('test');
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (12,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (12,"test triggered !")
+UPDATE rem1 SET f2 = 'testo';
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,testo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,"testo triggered !")
+-- Test returning a system attribute
+INSERT INTO rem1(f2) VALUES ('test') RETURNING ctid;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (13,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (13,"test triggered !")
+ ctid
+--------
+ (0,25)
+(1 row)
+
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_local_before ON loc1;
+-- Test direct foreign table modification functionality
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1 WHERE false; -- currently can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Result
+ Output: ctid
+ One-Time Filter: false
+(5 rows)
+
+-- Test with statement-level triggers
+CREATE TRIGGER trig_stmt_before
+ BEFORE DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_before ON rem1;
+CREATE TRIGGER trig_stmt_after
+ AFTER DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_after ON rem1;
+-- Test with row-level ON INSERT triggers
+CREATE TRIGGER trig_row_before_insert
+BEFORE INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_insert ON rem1;
+CREATE TRIGGER trig_row_after_insert
+AFTER INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_insert ON rem1;
+-- Test with row-level ON UPDATE triggers
+CREATE TRIGGER trig_row_before_update
+BEFORE UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_update ON rem1;
+CREATE TRIGGER trig_row_after_update
+AFTER UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = $2 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_update ON rem1;
+-- Test with row-level ON DELETE triggers
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_before_delete ON rem1;
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- ===================================================================
+-- test inheritance features
+-- ===================================================================
+CREATE TABLE a (aa TEXT);
+CREATE TABLE loct (aa TEXT, bb TEXT);
+ALTER TABLE a SET (autovacuum_enabled = 'false');
+ALTER TABLE loct SET (autovacuum_enabled = 'false');
+CREATE FOREIGN TABLE b (bb TEXT) INHERITS (a)
+ SERVER loopback OPTIONS (table_name 'loct');
+INSERT INTO a(aa) VALUES('aaa');
+INSERT INTO a(aa) VALUES('aaaa');
+INSERT INTO a(aa) VALUES('aaaaa');
+INSERT INTO b(aa) VALUES('bbb');
+INSERT INTO b(aa) VALUES('bbbb');
+INSERT INTO b(aa) VALUES('bbbbb');
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+(3 rows)
+
+UPDATE a SET aa = 'zzzzzz' WHERE aa LIKE 'aaaa%';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE b SET aa = 'new';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | new
+ b | new
+ b | new
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-----+----
+ b | new |
+ b | new |
+ b | new |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE a SET aa = 'newtoo';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+ b | newtoo
+ b | newtoo
+ b | newtoo
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+--------+----
+ b | newtoo |
+ b | newtoo |
+ b | newtoo |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+(3 rows)
+
+DELETE FROM a;
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+----+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+DROP TABLE a CASCADE;
+NOTICE: drop cascades to foreign table b
+DROP TABLE loct;
+-- Check SELECT FOR UPDATE/SHARE with an inherited source table
+create table loct1 (f1 int, f2 int, f3 int);
+create table loct2 (f1 int, f2 int, f3 int);
+alter table loct1 set (autovacuum_enabled = 'false');
+alter table loct2 set (autovacuum_enabled = 'false');
+create table foo (f1 int, f2 int);
+create foreign table foo2 (f3 int) inherits (foo)
+ server loopback options (table_name 'loct1');
+create table bar (f1 int, f2 int);
+create foreign table bar2 (f3 int) inherits (bar)
+ server loopback options (table_name 'loct2');
+alter table foo set (autovacuum_enabled = 'false');
+alter table bar set (autovacuum_enabled = 'false');
+insert into foo values(1,1);
+insert into foo values(3,3);
+insert into foo2 values(2,2,2);
+insert into foo2 values(4,4,4);
+insert into bar values(1,11);
+insert into bar values(2,22);
+insert into bar values(6,66);
+insert into bar2 values(3,33,33);
+insert into bar2 values(4,44,44);
+insert into bar2 values(7,77,77);
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for update;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for update;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for share;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for share;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+-- Now check SELECT FOR UPDATE/SHARE with an inherited source table,
+-- where the parent is itself a foreign table
+create table loct4 (f1 int, f2 int, f3 int);
+create foreign table foo2child (f3 int) inherits (foo2)
+ server loopback options (table_name 'loct4');
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct1
+ -> Foreign Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct4
+(24 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop foreign table foo2child;
+-- And with a local child relation of the foreign table parent
+create table foo2child (f3 int) inherits (foo2);
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.ctid, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+ -> Seq Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.ctid, foo2_2.tableoid
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop table foo2child;
+-- Check UPDATE with inherited target and an inherited source table
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Hash Join
+ Output: (bar.f2 + 100), foo.ctid, bar.tableoid, bar.ctid, (NULL::record), foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(25 rows)
+
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 111
+ bar | 2 | 122
+ bar | 6 | 66
+ bar2 | 3 | 133
+ bar2 | 4 | 144
+ bar2 | 7 | 77
+(6 rows)
+
+-- Check UPDATE with inherited target and an appendrel subquery
+explain (verbose, costs off)
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Merge Join
+ Output: (bar.f2 + 100), (ROW(foo.f1)), bar.tableoid, bar.ctid, (NULL::record)
+ Merge Cond: (bar.f1 = foo.f1)
+ -> Sort
+ Output: bar.f2, bar.f1, bar.tableoid, bar.ctid, (NULL::record)
+ Sort Key: bar.f1
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Sort
+ Output: (ROW(foo.f1)), foo.f1
+ Sort Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: ROW(foo.f1), foo.f1
+ -> Foreign Scan on public.foo2 foo_1
+ Output: ROW(foo_1.f1), foo_1.f1
+ Remote SQL: SELECT f1 FROM public.loct1
+ -> Seq Scan on public.foo foo_2
+ Output: ROW((foo_2.f1 + 3)), (foo_2.f1 + 3)
+ -> Foreign Scan on public.foo2 foo_3
+ Output: ROW((foo_3.f1 + 3)), (foo_3.f1 + 3)
+ Remote SQL: SELECT f1 FROM public.loct1
+(30 rows)
+
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 211
+ bar | 2 | 222
+ bar | 6 | 166
+ bar2 | 3 | 233
+ bar2 | 4 | 244
+ bar2 | 7 | 177
+(6 rows)
+
+-- Test forcing the remote server to produce sorted data for a merge join,
+-- but the foreign table is an inheritance child.
+truncate table loct1;
+truncate table only foo;
+\set num_rows_foo 2000
+insert into loct1 select generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2);
+insert into foo select generate_series(1, :num_rows_foo, 2), generate_series(1, :num_rows_foo, 2);
+SET enable_hashjoin to false;
+SET enable_nestloop to false;
+alter foreign table foo2 options (use_remote_estimate 'true');
+create index i_loct1_f1 on loct1(f1);
+create index i_foo_f1 on foo(f1);
+analyze foo;
+analyze loct1;
+-- inner join; expressions in the clauses appear in the equivalence class list
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 20 | 20
+ 22 | 22
+ 24 | 24
+ 26 | 26
+ 28 | 28
+ 30 | 30
+ 32 | 32
+ 34 | 34
+ 36 | 36
+ 38 | 38
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Left Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 10 | 10
+ 11 |
+ 12 | 12
+ 13 |
+ 14 | 14
+ 15 |
+ 16 | 16
+ 17 |
+ 18 | 18
+ 19 |
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test that WHERE CURRENT OF is not supported
+begin;
+declare c cursor for select * from bar where f1 = 7;
+fetch from c;
+ f1 | f2
+----+-----
+ 7 | 177
+(1 row)
+
+update bar set f2 = null where current of c;
+ERROR: WHERE CURRENT OF is not supported for this table type
+rollback;
+explain (verbose, costs off)
+delete from foo where f1 < 5 returning *;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Delete on public.foo
+ Output: foo_1.f1, foo_1.f2
+ Delete on public.foo foo_1
+ Foreign Delete on public.foo2 foo_2
+ -> Append
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.tableoid, foo_1.ctid
+ Index Cond: (foo_1.f1 < 5)
+ -> Foreign Delete on public.foo2 foo_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ((f1 < 5)) RETURNING f1, f2
+(10 rows)
+
+delete from foo where f1 < 5 returning *;
+ f1 | f2
+----+----
+ 1 | 1
+ 3 | 3
+ 0 | 0
+ 2 | 2
+ 4 | 4
+(5 rows)
+
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Update on public.bar
+ Output: bar_1.f1, bar_1.f2
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = (f2 + 100) RETURNING f1, f2
+(11 rows)
+
+update bar set f2 = f2 + 100 returning *;
+ f1 | f2
+----+-----
+ 1 | 311
+ 2 | 322
+ 6 | 266
+ 3 | 333
+ 4 | 344
+ 7 | 277
+(6 rows)
+
+-- Test that UPDATE/DELETE with inherited target works with row-level triggers
+CREATE TRIGGER trig_row_before
+BEFORE UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+explain (verbose, costs off)
+update bar set f2 = f2 + 100;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f1 = $2, f2 = $3, f3 = $4 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+(12 rows)
+
+update bar set f2 = f2 + 100;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+explain (verbose, costs off)
+delete from bar where f2 < 400;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Delete on public.bar
+ Delete on public.bar bar_1
+ Foreign Delete on public.bar2 bar_2
+ Remote SQL: DELETE FROM public.loct2 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.tableoid, bar_1.ctid, NULL::record
+ Filter: (bar_1.f2 < 400)
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 WHERE ((f2 < 400)) FOR UPDATE
+(11 rows)
+
+delete from bar where f2 < 400;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+-- cleanup
+drop table foo cascade;
+NOTICE: drop cascades to foreign table foo2
+drop table bar cascade;
+NOTICE: drop cascades to foreign table bar2
+drop table loct1;
+drop table loct2;
+-- Test pushing down UPDATE/DELETE joins to the remote server
+create table parent (a int, b text);
+create table loct1 (a int, b text);
+create table loct2 (a int, b text);
+create foreign table remt1 (a int, b text)
+ server loopback options (table_name 'loct1');
+create foreign table remt2 (a int, b text)
+ server loopback options (table_name 'loct2');
+alter foreign table remt1 inherit parent;
+insert into remt1 values (1, 'foo');
+insert into remt1 values (2, 'bar');
+insert into remt2 values (1, 'foo');
+insert into remt2 values (2, 'bar');
+analyze remt1;
+analyze remt2;
+explain (verbose, costs off)
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.parent
+ Output: parent_1.a, parent_1.b, remt2.a, remt2.b
+ Update on public.parent parent_1
+ Foreign Update on public.remt1 parent_2
+ Remote SQL: UPDATE public.loct1 SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: (parent.b || remt2.b), remt2.*, remt2.a, remt2.b, parent.tableoid, parent.ctid, (NULL::record)
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.b, parent_1.a, parent_1.tableoid, parent_1.ctid, NULL::record
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.b, parent_2.a, parent_2.tableoid, parent_2.ctid, parent_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.b, remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.b, remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ a | b | a | b
+---+--------+---+-----
+ 1 | foofoo | 1 | foo
+ 2 | barbar | 2 | bar
+(2 rows)
+
+explain (verbose, costs off)
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Delete on public.parent
+ Output: parent_1.*
+ Delete on public.parent parent_1
+ Foreign Delete on public.remt1 parent_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: remt2.*, parent.tableoid, parent.ctid
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.a, parent_1.tableoid, parent_1.ctid
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.a, parent_2.tableoid, parent_2.ctid
+ Remote SQL: SELECT a, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ parent
+------------
+ (1,foofoo)
+ (2,barbar)
+(2 rows)
+
+-- cleanup
+drop foreign table remt1;
+drop foreign table remt2;
+drop table loct1;
+drop table loct2;
+drop table parent;
+-- ===================================================================
+-- test tuple routing for foreign-table partitions
+-- ===================================================================
+-- Test insert tuple routing
+create table itrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table itrtest attach partition remp1 for values in (1);
+alter table itrtest attach partition remp2 for values in (2);
+insert into itrtest values (1, 'foo');
+insert into itrtest values (1, 'bar') returning *;
+ a | b
+---+-----
+ 1 | bar
+(1 row)
+
+insert into itrtest values (2, 'baz');
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----
+ 2 | qux
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------
+ 1 | test1
+ 2 | test2
+(2 rows)
+
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from itrtest;
+-- MERGE ought to fail cleanly
+merge into itrtest using (select 1, 'foo') as source on (true)
+ when matched then do nothing;
+ERROR: cannot execute MERGE on relation "remp1"
+DETAIL: This operation is not supported for foreign tables.
+create unique index loct1_idx on loct1 (a);
+-- DO NOTHING without an inference specification is supported
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+-----
+ 1 | foo
+(1 row)
+
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+---
+(0 rows)
+
+-- But other cases are not supported
+insert into itrtest values (1, 'bar') on conflict (a) do nothing;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+insert into itrtest values (1, 'bar') on conflict (a) do update set b = excluded.b;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+delete from itrtest;
+drop index loct1_idx;
+-- Test that remote triggers work with insert tuple routing
+create function br_insert_trigfunc() returns trigger as $$
+begin
+ new.b := new.b || ' triggered !';
+ return new;
+end
+$$ language plpgsql;
+create trigger loct1_br_insert_trigger before insert on loct1
+ for each row execute procedure br_insert_trigfunc();
+create trigger loct2_br_insert_trigger before insert on loct2
+ for each row execute procedure br_insert_trigfunc();
+-- The new values are concatenated with ' triggered !'
+insert into itrtest values (1, 'foo') returning *;
+ a | b
+---+-----------------
+ 1 | foo triggered !
+(1 row)
+
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----------------
+ 2 | qux triggered !
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+with result as (insert into itrtest values (1, 'test1'), (2, 'test2') returning *) select * from result;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+drop trigger loct1_br_insert_trigger on loct1;
+drop trigger loct2_br_insert_trigger on loct2;
+drop table itrtest;
+drop table loct1;
+drop table loct2;
+-- Test update tuple routing
+create table utrtest (a int, b text) partition by list (a);
+create table loct (a int check (a in (1)), b text);
+create foreign table remp (a int check (a in (1)), b text) server loopback options (table_name 'loct');
+create table locp (a int check (a in (2)), b text);
+alter table utrtest attach partition remp for values in (1);
+alter table utrtest attach partition locp for values in (2);
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- It's not allowed to move a row from a partition that is foreign to another
+update utrtest set a = 2 where b = 'foo' returning *;
+ERROR: new row for relation "loct" violates check constraint "loct_a_check"
+DETAIL: Failing row contains (2, foo).
+CONTEXT: remote SQL command: UPDATE public.loct SET a = 2 WHERE ((b = 'foo')) RETURNING a, b
+-- But the reverse is allowed
+update utrtest set a = 1 where b = 'qux' returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- The executor should not let unexercised FDWs shut down
+update utrtest set a = 1 where b = 'foo';
+-- Test that remote triggers work with update tuple routing
+create trigger loct_br_insert_trigger before insert on loct
+ for each row execute procedure br_insert_trigfunc();
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition is a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 WHERE (((a = 1) OR (a = 2))) RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ Filter: ((utrtest_2.a = 1) OR (utrtest_2.a = 2))
+(10 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition isn't a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 2 returning *;
+ QUERY PLAN
+-------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ -> Seq Scan on public.locp utrtest_1
+ Output: 1, utrtest_1.tableoid, utrtest_1.ctid
+ Filter: (utrtest_1.a = 2)
+(6 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 2 returning *;
+ a | b
+---+-----------------
+ 1 | qux triggered !
+(1 row)
+
+drop trigger loct_br_insert_trigger on loct;
+-- We can move rows to a foreign partition that has been updated already,
+-- but can't move rows to a foreign partition that hasn't been updated yet
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- Test the former case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+(9 rows)
+
+update utrtest set a = 1 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ Update on public.locp utrtest_2
+ -> Hash Join
+ Output: 1, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, utrtest.*
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Foreign Scan on public.remp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, utrtest_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Seq Scan on public.locp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- Change the definition of utrtest so that the foreign partition get updated
+-- after the local partition
+delete from utrtest;
+alter table utrtest detach partition remp;
+drop foreign table remp;
+alter table loct drop constraint loct_a_check;
+alter table loct add check (a in (3));
+create foreign table remp (a int check (a in (3)), b text) server loopback options (table_name 'loct');
+alter table utrtest attach partition remp for values in (3);
+insert into utrtest values (2, 'qux');
+insert into utrtest values (3, 'xyzzy');
+-- Test the latter case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: 3, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = 3 RETURNING a, b
+(9 rows)
+
+update utrtest set a = 3 returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ -> Hash Join
+ Output: 3, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, (NULL::record)
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Scan on public.remp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, utrtest_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+drop table utrtest;
+drop table loct;
+-- Test copy tuple routing
+create table ctrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table ctrtest attach partition remp1 for values in (1);
+alter table ctrtest attach partition remp2 for values in (2);
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp2 | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-----+---
+ remp2 | qux | 2
+(1 row)
+
+-- Copying into foreign partitions directly should work as well
+copy remp1 from stdin;
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+(2 rows)
+
+delete from ctrtest;
+-- Test copy tuple routing with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from ctrtest;
+alter server loopback options (drop batch_size);
+drop table ctrtest;
+drop table loct1;
+drop table loct2;
+-- ===================================================================
+-- test COPY FROM
+-- ===================================================================
+create table loc2 (f1 int, f2 text);
+alter table loc2 set (autovacuum_enabled = 'false');
+create foreign table rem2 (f1 int, f2 text) server loopback options(table_name 'loc2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2, line 1: "-1 xyzzy"
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test local triggers
+create trigger trig_stmt_before before insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_stmt_after after insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+copy rem2 from stdin;
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop trigger trig_row_before on rem2;
+drop trigger trig_row_after on rem2;
+drop trigger trig_stmt_before on rem2;
+drop trigger trig_stmt_after on rem2;
+delete from rem2;
+create trigger trig_row_before_insert before insert on rem2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on rem2;
+delete from rem2;
+create trigger trig_null before insert on rem2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on rem2;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Test a combination of local and remote triggers
+create trigger rem2_trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger rem2_trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger loc2_trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+copy rem2 from stdin;
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,"foo triggered !")
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,"bar triggered !")
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger rem2_trig_row_before on rem2;
+drop trigger rem2_trig_row_after on rem2;
+drop trigger loc2_trig_row_before_insert on loc2;
+delete from rem2;
+-- test COPY FROM with foreign table created in the same transaction
+create table loc3 (f1 int, f2 text);
+begin;
+create foreign table rem3 (f1 int, f2 text)
+ server loopback options(table_name 'loc3');
+copy rem3 from stdin;
+commit;
+select * from rem3;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop foreign table rem3;
+drop table loc3;
+-- Test COPY FROM with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+ 3 | baz triggered !
+(3 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Check with zero-column foreign table; batch insert will be disabled
+alter table loc2 drop column f1;
+alter table loc2 drop column f2;
+alter table rem2 drop column f1;
+alter table rem2 drop column f2;
+copy rem2 from stdin;
+select * from rem2;
+--
+(3 rows)
+
+delete from rem2;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test for TRUNCATE
+-- ===================================================================
+CREATE TABLE tru_rtable0 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable0');
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(1,10) x);
+CREATE TABLE tru_ptable (id int) PARTITION BY HASH(id);
+CREATE TABLE tru_ptable__p0 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tru_rtable1 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable__p1 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback OPTIONS (table_name 'tru_rtable1');
+INSERT INTO tru_ptable (SELECT x FROM generate_series(11,20) x);
+CREATE TABLE tru_pk_table(id int primary key);
+CREATE TABLE tru_fk_table(fkey int references tru_pk_table(id));
+INSERT INTO tru_pk_table (SELECT x FROM generate_series(1,10) x);
+INSERT INTO tru_fk_table (SELECT x % 10 + 1 FROM generate_series(5,25) x);
+CREATE FOREIGN TABLE tru_pk_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_pk_table');
+CREATE TABLE tru_rtable_parent (id int);
+CREATE TABLE tru_rtable_child (id int);
+CREATE FOREIGN TABLE tru_ftable_parent (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_parent');
+CREATE FOREIGN TABLE tru_ftable_child () INHERITS (tru_ftable_parent)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_child');
+INSERT INTO tru_rtable_parent (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_rtable_child (SELECT x FROM generate_series(10, 18) x);
+-- normal truncate
+SELECT sum(id) FROM tru_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_ftable;
+SELECT count(*) FROM tru_rtable0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'truncatable' option
+ALTER SERVER loopback OPTIONS (ADD truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (ADD truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER SERVER loopback OPTIONS (DROP truncatable);
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+-- partitioned table with both local and foreign tables as partitions
+SELECT sum(id) FROM tru_ptable; -- 155
+ sum
+-----
+ 155
+(1 row)
+
+TRUNCATE tru_ptable;
+SELECT count(*) FROM tru_ptable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ptable__p0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable__p1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_rtable1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'CASCADE' option
+SELECT sum(id) FROM tru_pk_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_pk_ftable; -- failed by FK reference
+ERROR: cannot truncate a table referenced in a foreign key constraint
+DETAIL: Table "tru_fk_table" references "tru_pk_table".
+HINT: Truncate table "tru_fk_table" at the same time, or use TRUNCATE ... CASCADE.
+CONTEXT: remote SQL command: TRUNCATE public.tru_pk_table CONTINUE IDENTITY RESTRICT
+TRUNCATE tru_pk_ftable CASCADE;
+SELECT count(*) FROM tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_fk_table; -- also truncated,0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate two tables at a command
+INSERT INTO tru_ftable (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_pk_ftable (SELECT x FROM generate_series(3,10) x);
+SELECT count(*) from tru_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+TRUNCATE tru_ftable, tru_pk_ftable CASCADE;
+SELECT count(*) from tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate with ONLY clause
+-- Since ONLY is specified, the table tru_ftable_child that inherits
+-- tru_ftable_parent locally is not truncated.
+TRUNCATE ONLY tru_ftable_parent;
+SELECT sum(id) FROM tru_ftable_parent; -- 126
+ sum
+-----
+ 126
+(1 row)
+
+TRUNCATE tru_ftable_parent;
+SELECT count(*) FROM tru_ftable_parent; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- in case when remote table has inherited children
+CREATE TABLE tru_rtable0_child () INHERITS (tru_rtable0);
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(5,9) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(10,14) x);
+SELECT sum(id) FROM tru_ftable; -- 95
+ sum
+-----
+ 95
+(1 row)
+
+-- Both parent and child tables in the foreign server are truncated
+-- even though ONLY is specified because ONLY has no effect
+-- when truncating a foreign table.
+TRUNCATE ONLY tru_ftable;
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(21,25) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(26,30) x);
+SELECT sum(id) FROM tru_ftable; -- 255
+ sum
+-----
+ 255
+(1 row)
+
+TRUNCATE tru_ftable; -- truncate both of parent and child
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- cleanup
+DROP FOREIGN TABLE tru_ftable_parent, tru_ftable_child, tru_pk_ftable,tru_ftable__p1,tru_ftable;
+DROP TABLE tru_rtable0, tru_rtable1, tru_ptable, tru_ptable__p0, tru_pk_table, tru_fk_table,
+tru_rtable_parent,tru_rtable_child, tru_rtable0_child;
+-- ===================================================================
+-- test IMPORT FOREIGN SCHEMA
+-- ===================================================================
+CREATE SCHEMA import_source;
+CREATE TABLE import_source.t1 (c1 int, c2 varchar NOT NULL);
+CREATE TABLE import_source.t2 (c1 int default 42, c2 varchar NULL, c3 text collate "POSIX");
+CREATE TYPE typ1 AS (m1 int, m2 varchar);
+CREATE TABLE import_source.t3 (c1 timestamptz default now(), c2 typ1);
+CREATE TABLE import_source."x 4" (c1 float8, "C 2" text, c3 varchar(42));
+CREATE TABLE import_source."x 5" (c1 float8);
+ALTER TABLE import_source."x 5" DROP COLUMN c1;
+CREATE TABLE import_source."x 6" (c1 int, c2 int generated always as (c1 * 2) stored);
+CREATE TABLE import_source.t4 (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE import_source.t4_part PARTITION OF import_source.t4
+ FOR VALUES FROM (1) TO (100);
+CREATE TABLE import_source.t4_part2 PARTITION OF import_source.t4
+ FOR VALUES FROM (100) TO (200);
+CREATE SCHEMA import_dest1;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest1;
+\det+ import_dest1.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest1 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest1 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest1 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest1 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest1 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest1 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest1 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest1.*
+ Foreign table "import_dest1.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest1.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest1.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest1.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest1.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest1.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest1.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Options
+CREATE SCHEMA import_dest2;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest2
+ OPTIONS (import_default 'true');
+\det+ import_dest2.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest2 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest2 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest2 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest2 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest2 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest2 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest2 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest2.*
+ Foreign table "import_dest2.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest2.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | 42 | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest2.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | now() | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest2.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest2.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest2.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest2.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+CREATE SCHEMA import_dest3;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest3
+ OPTIONS (import_collate 'false', import_generated 'false', import_not_null 'false');
+\det+ import_dest3.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest3 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest3 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest3 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest3 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest3 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest3 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest3 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest3.*
+ Foreign table "import_dest3.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest3.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest3.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest3.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest3.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest3.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest3.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Check LIMIT TO and EXCEPT
+CREATE SCHEMA import_dest4;
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t1, nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+(2 rows)
+
+IMPORT FOREIGN SCHEMA import_source EXCEPT (t1, "x 4", nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest4 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest4 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+ import_dest4 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest4 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+-- Assorted error cases
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest4;
+ERROR: relation "t1" already exists
+CONTEXT: importing foreign table "t1"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO import_dest4;
+ERROR: schema "nonesuch" is not present on foreign server "loopback"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO notthere;
+ERROR: schema "notthere" does not exist
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER nowhere INTO notthere;
+ERROR: server "nowhere" does not exist
+-- Check case of a type present only on the remote server.
+-- We can fake this by dropping the type locally in our transaction.
+CREATE TYPE "Colors" AS ENUM ('red', 'green', 'blue');
+CREATE TABLE import_source.t5 (c1 int, c2 text collate "C", "Col" "Colors");
+CREATE SCHEMA import_dest5;
+BEGIN;
+DROP TYPE "Colors" CASCADE;
+NOTICE: drop cascades to column Col of table import_source.t5
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t5)
+ FROM SERVER loopback INTO import_dest5; -- ERROR
+ERROR: type "public.Colors" does not exist
+LINE 4: "Col" public."Colors" OPTIONS (column_name 'Col')
+ ^
+QUERY: CREATE FOREIGN TABLE t5 (
+ c1 integer OPTIONS (column_name 'c1'),
+ c2 text OPTIONS (column_name 'c2') COLLATE pg_catalog."C",
+ "Col" public."Colors" OPTIONS (column_name 'Col')
+) SERVER loopback
+OPTIONS (schema_name 'import_source', table_name 't5');
+CONTEXT: importing foreign table "t5"
+ROLLBACK;
+BEGIN;
+CREATE SERVER fetch101 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( fetch_size '101' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER fetch101 OPTIONS( SET fetch_size '202' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=202'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30000 ( x int ) SERVER fetch101 OPTIONS ( fetch_size '30000' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '60000');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=60000'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- ===================================================================
+-- test partitionwise joins
+-- ===================================================================
+SET enable_partitionwise_join=on;
+CREATE TABLE fprt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE fprt1_p1 (LIKE fprt1);
+CREATE TABLE fprt1_p2 (LIKE fprt1);
+ALTER TABLE fprt1_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt1_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt1_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 2) i;
+INSERT INTO fprt1_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 2) i;
+CREATE FOREIGN TABLE ftprt1_p1 PARTITION OF fprt1 FOR VALUES FROM (0) TO (250)
+ SERVER loopback OPTIONS (table_name 'fprt1_p1', use_remote_estimate 'true');
+CREATE FOREIGN TABLE ftprt1_p2 PARTITION OF fprt1 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (TABLE_NAME 'fprt1_p2');
+ANALYZE fprt1;
+ANALYZE fprt1_p1;
+ANALYZE fprt1_p2;
+CREATE TABLE fprt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE fprt2_p1 (LIKE fprt2);
+CREATE TABLE fprt2_p2 (LIKE fprt2);
+ALTER TABLE fprt2_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt2_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt2_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 3) i;
+INSERT INTO fprt2_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 3) i;
+CREATE FOREIGN TABLE ftprt2_p1 (b int, c varchar, a int)
+ SERVER loopback OPTIONS (table_name 'fprt2_p1', use_remote_estimate 'true');
+ALTER TABLE fprt2 ATTACH PARTITION ftprt2_p1 FOR VALUES FROM (0) TO (250);
+CREATE FOREIGN TABLE ftprt2_p2 PARTITION OF fprt2 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (table_name 'fprt2_p2', use_remote_estimate 'true');
+ANALYZE fprt2;
+ANALYZE fprt2_p1;
+ANALYZE fprt2_p2;
+-- inner join three tables
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t3.c
+ -> Append
+ -> Foreign Scan
+ Relations: ((ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)) INNER JOIN (ftprt1_p1 t3_1)
+ -> Foreign Scan
+ Relations: ((ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)) INNER JOIN (ftprt1_p2 t3_2)
+(7 rows)
+
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0003
+ 250 | 250 | 0005
+ 400 | 400 | 0008
+(4 rows)
+
+-- left outer join + nullable clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.a, fprt2.b, fprt2.c
+ Relations: (public.ftprt1_p1 t1) LEFT JOIN (public.ftprt2_p1 fprt2)
+ Remote SQL: SELECT r5.a, r6.b, r6.c FROM (public.fprt1_p1 r5 LEFT JOIN public.fprt2_p1 r6 ON (((r5.a = r6.b)) AND ((r5.b = r6.a)) AND ((r6.a < 10)))) WHERE ((r5.a < 10)) ORDER BY r5.a ASC NULLS LAST, r6.b ASC NULLS LAST, r6.c ASC NULLS LAST
+(4 rows)
+
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ a | b | c
+---+---+------
+ 0 | 0 | 0000
+ 2 | |
+ 4 | |
+ 6 | 6 | 0000
+ 8 | |
+(5 rows)
+
+-- with whole-row reference; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ QUERY PLAN
+--------------------------------------------------------
+ Sort
+ Sort Key: ((t1.*)::fprt1), ((t2.*)::fprt2)
+ -> Hash Full Join
+ Hash Cond: (t1.a = t2.b)
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+(11 rows)
+
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ wr | wr
+----------------+----------------
+ (0,0,0000) | (0,0,0000)
+ (50,50,0001) |
+ (100,100,0002) |
+ (150,150,0003) | (150,150,0003)
+ (200,200,0004) |
+ (250,250,0005) | (250,250,0005)
+ (300,300,0006) |
+ (350,350,0007) |
+ (400,400,0008) | (400,400,0008)
+ (450,450,0009) |
+ | (75,75,0001)
+ | (225,225,0004)
+ | (325,325,0006)
+ | (475,475,0009)
+(14 rows)
+
+-- join with lateral reference
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t1.b
+ -> Append
+ -> Foreign Scan
+ Relations: (ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)
+ -> Foreign Scan
+ Relations: (ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)
+(7 rows)
+
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+-- with PHVs, partitionwise join selected but no join pushdown
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: fprt1.a, fprt2.b
+ -> Append
+ -> Hash Full Join
+ Hash Cond: (fprt1_1.a = fprt2_1.b)
+ -> Foreign Scan on ftprt1_p1 fprt1_1
+ -> Hash
+ -> Foreign Scan on ftprt2_p1 fprt2_1
+ -> Hash Full Join
+ Hash Cond: (fprt1_2.a = fprt2_2.b)
+ -> Foreign Scan on ftprt1_p2 fprt1_2
+ -> Hash
+ -> Foreign Scan on ftprt2_p2 fprt2_2
+(13 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | phv | b | phv
+-----+--------+-----+--------
+ 0 | t1_phv | 0 | t2_phv
+ 50 | t1_phv | |
+ 100 | t1_phv | |
+ 150 | t1_phv | 150 | t2_phv
+ 200 | t1_phv | |
+ 250 | t1_phv | 250 | t2_phv
+ 300 | t1_phv | |
+ 350 | t1_phv | |
+ 400 | t1_phv | 400 | t2_phv
+ 450 | t1_phv | |
+ | | 75 | t2_phv
+ | | 225 | t2_phv
+ | | 325 | t2_phv
+ | | 475 | t2_phv
+(14 rows)
+
+-- test FOR UPDATE; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ QUERY PLAN
+--------------------------------------------------------------
+ LockRows
+ -> Sort
+ Sort Key: t1.a
+ -> Hash Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+(12 rows)
+
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+RESET enable_partitionwise_join;
+-- ===================================================================
+-- test partitionwise aggregates
+-- ===================================================================
+CREATE TABLE pagg_tab (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE pagg_tab_p1 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p2 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p3 (LIKE pagg_tab);
+INSERT INTO pagg_tab_p1 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 10;
+INSERT INTO pagg_tab_p2 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 20 and (i % 30) >= 10;
+INSERT INTO pagg_tab_p3 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 30 and (i % 30) >= 20;
+-- Create foreign partitions
+CREATE FOREIGN TABLE fpagg_tab_p1 PARTITION OF pagg_tab FOR VALUES FROM (0) TO (10) SERVER loopback OPTIONS (table_name 'pagg_tab_p1');
+CREATE FOREIGN TABLE fpagg_tab_p2 PARTITION OF pagg_tab FOR VALUES FROM (10) TO (20) SERVER loopback OPTIONS (table_name 'pagg_tab_p2');
+CREATE FOREIGN TABLE fpagg_tab_p3 PARTITION OF pagg_tab FOR VALUES FROM (20) TO (30) SERVER loopback OPTIONS (table_name 'pagg_tab_p3');
+ANALYZE pagg_tab;
+ANALYZE fpagg_tab_p1;
+ANALYZE fpagg_tab_p2;
+ANALYZE fpagg_tab_p3;
+-- When GROUP BY clause matches with PARTITION KEY.
+-- Plan with partitionwise aggregates is disabled
+SET enable_partitionwise_aggregate TO false;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> HashAggregate
+ Group Key: pagg_tab.a
+ Filter: (avg(pagg_tab.b) < '22'::numeric)
+ -> Append
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab_1
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_2
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_3
+(9 rows)
+
+-- Plan with partitionwise aggregates is enabled
+SET enable_partitionwise_aggregate TO true;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> Append
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p1 pagg_tab)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p2 pagg_tab_1)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p3 pagg_tab_2)
+(9 rows)
+
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | sum | min | count
+----+------+-----+-------
+ 0 | 2000 | 0 | 100
+ 1 | 2100 | 1 | 100
+ 10 | 2000 | 0 | 100
+ 11 | 2100 | 1 | 100
+ 20 | 2000 | 0 | 100
+ 21 | 2100 | 1 | 100
+(6 rows)
+
+-- Check with whole-row reference
+-- Should have all the columns in the target list for the given relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, (count(((t1.*)::pagg_tab)))
+ Sort Key: t1.a
+ -> Append
+ -> HashAggregate
+ Output: t1.a, count(((t1.*)::pagg_tab))
+ Group Key: t1.a
+ Filter: (avg(t1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p1 t1
+ Output: t1.a, t1.*, t1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p1
+ -> HashAggregate
+ Output: t1_1.a, count(((t1_1.*)::pagg_tab))
+ Group Key: t1_1.a
+ Filter: (avg(t1_1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p2 t1_1
+ Output: t1_1.a, t1_1.*, t1_1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p2
+ -> HashAggregate
+ Output: t1_2.a, count(((t1_2.*)::pagg_tab))
+ Group Key: t1_2.a
+ Filter: (avg(t1_2.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p3 t1_2
+ Output: t1_2.a, t1_2.*, t1_2.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p3
+(25 rows)
+
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | count
+----+-------
+ 0 | 100
+ 1 | 100
+ 10 | 100
+ 11 | 100
+ 20 | 100
+ 21 | 100
+(6 rows)
+
+-- When GROUP BY clause does not match with PARTITION KEY.
+EXPLAIN (COSTS OFF)
+SELECT b, avg(a), max(a), count(*) FROM pagg_tab GROUP BY b HAVING sum(a) < 700 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.b
+ -> Finalize HashAggregate
+ Group Key: pagg_tab.b
+ Filter: (sum(pagg_tab.a) < 700)
+ -> Append
+ -> Partial HashAggregate
+ Group Key: pagg_tab.b
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab
+ -> Partial HashAggregate
+ Group Key: pagg_tab_1.b
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_1
+ -> Partial HashAggregate
+ Group Key: pagg_tab_2.b
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_2
+(15 rows)
+
+-- ===================================================================
+-- access rights and superuser
+-- ===================================================================
+-- Non-superuser cannot create a FDW without a password in the connstr
+CREATE ROLE regress_nosuper NOSUPERUSER;
+GRANT USAGE ON FOREIGN DATA WRAPPER postgres_fdw TO regress_nosuper;
+SET ROLE regress_nosuper;
+SHOW is_superuser;
+ is_superuser
+--------------
+ off
+(1 row)
+
+-- This will be OK, we can create the FDW
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback_nopw FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+-- But creation of user mappings for non-superusers should fail
+CREATE USER MAPPING FOR public SERVER loopback_nopw;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+CREATE FOREIGN TABLE pg_temp.ft1_nopw (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback_nopw OPTIONS (schema_name 'public', table_name 'ft1');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+-- If we add a password to the connstr it'll fail, because we don't allow passwords
+-- in connstrs only in user mappings.
+ALTER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+ERROR: invalid option "password"
+HINT: Perhaps you meant the option "passfile".
+-- If we add a password for our user mapping instead, we should get a different
+-- error because the password wasn't actually *used* when we run with trust auth.
+--
+-- This won't work with installcheck, but neither will most of the FDW checks.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+-- Unpriv user cannot make the mapping passwordless
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+ERROR: password_required=false is superuser-only
+HINT: User mappings with the password_required option set to false may only be created or modified by the superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+RESET ROLE;
+-- But the superuser can
+ALTER USER MAPPING FOR regress_nosuper SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+SET ROLE regress_nosuper;
+-- Should finally work now
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- unpriv user also cannot set sslcert / sslkey on the user mapping
+-- first set password_required so we see the right error messages
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (SET password_required 'true');
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslcert 'foo.crt');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslkey 'foo.key');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+-- We're done with the role named after a specific user and need to check the
+-- changes to the public mapping.
+DROP USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+-- This will fail again as it'll resolve the user mapping for public, which
+-- lacks password_required=false
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+RESET ROLE;
+-- The user mapping for public is passwordless and lacks the password_required=false
+-- mapping option, but will work because the current user is a superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- cleanup
+DROP USER MAPPING FOR public SERVER loopback_nopw;
+DROP OWNED BY regress_nosuper;
+DROP ROLE regress_nosuper;
+-- Clean-up
+RESET enable_partitionwise_aggregate;
+-- Two-phase transactions are not supported.
+BEGIN;
+SELECT count(*) FROM ft1;
+ count
+-------
+ 822
+(1 row)
+
+-- error here
+PREPARE TRANSACTION 'fdw_tpc';
+ERROR: cannot PREPARE a transaction that has operated on postgres_fdw foreign tables
+ROLLBACK;
+WARNING: there is no transaction in progress
+-- ===================================================================
+-- reestablish new connection
+-- ===================================================================
+-- Change application_name of remote connection to special one
+-- so that we can easily terminate the connection later.
+ALTER SERVER loopback OPTIONS (application_name 'fdw_retry_check');
+-- If debug_discard_caches is active, it results in
+-- dropping remote connections after every transaction, making it
+-- impossible to test termination meaningfully. So turn that off
+-- for this test.
+SET debug_discard_caches = 0;
+-- Make sure we have a remote connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- This query should detect the broken connection when starting new remote
+-- transaction, reestablish new connection, and then succeed.
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- If we detect the broken connection when starting a new remote
+-- subtransaction, we should fail instead of establishing a new connection.
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+SAVEPOINT s;
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT 1 FROM ft1 LIMIT 1; -- should fail
+ERROR: 08006
+\set VERBOSITY default
+COMMIT;
+RESET debug_discard_caches;
+-- =============================================================================
+-- test connection invalidation cases and postgres_fdw_get_connections function
+-- =============================================================================
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- This test case is for closing the connection in pgfdw_xact_callback
+BEGIN;
+-- Connection xact depth becomes 1 i.e. the connection is in midst of the xact.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT 1 FROM ft7 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback3 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback3
+(2 rows)
+
+-- Connections are not closed at the end of the alter and drop statements.
+-- That's because the connections are in midst of this xact,
+-- they are just marked as invalid in pgfdw_inval_callback.
+ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
+DROP SERVER loopback3 CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to user mapping for public on server loopback3
+drop cascades to foreign table ft7
+-- List all the existing cached connections. loopback and loopback3
+-- should be output as invalid connections. Also the server name for
+-- loopback3 should be NULL because the server was dropped.
+SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | valid
+-------------+-------
+ loopback | f
+ | f
+(2 rows)
+
+-- The invalid connections get closed in pgfdw_xact_callback during commit.
+COMMIT;
+-- All cached connections were closed while committing above xact, so no
+-- records should be output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+(0 rows)
+
+-- =======================================================================
+-- test postgres_fdw_disconnect and postgres_fdw_disconnect_all functions
+-- =======================================================================
+BEGIN;
+-- Ensure to cache loopback connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Ensure to cache loopback2 connection.
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Issue a warning and return false as loopback connection is still in use and
+-- can not be closed.
+SELECT postgres_fdw_disconnect('loopback');
+WARNING: cannot close connection for server "loopback" because it is still in use
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Return false as connections are still in use, warnings are issued.
+-- But disable warnings temporarily because the order of them is not stable.
+SET client_min_messages = 'ERROR';
+SELECT postgres_fdw_disconnect_all();
+ postgres_fdw_disconnect_all
+-----------------------------
+ f
+(1 row)
+
+RESET client_min_messages;
+COMMIT;
+-- Ensure that loopback2 connection is closed.
+SELECT 1 FROM postgres_fdw_disconnect('loopback2');
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT server_name FROM postgres_fdw_get_connections() WHERE server_name = 'loopback2';
+ server_name
+-------------
+(0 rows)
+
+-- Return false as loopback2 connection is closed already.
+SELECT postgres_fdw_disconnect('loopback2');
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- Return an error as there is no foreign server with given name.
+SELECT postgres_fdw_disconnect('unknownserver');
+ERROR: server "unknownserver" does not exist
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- =============================================================================
+-- test case for having multiple cached connections for a foreign server
+-- =============================================================================
+CREATE ROLE regress_multi_conn_user1 SUPERUSER;
+CREATE ROLE regress_multi_conn_user2 SUPERUSER;
+CREATE USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+CREATE USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+BEGIN;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user1
+SET ROLE regress_multi_conn_user1;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user2
+SET ROLE regress_multi_conn_user2;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Should output two connections for loopback server
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback
+(2 rows)
+
+COMMIT;
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- Clean up
+DROP USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+DROP USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+DROP ROLE regress_multi_conn_user1;
+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
+-- ===================================================================
+BEGIN;
+CREATE SERVER batch10 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( batch_size '10' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER batch10 OPTIONS( SET batch_size '20' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=20'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30 ( x int ) SERVER batch10 OPTIONS ( batch_size '30' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30 OPTIONS ( SET batch_size '40');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=40'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+CREATE TABLE batch_table ( x int );
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '10' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 10
+ -> Function Scan on pg_catalog.generate_series i
+ Output: i.i
+ Function Call: generate_series(1, 10)
+(6 rows)
+
+INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+INSERT INTO ftable SELECT * FROM generate_series(11, 31) i;
+INSERT INTO ftable VALUES (32);
+INSERT INTO ftable VALUES (33), (34);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 34
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- try if large batches exceed max number of bind parameters
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '100000' );
+INSERT INTO ftable SELECT * FROM generate_series(1, 70000) i;
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 70000
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- Disable batch insert
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '1' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (1), (2);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 2
+(1 row)
+
+-- Disable batch inserting into foreign tables with BEFORE ROW INSERT triggers
+-- even if the batch_size option is enabled.
+ALTER FOREIGN TABLE ftable OPTIONS ( SET batch_size '10' );
+CREATE TRIGGER trig_row_before BEFORE INSERT ON ftable
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (3), (4);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (3), (4);
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (3)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (4)
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 4
+(1 row)
+
+-- Clean up
+DROP TRIGGER trig_row_before ON ftable;
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+-- Use partitioning
+CREATE TABLE batch_table ( x int ) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0', batch_size '10');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1', batch_size '1');
+CREATE TABLE batch_table_p2
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 2);
+INSERT INTO batch_table SELECT * FROM generate_series(1, 66) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 66
+(1 row)
+
+-- Check that enabling batched inserts doesn't interfere with cross-partition
+-- updates
+CREATE TABLE batch_cp_upd_test (a int) PARTITION BY LIST (a);
+CREATE TABLE batch_cp_upd_test1 (LIKE batch_cp_upd_test);
+CREATE FOREIGN TABLE batch_cp_upd_test1_f
+ PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_cp_upd_test1', batch_size '10');
+CREATE TABLE batch_cp_up_test1 PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (2);
+INSERT INTO batch_cp_upd_test VALUES (1), (2);
+-- The following moves a row from the local partition to the foreign one
+UPDATE batch_cp_upd_test t SET a = 1 FROM (VALUES (1), (2)) s(a) WHERE t.a = s.a;
+ERROR: cannot route tuples into foreign table to be updated "batch_cp_upd_test1_f"
+SELECT tableoid::regclass, * FROM batch_cp_upd_test;
+ tableoid | a
+----------------------+---
+ batch_cp_upd_test1_f | 1
+ batch_cp_up_test1 | 2
+(2 rows)
+
+-- Clean up
+DROP TABLE batch_table, batch_cp_upd_test, batch_table_p0, batch_table_p1 CASCADE;
+-- Use partitioning
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+CREATE TABLE batch_table ( x int, field1 text, field2 text) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+ALTER TABLE batch_table_p0 ADD CONSTRAINT p0_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+ALTER TABLE batch_table_p1 ADD CONSTRAINT p1_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1');
+INSERT INTO batch_table SELECT i, 'test'||i, 'test'|| i FROM generate_series(1, 50) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 50
+(1 row)
+
+SELECT * FROM batch_table ORDER BY x;
+ x | field1 | field2
+----+--------+--------
+ 1 | test1 | test1
+ 2 | test2 | test2
+ 3 | test3 | test3
+ 4 | test4 | test4
+ 5 | test5 | test5
+ 6 | test6 | test6
+ 7 | test7 | test7
+ 8 | test8 | test8
+ 9 | test9 | test9
+ 10 | test10 | test10
+ 11 | test11 | test11
+ 12 | test12 | test12
+ 13 | test13 | test13
+ 14 | test14 | test14
+ 15 | test15 | test15
+ 16 | test16 | test16
+ 17 | test17 | test17
+ 18 | test18 | test18
+ 19 | test19 | test19
+ 20 | test20 | test20
+ 21 | test21 | test21
+ 22 | test22 | test22
+ 23 | test23 | test23
+ 24 | test24 | test24
+ 25 | test25 | test25
+ 26 | test26 | test26
+ 27 | test27 | test27
+ 28 | test28 | test28
+ 29 | test29 | test29
+ 30 | test30 | test30
+ 31 | test31 | test31
+ 32 | test32 | test32
+ 33 | test33 | test33
+ 34 | test34 | test34
+ 35 | test35 | test35
+ 36 | test36 | test36
+ 37 | test37 | test37
+ 38 | test38 | test38
+ 39 | test39 | test39
+ 40 | test40 | test40
+ 41 | test41 | test41
+ 42 | test42 | test42
+ 43 | test43 | test43
+ 44 | test44 | test44
+ 45 | test45 | test45
+ 46 | test46 | test46
+ 47 | test47 | test47
+ 48 | test48 | test48
+ 49 | test49 | test49
+ 50 | test50 | test50
+(50 rows)
+
+-- Clean up
+DROP TABLE batch_table;
+DROP TABLE batch_table_p0;
+DROP TABLE batch_table_p1;
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+-- Test that pending inserts are handled properly when needed
+CREATE TABLE batch_table (a text, b int);
+CREATE FOREIGN TABLE ftable (a text, b int)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table', batch_size '2');
+CREATE TABLE ltable (a text, b int);
+CREATE FUNCTION ftable_rowcount_trigf() RETURNS trigger LANGUAGE plpgsql AS
+$$
+begin
+ raise notice '%: there are % rows in ftable',
+ TG_NAME, (SELECT count(*) FROM ftable);
+ if TG_OP = 'DELETE' then
+ return OLD;
+ else
+ return NEW;
+ end if;
+end;
+$$;
+CREATE TRIGGER ftable_rowcount_trigger
+BEFORE INSERT OR UPDATE OR DELETE ON ltable
+FOR EACH ROW EXECUTE PROCEDURE ftable_rowcount_trigf();
+WITH t AS (
+ INSERT INTO ltable VALUES ('AAA', 42), ('BBB', 42) RETURNING *
+)
+INSERT INTO ftable SELECT * FROM t;
+NOTICE: ftable_rowcount_trigger: there are 0 rows in ftable
+NOTICE: ftable_rowcount_trigger: there are 1 rows in ftable
+SELECT * FROM ltable;
+ a | b
+-----+----
+ AAA | 42
+ BBB | 42
+(2 rows)
+
+SELECT * FROM ftable;
+ a | b
+-----+----
+ AAA | 42
+ BBB | 42
+(2 rows)
+
+DELETE FROM ftable;
+WITH t AS (
+ UPDATE ltable SET b = b + 100 RETURNING *
+)
+INSERT INTO ftable SELECT * FROM t;
+NOTICE: ftable_rowcount_trigger: there are 0 rows in ftable
+NOTICE: ftable_rowcount_trigger: there are 1 rows in ftable
+SELECT * FROM ltable;
+ a | b
+-----+-----
+ AAA | 142
+ BBB | 142
+(2 rows)
+
+SELECT * FROM ftable;
+ a | b
+-----+-----
+ AAA | 142
+ BBB | 142
+(2 rows)
+
+DELETE FROM ftable;
+WITH t AS (
+ DELETE FROM ltable RETURNING *
+)
+INSERT INTO ftable SELECT * FROM t;
+NOTICE: ftable_rowcount_trigger: there are 0 rows in ftable
+NOTICE: ftable_rowcount_trigger: there are 1 rows in ftable
+SELECT * FROM ltable;
+ a | b
+---+---
+(0 rows)
+
+SELECT * FROM ftable;
+ a | b
+-----+-----
+ AAA | 142
+ BBB | 142
+(2 rows)
+
+DELETE FROM ftable;
+-- Clean up
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+DROP TRIGGER ftable_rowcount_trigger ON ltable;
+DROP TABLE ltable;
+CREATE TABLE parent (a text, b int) PARTITION BY LIST (a);
+CREATE TABLE batch_table (a text, b int);
+CREATE FOREIGN TABLE ftable
+ PARTITION OF parent
+ FOR VALUES IN ('AAA')
+ SERVER loopback
+ OPTIONS (table_name 'batch_table', batch_size '2');
+CREATE TABLE ltable
+ PARTITION OF parent
+ FOR VALUES IN ('BBB');
+CREATE TRIGGER ftable_rowcount_trigger
+BEFORE INSERT ON ltable
+FOR EACH ROW EXECUTE PROCEDURE ftable_rowcount_trigf();
+INSERT INTO parent VALUES ('AAA', 42), ('BBB', 42), ('AAA', 42), ('BBB', 42);
+NOTICE: ftable_rowcount_trigger: there are 1 rows in ftable
+NOTICE: ftable_rowcount_trigger: there are 2 rows in ftable
+SELECT tableoid::regclass, * FROM parent;
+ tableoid | a | b
+----------+-----+----
+ ftable | AAA | 42
+ ftable | AAA | 42
+ ltable | BBB | 42
+ ltable | BBB | 42
+(4 rows)
+
+-- Clean up
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+DROP TRIGGER ftable_rowcount_trigger ON ltable;
+DROP TABLE ltable;
+DROP TABLE parent;
+DROP FUNCTION ftable_rowcount_trigf;
+-- ===================================================================
+-- test asynchronous execution
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD async_capable 'true');
+ALTER SERVER loopback2 OPTIONS (ADD async_capable 'true');
+CREATE TABLE async_pt (a int, b int, c text) PARTITION BY RANGE (a);
+CREATE TABLE base_tbl1 (a int, b int, c text);
+CREATE TABLE base_tbl2 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p1 PARTITION OF async_pt FOR VALUES FROM (1000) TO (2000)
+ SERVER loopback OPTIONS (table_name 'base_tbl1');
+CREATE FOREIGN TABLE async_p2 PARTITION OF async_pt FOR VALUES FROM (2000) TO (3000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl2');
+INSERT INTO async_p1 SELECT 1000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+INSERT INTO async_p2 SELECT 2000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+-- simple queries
+CREATE TABLE result_tbl (a int, b int, c text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE (((b % 100) = 0))
+(8 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1000 | 0 | 0000
+ 1100 | 100 | 0100
+ 1200 | 200 | 0200
+ 1300 | 300 | 0300
+ 1400 | 400 | 0400
+ 1500 | 500 | 0500
+ 1600 | 600 | 0600
+ 1700 | 700 | 0700
+ 1800 | 800 | 0800
+ 1900 | 900 | 0900
+ 2000 | 0 | 0000
+ 2100 | 100 | 0100
+ 2200 | 200 | 0200
+ 2300 | 300 | 0300
+ 2400 | 400 | 0400
+ 2500 | 500 | 0500
+ 2600 | 600 | 0600
+ 2700 | 700 | 0700
+ 2800 | 800 | 0800
+ 2900 | 900 | 0900
+(20 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, ('AAA'::text || async_pt_1.c)
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, ('AAA'::text || async_pt_2.c)
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+---------
+ 1505 | 505 | AAA0505
+ 2505 | 505 | AAA0505
+(2 rows)
+
+DELETE FROM result_tbl;
+-- Check case where multiple partitions use the same connection
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl3');
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Async Foreign Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(14 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+DROP FOREIGN TABLE async_p3;
+DROP TABLE base_tbl3;
+-- Check case where the partitioned table has local/remote partitions
+CREATE TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000);
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+(13 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+-- partitionwise joins
+SET enable_partitionwise_join TO true;
+CREATE TABLE join_tbl (a1 int, b1 int, c1 text, a2 int, b2 int, c2 text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t2_1.b, t2_1.c
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t2_2.b, t2_2.c
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, t1_3.c, t2_3.a, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+ 2000 | 0 | 0000 | 2000 | 0 | 0000
+ 2100 | 100 | 0100 | 2100 | 100 | 0100
+ 2200 | 200 | 0200 | 2200 | 200 | 0200
+ 2300 | 300 | 0300 | 2300 | 300 | 0300
+ 2400 | 400 | 0400 | 2400 | 400 | 0400
+ 2500 | 500 | 0500 | 2500 | 500 | 0500
+ 2600 | 600 | 0600 | 2600 | 600 | 0600
+ 2700 | 700 | 0700 | 2700 | 700 | 0700
+ 2800 | 800 | 0800 | 2800 | 800 | 0800
+ 2900 | 900 | 0900 | 2900 | 900 | 0900
+ 3000 | 0 | 0000 | 3000 | 0 | 0000
+ 3100 | 100 | 0100 | 3100 | 100 | 0100
+ 3200 | 200 | 0200 | 3200 | 200 | 0200
+ 3300 | 300 | 0300 | 3300 | 300 | 0300
+ 3400 | 400 | 0400 | 3400 | 400 | 0400
+ 3500 | 500 | 0500 | 3500 | 500 | 0500
+ 3600 | 600 | 0600 | 3600 | 600 | 0600
+ 3700 | 700 | 0700 | 3700 | 700 | 0700
+ 3800 | 800 | 0800 | 3800 | 800 | 0800
+ 3900 | 900 | 0900 | 3900 | 900 | 0900
+(30 rows)
+
+DELETE FROM join_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, ('AAA'::text || t1_1.c), t2_1.a, t2_1.b, ('AAA'::text || t2_1.c)
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, ('AAA'::text || t1_2.c), t2_2.a, t2_2.b, ('AAA'::text || t2_2.c)
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, ('AAA'::text || t1_3.c), t2_3.a, t2_3.b, ('AAA'::text || t2_3.c)
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+---------+------+-----+---------
+ 1000 | 0 | AAA0000 | 1000 | 0 | AAA0000
+ 1100 | 100 | AAA0100 | 1100 | 100 | AAA0100
+ 1200 | 200 | AAA0200 | 1200 | 200 | AAA0200
+ 1300 | 300 | AAA0300 | 1300 | 300 | AAA0300
+ 1400 | 400 | AAA0400 | 1400 | 400 | AAA0400
+ 1500 | 500 | AAA0500 | 1500 | 500 | AAA0500
+ 1600 | 600 | AAA0600 | 1600 | 600 | AAA0600
+ 1700 | 700 | AAA0700 | 1700 | 700 | AAA0700
+ 1800 | 800 | AAA0800 | 1800 | 800 | AAA0800
+ 1900 | 900 | AAA0900 | 1900 | 900 | AAA0900
+ 2000 | 0 | AAA0000 | 2000 | 0 | AAA0000
+ 2100 | 100 | AAA0100 | 2100 | 100 | AAA0100
+ 2200 | 200 | AAA0200 | 2200 | 200 | AAA0200
+ 2300 | 300 | AAA0300 | 2300 | 300 | AAA0300
+ 2400 | 400 | AAA0400 | 2400 | 400 | AAA0400
+ 2500 | 500 | AAA0500 | 2500 | 500 | AAA0500
+ 2600 | 600 | AAA0600 | 2600 | 600 | AAA0600
+ 2700 | 700 | AAA0700 | 2700 | 700 | AAA0700
+ 2800 | 800 | AAA0800 | 2800 | 800 | AAA0800
+ 2900 | 900 | AAA0900 | 2900 | 900 | AAA0900
+ 3000 | 0 | AAA0000 | 3000 | 0 | AAA0000
+ 3100 | 100 | AAA0100 | 3100 | 100 | AAA0100
+ 3200 | 200 | AAA0200 | 3200 | 200 | AAA0200
+ 3300 | 300 | AAA0300 | 3300 | 300 | AAA0300
+ 3400 | 400 | AAA0400 | 3400 | 400 | AAA0400
+ 3500 | 500 | AAA0500 | 3500 | 500 | AAA0500
+ 3600 | 600 | AAA0600 | 3600 | 600 | AAA0600
+ 3700 | 700 | AAA0700 | 3700 | 700 | AAA0700
+ 3800 | 800 | AAA0800 | 3800 | 800 | AAA0800
+ 3900 | 900 | AAA0900 | 3900 | 900 | AAA0900
+(30 rows)
+
+DELETE FROM join_tbl;
+RESET enable_partitionwise_join;
+-- Test rescan of an async Append node with do_exec_prune=false
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: ((t1.a = t2.a) AND (t1.b = t2.b))
+ -> Foreign Scan on public.async_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t2_1
+ Output: t2_1.a, t2_1.b, t2_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t2_2
+ Output: t2_2.a, t2_2.b, t2_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+(16 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+(10 rows)
+
+DELETE FROM join_tbl;
+RESET enable_hashjoin;
+-- Test interaction of async execution with plan-time partition pruning
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 3000;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(7 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 2000;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Foreign Scan on public.async_p1 async_pt
+ Output: async_pt.a, async_pt.b, async_pt.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 2000))
+(3 rows)
+
+-- Test interaction of async execution with run-time partition pruning
+SET plan_cache_mode TO force_generic_plan;
+PREPARE async_pt_query (int, int) AS
+ INSERT INTO result_tbl SELECT * FROM async_pt WHERE a < $1 AND b === $2;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (3000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 1
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < $1::integer))
+(11 rows)
+
+EXECUTE async_pt_query (3000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (2000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 2
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+(7 rows)
+
+EXECUTE async_pt_query (2000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+(1 row)
+
+DELETE FROM result_tbl;
+RESET plan_cache_mode;
+CREATE TABLE local_tbl(a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo'), (2505, 505, 'bar');
+ANALYZE local_tbl;
+CREATE INDEX base_tbl1_idx ON base_tbl1 (a);
+CREATE INDEX base_tbl2_idx ON base_tbl2 (a);
+CREATE INDEX async_p3_idx ON async_p3 (a);
+ANALYZE base_tbl1;
+ANALYZE base_tbl2;
+ANALYZE async_p3;
+ALTER FOREIGN TABLE async_p1 OPTIONS (use_remote_estimate 'true');
+ALTER FOREIGN TABLE async_p2 OPTIONS (use_remote_estimate 'true');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: local_tbl.a, local_tbl.b, local_tbl.c, async_pt.a, async_pt.b, async_pt.c
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ Filter: (local_tbl.c = 'bar'::text)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a = $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a = $1::integer))
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.a = local_tbl.a)
+(15 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Nested Loop (actual rows=1 loops=1)
+ -> Seq Scan on local_tbl (actual rows=1 loops=1)
+ Filter: (c = 'bar'::text)
+ Rows Removed by Filter: 1
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (never executed)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=1 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (never executed)
+ Filter: (a = local_tbl.a)
+(9 rows)
+
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ a | b | c | a | b | c
+------+-----+-----+------+-----+------
+ 2505 | 505 | bar | 2505 | 505 | 0505
+(1 row)
+
+ALTER FOREIGN TABLE async_p1 OPTIONS (DROP use_remote_estimate);
+ALTER FOREIGN TABLE async_p2 OPTIONS (DROP use_remote_estimate);
+DROP TABLE local_tbl;
+DROP INDEX base_tbl1_idx;
+DROP INDEX base_tbl2_idx;
+DROP INDEX async_p3_idx;
+-- UNION queries
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> HashAggregate
+ Output: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ Group Key: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(11 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(8 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+-- Disable async execution if we use gating Result nodes for pseudoconstant
+-- quals
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Result
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+(18 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+(SELECT * FROM async_p1 WHERE CURRENT_USER = SESSION_USER)
+UNION ALL
+(SELECT * FROM async_p2 WHERE CURRENT_USER = SESSION_USER);
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(13 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ((SELECT * FROM async_p1 WHERE b < 10) UNION ALL (SELECT * FROM async_p2 WHERE b < 10)) s WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((b < 10))
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(13 rows)
+
+-- Test that pending requests are processed properly
+SET enable_mergejoin TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: (t1.a = t2.a)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+ -> Materialize
+ Output: t2.a, t2.b, t2.c
+ -> Foreign Scan on public.async_p2 t2
+ Output: t2.a, t2.b, t2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(20 rows)
+
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ a | b | c | a | b | c
+------+-----+------+------+-----+------
+ 2505 | 505 | 0505 | 2505 | 505 | 0505
+(1 row)
+
+CREATE TABLE local_tbl (a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo');
+ANALYZE local_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, async_pt.a, async_pt.b, async_pt.c, ($0)
+ Join Filter: (t1.a = async_pt.a)
+ InitPlan 1 (returns $0)
+ -> Aggregate
+ Output: count(*)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_4
+ Remote SQL: SELECT NULL FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_5
+ Remote SQL: SELECT NULL FROM public.base_tbl2 WHERE ((a < 3000))
+ -> Seq Scan on public.local_tbl t1
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(20 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Nested Loop Left Join (actual rows=1 loops=1)
+ Join Filter: (t1.a = async_pt.a)
+ Rows Removed by Join Filter: 399
+ InitPlan 1 (returns $0)
+ -> Aggregate (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_4 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_5 (actual rows=200 loops=1)
+ -> Seq Scan on local_tbl t1 (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=200 loops=1)
+(12 rows)
+
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ a | b | c | a | b | c | count
+------+-----+-----+------+-----+------+-------
+ 1505 | 505 | foo | 1505 | 505 | 0505 | 400
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+----------------------------------------------------------------
+ Limit
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+(14 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit (actual rows=1 loops=1)
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 t1_1 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Async Foreign Scan on async_p2 t1_2 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Seq Scan on async_p3 t1_3 (actual rows=1 loops=1)
+ Filter: (b === 505)
+ Rows Removed by Filter: 101
+(9 rows)
+
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ a | b | c
+------+-----+------
+ 3505 | 505 | 0505
+(1 row)
+
+-- Check with foreign modify
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE remote_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl3');
+INSERT INTO remote_tbl VALUES (2505, 505, 'bar');
+CREATE TABLE base_tbl4 (a int, b int, c text);
+CREATE FOREIGN TABLE insert_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl4');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Insert on public.insert_tbl
+ Remote SQL: INSERT INTO public.base_tbl4(a, b, c) VALUES ($1, $2, $3)
+ Batch Size: 1
+ -> Append
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ -> Async Foreign Scan on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(9 rows)
+
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+SELECT * FROM insert_tbl ORDER BY a;
+ a | b | c
+------+-----+-----
+ 1505 | 505 | foo
+ 2505 | 505 | bar
+(2 rows)
+
+-- Check with direct modify
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ CTE t
+ -> Update on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ -> Foreign Update on public.remote_tbl
+ Remote SQL: UPDATE public.base_tbl3 SET c = (c || c) RETURNING a, b, c
+ -> Nested Loop Left Join
+ Output: async_pt.a, async_pt.b, async_pt.c, t.a, t.b, t.c
+ Join Filter: ((async_pt.a = t.a) AND (async_pt.b = t.b))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ -> CTE Scan on t
+ Output: t.a, t.b, t.c
+(23 rows)
+
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+--------
+ 1505 | 505 | 0505 | | |
+ 2505 | 505 | 0505 | 2505 | 505 | barbar
+ 3505 | 505 | 0505 | | |
+(3 rows)
+
+DELETE FROM join_tbl;
+DROP TABLE local_tbl;
+DROP FOREIGN TABLE remote_tbl;
+DROP FOREIGN TABLE insert_tbl;
+DROP TABLE base_tbl3;
+DROP TABLE base_tbl4;
+RESET enable_mergejoin;
+RESET enable_hashjoin;
+-- Test that UPDATE/DELETE with inherited target works with async_capable enabled
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Update on public.async_p1 async_pt_1
+ Foreign Update on public.async_p2 async_pt_2
+ Update on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Update on public.async_p1 async_pt_1
+ Remote SQL: UPDATE public.base_tbl1 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Update on public.async_p2 async_pt_2
+ Remote SQL: UPDATE public.base_tbl2 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: (async_pt_3.c || async_pt_3.c), async_pt_3.tableoid, async_pt_3.ctid, NULL::record
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Delete on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Delete on public.async_p1 async_pt_1
+ Foreign Delete on public.async_p2 async_pt_2
+ Delete on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Delete on public.async_p1 async_pt_1
+ Remote SQL: DELETE FROM public.base_tbl1 WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Delete on public.async_p2 async_pt_2
+ Remote SQL: DELETE FROM public.base_tbl2 WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.tableoid, async_pt_3.ctid
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+-- Check EXPLAIN ANALYZE for a query that scans empty partitions asynchronously
+DELETE FROM async_p1;
+DELETE FROM async_p2;
+DELETE FROM async_p3;
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Append (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=0 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (actual rows=0 loops=1)
+(4 rows)
+
+-- Clean up
+DROP TABLE async_pt;
+DROP TABLE base_tbl1;
+DROP TABLE base_tbl2;
+DROP TABLE result_tbl;
+DROP TABLE join_tbl;
+-- Test that an asynchronous fetch is processed before restarting the scan in
+-- ReScanForeignScan
+CREATE TABLE base_tbl (a int, b int);
+INSERT INTO base_tbl VALUES (1, 11), (2, 22), (3, 33);
+CREATE FOREIGN TABLE foreign_tbl (b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE FOREIGN TABLE foreign_tbl2 () INHERITS (foreign_tbl)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Seq Scan on public.base_tbl
+ Output: base_tbl.a
+ Filter: (SubPlan 1)
+ SubPlan 1
+ -> Result
+ Output: base_tbl.a
+ -> Append
+ -> Async Foreign Scan on public.foreign_tbl foreign_tbl_1
+ Remote SQL: SELECT NULL FROM public.base_tbl
+ -> Async Foreign Scan on public.foreign_tbl2 foreign_tbl_2
+ Remote SQL: SELECT NULL FROM public.base_tbl
+(11 rows)
+
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ a
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+-- Clean up
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to foreign table foreign_tbl2
+DROP TABLE base_tbl;
+ALTER SERVER loopback OPTIONS (DROP async_capable);
+ALTER SERVER loopback2 OPTIONS (DROP async_capable);
+-- ===================================================================
+-- test invalid server, foreign table and foreign data wrapper options
+-- ===================================================================
+-- Invalid fdw_startup_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_startup_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_startup_cost": 100$%$#$#
+-- Invalid fdw_tuple_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_tuple_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_tuple_cost": 100$%$#$#
+-- Invalid fetch_size option
+CREATE FOREIGN TABLE inv_fsz (c1 int )
+ SERVER loopback OPTIONS (fetch_size '100$%$#$#');
+ERROR: invalid value for integer option "fetch_size": 100$%$#$#
+-- Invalid batch_size option
+CREATE FOREIGN TABLE inv_bsz (c1 int )
+ SERVER loopback OPTIONS (batch_size '100$%$#$#');
+ERROR: invalid value for integer option "batch_size": 100$%$#$#
+-- No option is allowed to be specified at foreign data wrapper level
+ALTER FOREIGN DATA WRAPPER postgres_fdw OPTIONS (nonexistent 'fdw');
+ERROR: invalid option "nonexistent"
+HINT: There are no valid options in this context.
+-- ===================================================================
+-- test postgres_fdw.application_name GUC
+-- ===================================================================
+--- Turn debug_discard_caches off for this test to make sure that
+--- the remote connection is alive when checking its application_name.
+SET debug_discard_caches = 0;
+-- Specify escape sequences in application_name option of a server
+-- object so as to test that they are replaced with status information
+-- expectedly.
+--
+-- Since pg_stat_activity.application_name may be truncated to less than
+-- NAMEDATALEN characters, note that substring() needs to be used
+-- at the condition of test query to make sure that the string consisting
+-- of database name and process ID is also less than that.
+ALTER SERVER loopback2 OPTIONS (application_name 'fdw_%d%p');
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_database() || pg_backend_pid() for
+ current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- postgres_fdw.application_name overrides application_name option
+-- of a server object if both settings are present.
+SET postgres_fdw.application_name TO 'fdw_%a%u%%';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('application_name') ||
+ CURRENT_USER || '%' for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- Test %c (session ID) and %C (cluster name) escape sequences.
+SET postgres_fdw.application_name TO 'fdw_%C%c';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('cluster_name') ||
+ to_hex(trunc(EXTRACT(EPOCH FROM (SELECT backend_start FROM
+ pg_stat_get_activity(pg_backend_pid()))))::integer) || '.' ||
+ to_hex(pg_backend_pid())
+ for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+--Clean up
+RESET postgres_fdw.application_name;
+RESET debug_discard_caches;
+-- ===================================================================
+-- test parallel commit
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (ADD parallel_commit 'true');
+ALTER SERVER loopback2 OPTIONS (ADD parallel_commit 'true');
+CREATE TABLE ploc1 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem1 (f1 int, f2 text)
+ SERVER loopback OPTIONS (table_name 'ploc1');
+CREATE TABLE ploc2 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem2 (f1 int, f2 text)
+ SERVER loopback2 OPTIONS (table_name 'ploc2');
+BEGIN;
+INSERT INTO prem1 VALUES (101, 'foo');
+INSERT INTO prem2 VALUES (201, 'bar');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+-----
+ 101 | foo
+(1 row)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+-----
+ 201 | bar
+(1 row)
+
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (102, 'foofoo');
+INSERT INTO prem2 VALUES (202, 'barbar');
+RELEASE SAVEPOINT s;
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+(2 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+(2 rows)
+
+-- This tests executing DEALLOCATE ALL against foreign servers in parallel
+-- during pre-commit
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (103, 'baz');
+INSERT INTO prem2 VALUES (203, 'qux');
+ROLLBACK TO SAVEPOINT s;
+RELEASE SAVEPOINT s;
+INSERT INTO prem1 VALUES (104, 'bazbaz');
+INSERT INTO prem2 VALUES (204, 'quxqux');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+ 104 | bazbaz
+(3 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+ 204 | quxqux
+(3 rows)
+
+ALTER SERVER loopback OPTIONS (DROP parallel_commit);
+ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- execute check function. This should return false on supported platforms,
+-- otherwise return true.
+SELECT postgres_fdw_verify_connection_states('loopback');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+(1 row)
+
+ABORT;
+WARNING: 08006
+\set VERBOSITY default
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 51560429e0..18154864d0 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3874,3 +3874,33 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+-- execute check function. This should return false on supported platforms,
+-- otherwise return true.
+SELECT postgres_fdw_verify_connection_states('loopback');
+ABORT;
+
+\set VERBOSITY default
+
+-- Clean up
+RESET debug_discard_caches;
--
2.27.0
Dear hackers,
PSA rebased patches.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v21-0001-Add-PQConncheck-to-libpq.patchapplication/octet-stream; name=v21-0001-Add-PQConncheck-to-libpq.patchDownload
From 0b738b2ce20d194aac8ed49c524d85260659c52b Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:20 +0000
Subject: [PATCH v21 1/3] Add PQConncheck to libpq
This new libpq function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
---
doc/src/sgml/libpq.sgml | 24 ++++++++++++++++++
src/interfaces/libpq/exports.txt | 1 +
src/interfaces/libpq/fe-misc.c | 42 ++++++++++++++++++++++++++++++++
src/interfaces/libpq/libpq-fe.h | 3 +++
4 files changed, 70 insertions(+)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index af278660eb..1435b39173 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,30 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQConncheck">
+ <term><function>PQConncheck</function><indexterm><primary>PQConncheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQConncheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQConncheck"/> returns <literal>1</literal>
+ if the remote peer seems to be closed, returns <literal>0</literal> if
+ the socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..3c4f946b51 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,4 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQConncheck 187
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 4159610f6c..2446d2d396 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -1218,6 +1218,48 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Helper function for PQconncheck().
+ *
+ * Return >0 if opposite side seems to be disconnected.
+ */
+static int
+pqConncheck_internal(int sock)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ struct pollfd input_fd;
+ int errflags = POLLHUP | POLLERR | POLLNVAL;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP | errflags;
+ input_fd.revents = 0;
+
+ poll(&input_fd, 1, 0);
+
+ return input_fd.revents;
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad.
+ */
+int
+PQConncheck(PGconn *conn)
+{
+ /* quick exit if invalid connection has come */
+ if (conn == NULL ||
+ conn->sock == PGINVALID_SOCKET ||
+ conn->status != CONNECTION_OK)
+ return -1;
+
+ return pqConncheck_internal(conn->sock);
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index b7df3224c0..8b2d78f3ef 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,9 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQConncheck(PGconn *conn);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v21-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v21-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From 46550779c148a8ce548b39b83b8d5fa23f7bc50c Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:42 +0000
Subject: [PATCH v21 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQConncheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if checked connection is still valid, or the checking is
not supported on this platform. False is returned if the connection seems
to be closed.
---
contrib/postgres_fdw/connection.c | 100 ++++++++++++++++++
.../postgres_fdw/postgres_fdw--1.0--1.1.sql | 10 ++
doc/src/sgml/postgres-fdw.sgml | 49 +++++++++
3 files changed, 159 insertions(+)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index f0c45b00db..69959a0f12 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -86,6 +86,8 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -116,6 +118,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1862,3 +1865,100 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+
+ /* quick exit if connection cache has been not initialized yet. */
+ if (!ConnectionHash)
+ return true;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQConncheck(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so throw ereport(WARNING).
+ */
+ ForeignServer *server;
+
+ server = GetForeignServer(entry->serverid);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("could not connect to server \"%s\"",
+ server->servername),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of the server.")));
+
+ result = false;
+ }
+ }
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found, and this returns
+ * false only when the verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
diff --git a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
index ed4ca378d4..f1e2ee442f 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
@@ -18,3 +18,13 @@ CREATE FUNCTION postgres_fdw_disconnect_all ()
RETURNS bool
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 527f4deaaa..d535973237 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -790,6 +790,55 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if a checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports that
+ the connection is closed. This function is currently available only on
+ systems that support the non-standard <symbol>POLLRDHUP</symbol> extension
+ to the <symbol>poll</symbol> system call, including Linux. This returns
+ <literal>true</literal> if a lastly checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
</variablelist>
</sect2>
--
2.27.0
v21-0003-add-test.patchapplication/octet-stream; name=v21-0003-add-test.patchDownload
From 54ec62936ca84a3744dbcdb761a088a6953ef0ad Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v21 3/3] add test
Note that this test has two comparison files. Alternative comparison file is needed
because some platforms like Windows cannot check the status of the socket.
---
.../postgres_fdw/expected/postgres_fdw.out | 44 +
.../postgres_fdw/expected/postgres_fdw_1.out | 11746 ++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 30 +
3 files changed, 11820 insertions(+)
create mode 100644 contrib/postgres_fdw/expected/postgres_fdw_1.out
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 5f6e1f9833..1a7c0cc07b 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11701,3 +11701,47 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- execute check function. This should return false on supported platforms,
+-- otherwise return true.
+SELECT postgres_fdw_verify_connection_states('loopback');
+WARNING: 08006
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ f
+(1 row)
+
+ABORT;
+WARNING: 08006
+\set VERBOSITY default
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/expected/postgres_fdw_1.out b/contrib/postgres_fdw/expected/postgres_fdw_1.out
new file mode 100644
index 0000000000..0772d8ba9e
--- /dev/null
+++ b/contrib/postgres_fdw/expected/postgres_fdw_1.out
@@ -0,0 +1,11746 @@
+-- ===================================================================
+-- create FDW objects
+-- ===================================================================
+CREATE EXTENSION postgres_fdw;
+CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw;
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback2 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback3 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+CREATE USER MAPPING FOR public SERVER testserver1
+ OPTIONS (user 'value', password 'value');
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback2;
+CREATE USER MAPPING FOR public SERVER loopback3;
+-- ===================================================================
+-- create objects used through FDW loopback server
+-- ===================================================================
+CREATE TYPE user_enum AS ENUM ('foo', 'bar', 'buz');
+CREATE SCHEMA "S 1";
+CREATE TABLE "S 1"."T 1" (
+ "C 1" int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10),
+ c8 user_enum,
+ CONSTRAINT t1_pkey PRIMARY KEY ("C 1")
+);
+CREATE TABLE "S 1"."T 2" (
+ c1 int NOT NULL,
+ c2 text,
+ CONSTRAINT t2_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 3" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t3_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 4" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t4_pkey PRIMARY KEY (c1)
+);
+-- Disable autovacuum for these tables to avoid unexpected effects of that
+ALTER TABLE "S 1"."T 1" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 2" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 3" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 4" SET (autovacuum_enabled = 'false');
+INSERT INTO "S 1"."T 1"
+ SELECT id,
+ id % 10,
+ to_char(id, 'FM00000'),
+ '1970-01-01'::timestamptz + ((id % 100) || ' days')::interval,
+ '1970-01-01'::timestamp + ((id % 100) || ' days')::interval,
+ id % 10,
+ id % 10,
+ 'foo'::user_enum
+ FROM generate_series(1, 1000) id;
+INSERT INTO "S 1"."T 2"
+ SELECT id,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+INSERT INTO "S 1"."T 3"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 3" WHERE c1 % 2 != 0; -- delete for outer join tests
+INSERT INTO "S 1"."T 4"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests
+ANALYZE "S 1"."T 1";
+ANALYZE "S 1"."T 2";
+ANALYZE "S 1"."T 3";
+ANALYZE "S 1"."T 4";
+-- ===================================================================
+-- create foreign tables
+-- ===================================================================
+CREATE FOREIGN TABLE ft1 (
+ c0 int,
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft1 DROP COLUMN c0;
+CREATE FOREIGN TABLE ft2 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ cx int,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft2',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft2 DROP COLUMN cx;
+CREATE FOREIGN TABLE ft4 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 3');
+CREATE FOREIGN TABLE ft5 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft6 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback2 OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft7 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback3 OPTIONS (schema_name 'S 1', table_name 'T 4');
+-- ===================================================================
+-- tests for validator
+-- ===================================================================
+-- requiressl and some other parameters are omitted because
+-- valid values for them depend on configure options
+ALTER SERVER testserver1 OPTIONS (
+ use_remote_estimate 'false',
+ updatable 'true',
+ fdw_startup_cost '123.456',
+ fdw_tuple_cost '0.123',
+ service 'value',
+ connect_timeout 'value',
+ dbname 'value',
+ host 'value',
+ hostaddr 'value',
+ port 'value',
+ --client_encoding 'value',
+ application_name 'value',
+ --fallback_application_name 'value',
+ keepalives 'value',
+ keepalives_idle 'value',
+ keepalives_interval 'value',
+ tcp_user_timeout 'value',
+ -- requiressl 'value',
+ sslcompression 'value',
+ sslmode 'value',
+ sslcert 'value',
+ sslkey 'value',
+ sslrootcert 'value',
+ sslcrl 'value',
+ --requirepeer 'value',
+ krbsrvname 'value',
+ gsslib 'value'
+ --replication 'value'
+);
+-- Error, invalid list syntax
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo; bar');
+ERROR: parameter "extensions" must be a list of extension names
+-- OK but gets a warning
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo, bar');
+WARNING: extension "foo" is not installed
+WARNING: extension "bar" is not installed
+ALTER SERVER testserver1 OPTIONS (DROP extensions);
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (DROP user, DROP password);
+-- Attempt to add a valid option that's not allowed in a user mapping
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslmode 'require');
+ERROR: invalid option "sslmode"
+-- But we can add valid ones fine
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslpassword 'dummy');
+-- Ensure valid options we haven't used in a user mapping yet are
+-- permitted to check validation.
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslkey 'value', ADD sslcert 'value');
+ALTER FOREIGN TABLE ft1 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft2 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+ALTER FOREIGN TABLE ft2 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+\det+
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------+-------+-----------+---------------------------------------+-------------
+ public | ft1 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft2 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft4 | loopback | (schema_name 'S 1', table_name 'T 3') |
+ public | ft5 | loopback | (schema_name 'S 1', table_name 'T 4') |
+ public | ft6 | loopback2 | (schema_name 'S 1', table_name 'T 4') |
+ public | ft7 | loopback3 | (schema_name 'S 1', table_name 'T 4') |
+(6 rows)
+
+-- Test that alteration of server options causes reconnection
+-- Remote's errors might be non-English, so hide them to ensure stable results
+\set VERBOSITY terse
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET dbname 'no such database');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+DO $d$
+ BEGIN
+ EXECUTE $$ALTER SERVER loopback
+ OPTIONS (SET dbname '$$||current_database()||$$')$$;
+ END;
+$d$;
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+-- Test that alteration of user mapping options causes reconnection
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (ADD user 'no such user');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (DROP user);
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+\set VERBOSITY default
+-- Now we should be able to run ANALYZE.
+-- To exercise multiple code paths, we use local stats on ft1
+-- and remote-estimate mode on ft2.
+ANALYZE ft1;
+ALTER FOREIGN TABLE ft2 OPTIONS (use_remote_estimate 'true');
+-- ===================================================================
+-- test error case for create publication on foreign table
+-- ===================================================================
+CREATE PUBLICATION testpub_ftbl FOR TABLE ft1; -- should fail
+ERROR: cannot add relation "ft1" to publication
+DETAIL: This operation is not supported for foreign tables.
+-- ===================================================================
+-- simple queries
+-- ===================================================================
+-- single table without alias
+EXPLAIN (COSTS OFF) SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------
+ Foreign Scan on ft1
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- single table with alias - also test that tableoid sort is not pushed to remote side
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ -> Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Sort Key: t1.c3, t1.c1, t1.tableoid
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(8 rows)
+
+SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF) SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: t1.*, c3, c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c3 ASC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(3 rows)
+
+SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ t1
+--------------------------------------------------------------------------------------------
+ (101,1,00101,"Fri Jan 02 00:00:00 1970 PST","Fri Jan 02 00:00:00 1970",1,"1 ",foo)
+ (102,2,00102,"Sat Jan 03 00:00:00 1970 PST","Sat Jan 03 00:00:00 1970",2,"2 ",foo)
+ (103,3,00103,"Sun Jan 04 00:00:00 1970 PST","Sun Jan 04 00:00:00 1970",3,"3 ",foo)
+ (104,4,00104,"Mon Jan 05 00:00:00 1970 PST","Mon Jan 05 00:00:00 1970",4,"4 ",foo)
+ (105,5,00105,"Tue Jan 06 00:00:00 1970 PST","Tue Jan 06 00:00:00 1970",5,"5 ",foo)
+ (106,6,00106,"Wed Jan 07 00:00:00 1970 PST","Wed Jan 07 00:00:00 1970",6,"6 ",foo)
+ (107,7,00107,"Thu Jan 08 00:00:00 1970 PST","Thu Jan 08 00:00:00 1970",7,"7 ",foo)
+ (108,8,00108,"Fri Jan 09 00:00:00 1970 PST","Fri Jan 09 00:00:00 1970",8,"8 ",foo)
+ (109,9,00109,"Sat Jan 10 00:00:00 1970 PST","Sat Jan 10 00:00:00 1970",9,"9 ",foo)
+ (110,0,00110,"Sun Jan 11 00:00:00 1970 PST","Sun Jan 11 00:00:00 1970",0,"0 ",foo)
+(10 rows)
+
+-- empty result
+SELECT * FROM ft1 WHERE false;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- with WHERE clause
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c7 >= '1')) AND (("C 1" = 101)) AND ((c6 = '1'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- with FOR UPDATE/SHARE
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 101)) FOR UPDATE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 102)) FOR SHARE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+-- aggregate
+SELECT COUNT(*) FROM ft1 t1;
+ count
+-------
+ 1000
+(1 row)
+
+-- subquery
+SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- subquery+MAX
+SELECT * FROM ft1 t1 WHERE t1.c3 = (SELECT MAX(c3) FROM ft2 t2) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+(1 row)
+
+-- used in CTE
+WITH t1 AS (SELECT * FROM ft1 WHERE c1 <= 10) SELECT t2.c1, t2.c2, t2.c3, t2.c4 FROM t1, ft2 t2 WHERE t1.c1 = t2.c1 ORDER BY t1.c1;
+ c1 | c2 | c3 | c4
+----+----+-------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+(10 rows)
+
+-- fixed values
+SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1;
+ ?column? | ?column?
+----------+----------
+ fixed |
+(1 row)
+
+-- Test forcing the remote server to produce sorted data for a merge join.
+SET enable_hashjoin TO false;
+SET enable_nestloop TO false;
+-- inner join; expressions in the clauses appear in the equivalence class list
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Left Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- A join between local table and foreign join. ORDER BY clause is added to the
+-- foreign join so that the local table can be joined using merge join strategy.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Merge Right Join
+ Output: t1."C 1"
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r3."C 1" FROM ("S 1"."T 1" r2 INNER JOIN "S 1"."T 1" r3 ON (((r3."C 1" = r2."C 1")))) ORDER BY r2."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- Test similar to above, except that the full join prevents any equivalence
+-- classes from being merged. This produces single relation equivalence classes
+-- included in join restrictions.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Right Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1, t2.c1
+ Relations: (public.ft2 t3) LEFT JOIN (public.ft1 t2)
+ Remote SQL: SELECT r3."C 1", r2."C 1" FROM ("S 1"."T 1" r3 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+-- Test similar to above with all full outer joins
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Full Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) FULL JOIN (public.ft2 t3)
+ Remote SQL: SELECT r2."C 1", r3."C 1" FROM ("S 1"."T 1" r2 FULL JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test executing assertion in estimate_path_cost_size() that makes sure that
+-- retrieved_rows for foreign rel re-used to cost pre-sorted foreign paths is
+-- a sensible value even when the rel has tuples=0
+CREATE TABLE loct_empty (c1 int NOT NULL, c2 text);
+CREATE FOREIGN TABLE ft_empty (c1 int NOT NULL, c2 text)
+ SERVER loopback OPTIONS (table_name 'loct_empty');
+INSERT INTO loct_empty
+ SELECT id, 'AAA' || to_char(id, 'FM000') FROM generate_series(1, 100) id;
+DELETE FROM loct_empty;
+ANALYZE ft_empty;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Foreign Scan on public.ft_empty
+ Output: c1, c2
+ Remote SQL: SELECT c1, c2 FROM public.loct_empty ORDER BY c1 ASC NULLS LAST
+(3 rows)
+
+-- ===================================================================
+-- WHERE with remotely-executable conditions
+-- ===================================================================
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1; -- Var, OpExpr(b), Const
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL; -- NullTest
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL; -- NullTest
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((round(abs("C 1"), 0) = 1::numeric))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1; -- OpExpr(l)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = (- "C 1")))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" IS NOT NULL) IS DISTINCT FROM ("C 1" IS NOT NULL)))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]); -- ScalarArrayOpExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ANY (ARRAY[c2, 1, ("C 1" + 0)])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1]; -- SubscriptingRef
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ((ARRAY["C 1", c2, 3])[1])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar'; -- check special chars
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c6 = E'foo''s\\bar'))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c8 = 'foo'; -- can't be sent to remote
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- parameterized remote path for foreign table
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM "S 1"."T 1" a, ft2 b WHERE a."C 1" = 47 AND b.c1 = a.c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Index Scan using t1_pkey on "S 1"."T 1" a
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Index Cond: (a."C 1" = 47)
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(8 rows)
+
+SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 47 | 7 | 00047 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo | 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+(1 row)
+
+-- check both safe and unsafe join conditions
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 a, ft2 b
+ WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Foreign Scan on public.ft2 a
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Filter: (a.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c2 = 6))
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Filter: ((b.c7)::text = upper((a.c7)::text))
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(10 rows)
+
+SELECT * FROM ft2 a, ft2 b
+WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+(100 rows)
+
+-- bug before 9.3.5 due to sloppy handling of remote-estimate parameters
+SELECT * FROM ft1 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft2 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+SELECT * FROM ft2 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft1 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+-- we should not push order by clause with volatile expressions or unsafe
+-- collations
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, random();
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, (random())
+ Sort Key: ft2.c1, (random())
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, random()
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, ft2.c3 collate "C";
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, ((c3)::text)
+ Sort Key: ft2.c1, ft2.c3 COLLATE "C"
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- user-defined operator/function
+CREATE FUNCTION postgres_fdw_abs(int) RETURNS int AS $$
+BEGIN
+RETURN abs($1);
+END
+$$ LANGUAGE plpgsql IMMUTABLE;
+CREATE OPERATOR === (
+ LEFTARG = int,
+ RIGHTARG = int,
+ PROCEDURE = int4eq,
+ COMMUTATOR = ===
+);
+-- built-in operators and functions can be shipped for remote execution
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ QUERY PLAN
+----------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- by default, user-defined ones cannot
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 = postgres_fdw_abs(t1.c2))
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- ORDER BY can be shipped, though
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- but let's put them in an extension ...
+ALTER EXTENSION postgres_fdw ADD FUNCTION postgres_fdw_abs(int);
+ALTER EXTENSION postgres_fdw ADD OPERATOR === (int, int);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- ... now they can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- and both ORDER BY and LIMIT can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2)) ORDER BY c2 ASC NULLS LAST LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- Test CASE pushdown
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE WHEN ("C 1" > 990) THEN "C 1" ELSE NULL::integer END) < 1000)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ c1 | c2 | c3
+-----+----+-------
+ 991 | 1 | 00991
+ 992 | 2 | 00992
+ 993 | 3 | 00993
+ 994 | 4 | 00994
+ 995 | 5 | 00995
+ 996 | 6 | 00996
+ 997 | 7 | 00997
+ 998 | 8 | 00998
+ 999 | 9 | 00999
+(9 rows)
+
+-- Nested CASE
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE (CASE WHEN (c2 > 0) THEN c2 ELSE NULL::integer END) WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END) > 600)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ c1 | c2 | c3
+----+----+----
+(0 rows)
+
+-- CASE arg WHEN
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE mod(c1, 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" > (CASE mod("C 1", 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)))
+(3 rows)
+
+-- CASE cannot be pushed down because of unshippable arg clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE random()::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (ft1.c1 > CASE (random())::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- these are shippable
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c6 WHEN 'foo' THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c6 WHEN 'foo'::text THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c3 WHEN c6 THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+-- but this is not because of collation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 COLLATE "C" WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: CASE (ft1.c3)::text WHEN ft1.c6 THEN true ELSE (ft1.c3 < 'bar'::text) END
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- a regconfig constant referring to this text search configuration
+-- is initially unshippable
+CREATE TEXT SEARCH CONFIGURATION public.custom_search
+ (COPY = pg_catalog.english);
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Filter: (length(to_tsvector('custom_search'::regconfig, ft1.c3)) > 0)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642))
+(4 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- but if it's in a shippable extension, it can be shipped
+ALTER EXTENSION postgres_fdw ADD TEXT SEARCH CONFIGURATION public.custom_search;
+-- however, that doesn't flush the shippability cache, so do a quick reconnect
+\c -
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642)) AND ((length(to_tsvector('public.custom_search'::regconfig, c3)) > 0))
+(3 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- ===================================================================
+-- JOIN queries
+-- ===================================================================
+-- Analyze ft4 and ft5 so that we have better statistics. These tables do not
+-- have use_remote_estimate set.
+ANALYZE ft4;
+ANALYZE ft5;
+-- join two tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3, t1.c3
+ Relations: ((public.ft1 t1) INNER JOIN (public.ft2 t2)) INNER JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3, r1.c3 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) INNER JOIN "S 1"."T 3" r4 ON (((r1."C 1" = r4.c1)))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 22 |
+ 24 | 24
+ 26 |
+ 28 |
+ 30 | 30
+ 32 |
+ 34 |
+ 36 | 36
+ 38 |
+ 40 |
+(10 rows)
+
+-- left outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + placement of clauses.
+-- clauses within the nullable side are not pulled up, but top level clause on
+-- non-nullable side is pushed into non-nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- clauses within the nullable side are not pulled up, but the top level clause
+-- on nullable side is not pushed down into nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE (((r4.c1 < 10) OR (r4.c1 IS NULL))) AND ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t2) LEFT JOIN (public.ft5 t1)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r1 ON (((r1.c1 = r2.c1)))) ORDER BY r2.c1 ASC NULLS LAST, r1.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ | 22
+ 24 | 24
+ | 26
+ | 28
+ 30 | 30
+ | 32
+ | 34
+ 36 | 36
+ | 38
+ | 40
+(10 rows)
+
+-- right outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 45::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ c1 | c1
+-----+----
+ 92 |
+ 94 |
+ 96 | 96
+ 98 |
+ 100 |
+ | 3
+ | 9
+ | 15
+ | 21
+ | 27
+(10 rows)
+
+-- full outer join with restrictions on the joining relations
+-- a. the joining relations are both base relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s4.c1, s5.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s5.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ c1 | c1
+----+----
+ 50 |
+ 52 |
+ 54 | 54
+ 56 |
+ 58 |
+ 60 | 60
+ | 51
+ | 57
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: 1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT NULL FROM ((SELECT NULL FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4 FULL JOIN (SELECT NULL FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5 ON (TRUE)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ ?column?
+----------
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- b. one of the joining relations is a base relation and the other is a join
+-- relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c1, t3.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 t2) LEFT JOIN (public.ft5 t3))
+ Remote SQL: SELECT s4.c1, s8.c1, s8.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT r5.c1, r6.c1 FROM ("S 1"."T 3" r5 LEFT JOIN "S 1"."T 4" r6 ON (((r5.c1 = r6.c1)))) WHERE ((r5.c1 >= 50)) AND ((r5.c1 <= 60))) s8(c1, c2) ON (((s4.c1 = s8.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s8.c1 ASC NULLS LAST, s8.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+(6 rows)
+
+-- c. test deparsing the remote query as nested subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft4_1.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 ft4_1) FULL JOIN (public.ft5))
+ Remote SQL: SELECT s4.c1, s10.c1, s10.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT s8.c1, s9.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL)))) s10(c1, c2) ON (((s4.c1 = s10.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s10.c1 ASC NULLS LAST, s10.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+ | | 51
+ | | 57
+(8 rows)
+
+-- d. test deparsing rowmarked relations as subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Nested Loop
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Foreign Scan
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s8.c1, s8.c2, s9.c1, s9.c2 FROM ((SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1, c2) FULL JOIN (SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1, c2) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL))) ORDER BY s8.c1 ASC NULLS LAST, s9.c1 ASC NULLS LAST
+ -> Sort
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Full Join
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Hash Cond: (ft4.c1 = ft5.c1)
+ Filter: ((ft4.c1 IS NULL) OR (ft4.c1 IS NOT NULL))
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Hash
+ Output: ft5.c1, ft5.*
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Materialize
+ Output: "T 3".c1, "T 3".ctid
+ -> Seq Scan on "S 1"."T 3"
+ Output: "T 3".c1, "T 3".ctid
+ Filter: ("T 3".c1 = 50)
+(28 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 50 | 52 |
+ 50 | 54 | 54
+ 50 | 56 |
+ 50 | 58 |
+ 50 | 60 | 60
+ 50 | | 51
+ 50 | | 57
+(8 rows)
+
+-- full outer join + inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t3.c1
+ Relations: ((public.ft4 t1) INNER JOIN (public.ft5 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1.c1, r2.c1, r4.c1 FROM (("S 1"."T 3" r1 INNER JOIN "S 1"."T 4" r2 ON (((r1.c1 = (r2.c1 + 1))) AND ((r1.c1 >= 50)) AND ((r1.c1 <= 60)))) FULL JOIN "S 1"."T 3" r4 ON (((r2.c1 = r4.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST, r4.c1 ASC NULLS LAST LIMIT 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ c1 | c1 | c1
+----+----+----
+ 52 | 51 |
+ 58 | 57 |
+ | | 2
+ | | 4
+ | | 6
+ | | 8
+ | | 10
+ | | 12
+ | | 14
+ | | 16
+(10 rows)
+
+-- full outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- right outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+SET enable_memoize TO off;
+-- right outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+RESET enable_memoize;
+-- left outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: (public.ft4 t3) LEFT JOIN ((public.ft2 t1) INNER JOIN (public.ft2 t2))
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM ("S 1"."T 3" r4 LEFT JOIN ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join + WHERE clause, only matched rows
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 = r2.c1) OR (r1.c1 IS NULL)))
+(9 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 66 | 66
+ 72 | 72
+ 78 | 78
+ 84 | 84
+ 90 | 90
+ 96 | 96
+ | 3
+ | 9
+ | 15
+ | 21
+(10 rows)
+
+-- full outer join + WHERE clause with shippable extensions set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) WHERE ((public.postgres_fdw_abs(r1."C 1") > 0)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+-- full outer join + WHERE clause with shippable extensions not set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c2, t1.c3
+ -> Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Filter: (postgres_fdw_abs(t1.c1) > 0)
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- join two tables with FOR UPDATE clause
+-- tests whole-row reference for row marks
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1 FOR UPDATE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join two tables with FOR SHARE clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1 FOR SHARE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join in CTE
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t.c1_1, t.c2_1, t.c1_3
+ CTE t
+ -> Foreign Scan
+ Output: t1.c1, t1.c3, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r1.c3, r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+ -> Sort
+ Output: t.c1_1, t.c2_1, t.c1_3
+ Sort Key: t.c1_3, t.c1_1
+ -> CTE Scan on t
+ Output: t.c1_1, t.c2_1, t.c1_3
+(12 rows)
+
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ c1_1 | c2_1
+------+------
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- ctid with whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.ctid, t1.*, t2.*, t1.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r1."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+-- SEMI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Semi Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c1)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- ANTI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Anti Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c2)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 110
+ 111
+ 112
+ 113
+ 114
+ 115
+ 116
+ 117
+ 118
+ 119
+(10 rows)
+
+-- CROSS JOIN can be pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (TRUE)) ORDER BY r1."C 1" ASC NULLS LAST, r2."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- different server, not pushed down. No result expected.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Merge Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft6 t2
+ Output: t2.c1, t2.c2, t2.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+ -> Materialize
+ Output: t1.c1, t1.c2, t1.c3
+ -> Foreign Scan on public.ft5 t1
+ Output: t1.c1, t1.c2, t1.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+(13 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+----
+(0 rows)
+
+-- unsafe join conditions (c8 has a UDT), not pushed down. Practically a CROSS
+-- JOIN since c8 in both tables has same value.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Merge Left Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t1.c8 = t2.c8)
+ -> Sort
+ Output: t1.c1, t1.c8
+ Sort Key: t1.c8
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+ -> Sort
+ Output: t2.c1, t2.c8
+ Sort Key: t2.c8
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1, t2.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+(20 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- unsafe conditions on one side (c8 has a UDT), not pushed down.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Hash Right Join
+ Output: t1.c1, t2.c1, t1.c3
+ Hash Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+ -> Hash
+ Output: t1.c1, t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c3
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c3, c8 FROM "S 1"."T 1"
+(17 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join where unsafe to pushdown condition in WHERE clause has a column not
+-- in the SELECT clause. In this test unsafe clause needs to have column
+-- references from both joining sides so that the clause is not pushed down
+-- into one of the joining sides.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Filter: (t1.c8 = t2.c8)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, r1.c8, r2.c8 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(10 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- Aggregate after UNION, for testing setrefs
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ -> Sort
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ Sort Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, avg((t1.c1 + t2.c1))
+ Group Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, t2.c1
+ Group Key: t1.c1, t2.c1
+ -> Append
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+ -> Foreign Scan
+ Output: t1_1.c1, t2_1.c1
+ Relations: (public.ft1 t1_1) INNER JOIN (public.ft2 t2_1)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(20 rows)
+
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ t1c1 | avg
+------+----------------------
+ 101 | 202.0000000000000000
+ 102 | 204.0000000000000000
+ 103 | 206.0000000000000000
+ 104 | 208.0000000000000000
+ 105 | 210.0000000000000000
+ 106 | 212.0000000000000000
+ 107 | 214.0000000000000000
+ 108 | 216.0000000000000000
+ 109 | 218.0000000000000000
+ 110 | 220.0000000000000000
+(10 rows)
+
+-- join with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Nested Loop
+ Output: t1."C 1"
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ -> Memoize
+ Cache Key: t1.c2
+ Cache Mode: binary
+ -> Subquery Scan on q
+ -> HashAggregate
+ Output: t2.c1, t3.c1
+ Group Key: t2.c1, t3.c1
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")) AND ((r1.c2 = $1::integer))))
+(17 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ C 1
+-----
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- non-Var items in targetlist of the nullable rel of a join preventing
+-- push-down in some cases
+-- unable to push {ft1, ft2}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: (13), ft2.c1
+ Join Filter: (13 = ft2.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" WHERE (("C 1" >= 10)) AND (("C 1" <= 15)) ORDER BY "C 1" ASC NULLS LAST
+ -> Materialize
+ Output: (13)
+ -> Foreign Scan on public.ft1
+ Output: 13
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 13))
+(11 rows)
+
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ a | c1
+----+----
+ | 10
+ | 11
+ | 12
+ 13 | 13
+ | 14
+ | 15
+(6 rows)
+
+-- ok to push {ft1, ft2} but not {ft1, ft2, ft4}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: ft4.c1, (13), ft1.c1, ft2.c1
+ Join Filter: (ft4.c1 = ft1.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
+ -> Materialize
+ Output: ft1.c1, ft2.c1, (13)
+ -> Foreign Scan
+ Output: ft1.c1, ft2.c1, 13
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r5."C 1" FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = 12)) AND ((r4."C 1" = 12)))) ORDER BY r4."C 1" ASC NULLS LAST
+(12 rows)
+
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ c1 | a | b | c
+----+----+----+----
+ 10 | | |
+ 12 | 13 | 12 | 12
+ 14 | | |
+(3 rows)
+
+-- join with nullable side with some columns with null values
+UPDATE ft5 SET c3 = null where c1 % 9 = 0;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2
+ Relations: (public.ft5) INNER JOIN (public.ft4)
+ Remote SQL: SELECT CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1.c1, r1.c2, r1.c3) END, r1.c1, r1.c2, r1.c3, r2.c1, r2.c2 FROM ("S 1"."T 4" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c1 = r2.c1)) AND ((r2.c1 >= 10)) AND ((r2.c1 <= 30)))) ORDER BY r1.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ ft5 | c1 | c2 | c3 | c1 | c2
+----------------+----+----+--------+----+----
+ (12,13,AAA012) | 12 | 13 | AAA012 | 12 | 13
+ (18,19,) | 18 | 19 | | 18 | 19
+ (24,25,AAA024) | 24 | 25 | AAA024 | 24 | 25
+ (30,31,AAA030) | 30 | 31 | AAA030 | 30 | 31
+(4 rows)
+
+-- multi-way join involving multiple merge joins
+-- (this case used to have EPQ-related planning problems)
+CREATE TABLE local_tbl (c1 int NOT NULL, c2 int NOT NULL, c3 text, CONSTRAINT local_tbl_pkey PRIMARY KEY (c1));
+INSERT INTO local_tbl SELECT id, id % 10, to_char(id, 'FM0000') FROM generate_series(1, 1000) id;
+ANALYZE local_tbl;
+SET enable_nestloop TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ Inner Unique: true
+ Merge Cond: (ft1.c2 = local_tbl.c1)
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Relations: (((public.ft1) INNER JOIN (public.ft2)) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r3.c1, r3.c2, r3.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r4.c1, r4.c2, r4.c3, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4.c1, r4.c2, r4.c3) END FROM ((("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")) AND ((r2."C 1" < 100)) AND ((r1."C 1" < 100)))) INNER JOIN "S 1"."T 3" r3 ON (((r1.c2 = r3.c1)))) INNER JOIN "S 1"."T 4" r4 ON (((r1.c2 = r4.c1)))) ORDER BY r1.c2 ASC NULLS LAST FOR UPDATE OF r1 FOR UPDATE OF r2 FOR UPDATE OF r3 FOR UPDATE OF r4
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Merge Cond: (ft1.c2 = ft5.c1)
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Merge Cond: (ft1.c2 = ft4.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Sort Key: ft1.c2
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Merge Cond: (ft1.c1 = ft2.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) FOR UPDATE
+ -> Materialize
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Sort
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Sort Key: ft4.c1
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" FOR UPDATE
+ -> Sort
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Sort Key: ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" FOR UPDATE
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+(47 rows)
+
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3 | c1 | c2 | c3
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+--------+----+----+--------+----+----+------
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+(10 rows)
+
+RESET enable_nestloop;
+RESET enable_hashjoin;
+-- test that add_paths_with_pathkeys_for_rel() arranges for the epq_path to
+-- return columns needed by the parent ForeignScan node
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.*, COALESCE(ft1.c3 || ft2.c3, 'foobar') FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100)) ss ON (local_tbl.c1 = ss.c1) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ -> Merge Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ Merge Cond: (local_tbl.c1 = ft1.c1)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text))
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c3 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = r4."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4."C 1" ASC NULLS LAST
+ -> Result
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c3
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), ft2.c3
+ Sort Key: ft1.c1
+ -> Hash Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text), ft2.c3
+ Hash Cond: (ft1.c1 = ft2.c1)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Hash
+ Output: ft2.*, ft2.c1, ft2.c3
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(29 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD fdw_startup_cost '10000.0');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.* FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100 AND ft1.c1 = postgres_fdw_abs(ft2.c2))) ss ON (local_tbl.c3 = ss.c3) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ -> Nested Loop Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ Join Filter: (local_tbl.c3 = ft1.c3)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ Filter: (ft1.c1 = postgres_fdw_abs(ft2.c2))
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c2 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = r4."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4.c3 ASC NULLS LAST
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Sort Key: ft1.c3
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Merge Cond: ((ft1.c1 = (postgres_fdw_abs(ft2.c2))) AND (ft1.c1 = ft2.c1))
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Sort
+ Output: ft2.*, ft2.c1, ft2.c2, (postgres_fdw_abs(ft2.c2))
+ Sort Key: (postgres_fdw_abs(ft2.c2)), ft2.c1
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, postgres_fdw_abs(ft2.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(32 rows)
+
+ALTER SERVER loopback OPTIONS (DROP fdw_startup_cost);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+DROP TABLE local_tbl;
+-- check join pushdown in situations where multiple userids are involved
+CREATE ROLE regress_view_owner SUPERUSER;
+CREATE USER MAPPING FOR regress_view_owner SERVER loopback;
+GRANT SELECT ON ft4 TO regress_view_owner;
+GRANT SELECT ON ft5 TO regress_view_owner;
+CREATE VIEW v4 AS SELECT * FROM ft4;
+CREATE VIEW v5 AS SELECT * FROM ft5;
+ALTER VIEW v5 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, different view owners
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, ft5.c2, ft5.c1
+ -> Sort
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Left Join
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.c2, ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c2, ft5.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r6.c1, r9.c2, r9.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r9 ON (((r6.c1 = r9.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r9.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, view owner not current user
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, t2.c2, t2.c1
+ -> Sort
+ Output: ft4.c1, t2.c2, t2.c1
+ Sort Key: ft4.c1, t2.c1
+ -> Hash Left Join
+ Output: ft4.c1, t2.c2, t2.c1
+ Hash Cond: (ft4.c1 = t2.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: t2.c2, t2.c1
+ -> Foreign Scan on public.ft5 t2
+ Output: t2.c2, t2.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO CURRENT_USER;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c2, t2.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r6.c1, r2.c2, r2.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r2 ON (((r6.c1 = r2.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+-- cleanup
+DROP OWNED BY regress_view_owner;
+DROP ROLE regress_view_owner;
+-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+------+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+ 100 | 49700 | 497.0000000000000000 | 2 | 992 | 0 | 49700
+ 100 | 49800 | 498.0000000000000000 | 3 | 993 | 0 | 49800
+ 100 | 49900 | 499.0000000000000000 | 4 | 994 | 0 | 49900
+ 100 | 50500 | 505.0000000000000000 | 0 | 1000 | 0 | 50500
+(5 rows)
+
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST LIMIT 1::bigint
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+-----+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+(1 row)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * (random() <= 1)::int) as sum, avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Aggregate
+ Output: sum((c1 * ((random() <= '1'::double precision))::integer)), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT count(*), sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ count | sum | avg
+-------+---------+----------------------
+ 10000 | 5010000 | 501.0000000000000000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where ((t1.c1 * t2.c1)/(t1.c1 * t2.c1)) * random() <= 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(t1.c1), count(t2.c1)
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Filter: (((((t1.c1 * t2.c1) / (t1.c1 * t2.c1)))::double precision * random()) <= '1'::double precision)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(7 rows)
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY 1 ORDER BY (c2 / 2) ASC NULLS LAST
+(4 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 500
+ 2 | 1800
+ 3 | 3900
+ 4 | 6800
+(5 rows)
+
+-- Aggregates in subquery are pushed down.
+set enable_incremental_sort = off;
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 ORDER BY c2 ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(6 rows)
+
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+------
+ 1000 | 4500
+(1 row)
+
+reset enable_incremental_sort;
+-- Aggregate is still pushed down by taking unshippable expression out
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer)), ((sum(c1) * c2)), c2
+ Sort Key: ((ft1.c2 * ((random() <= '1'::double precision))::integer)), ((sum(ft1.c1) * ft1.c2))
+ -> Foreign Scan
+ Output: (c2 * ((random() <= '1'::double precision))::integer), ((sum(c1) * c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum("C 1") * c2), c2 FROM "S 1"."T 1" GROUP BY 2
+(7 rows)
+
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ sum1 | sum2
+------+--------
+ 0 | 0
+ 1 | 49600
+ 2 | 99400
+ 3 | 149400
+ 4 | 199600
+ 5 | 250000
+ 6 | 300600
+ 7 | 351400
+ 8 | 402400
+ 9 | 453600
+(10 rows)
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::int order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Sort Key: ((ft2.c2 * ((random() <= '1'::double precision))::integer))
+ -> HashAggregate
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Group Key: (ft2.c2 * ((random() <= '1'::double precision))::integer)
+ -> Foreign Scan on public.ft2
+ Output: (c2 * ((random() <= '1'::double precision))::integer)
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- GROUP BY clause in various forms, cardinal, alias and constant expression
+explain (verbose, costs off)
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), c2, 5, 7.0, 9 FROM "S 1"."T 1" GROUP BY 2, 3, 5
+(7 rows)
+
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ w | x | y | z
+-----+---+---+-----
+ 100 | 0 | 5 | 7.0
+ 100 | 1 | 5 | 7.0
+ 100 | 2 | 5 | 7.0
+ 100 | 3 | 5 | 7.0
+ 100 | 4 | 5 | 7.0
+ 100 | 5 | 5 | 7.0
+ 100 | 6 | 5 | 7.0
+ 100 | 7 | 5 | 7.0
+ 100 | 8 | 5 | 7.0
+ 100 | 9 | 5 | 7.0
+(10 rows)
+
+-- GROUP BY clause referring to same column multiple times
+-- Also, ORDER BY contains an aggregate function
+explain (verbose, costs off)
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, c2, (sum(c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, c2, sum("C 1") FROM "S 1"."T 1" WHERE ((c2 > 6)) GROUP BY 1, 2 ORDER BY sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ c2 | c2
+----+----
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(3 rows)
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 49800)) ORDER BY c2 ASC NULLS LAST
+(4 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ c2 | sum
+----+-------
+ 1 | 49600
+ 2 | 49700
+(2 rows)
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, NULL::bigint, (sqrt((ft1.c2)::double precision))
+ Filter: (((((avg(ft1.c1)) / (avg(ft1.c1))))::double precision * random()) <= '1'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ count
+-------
+ 49
+(1 row)
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * (random() <= 1)::int) > 100 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1)), c2
+ Sort Key: (sum(ft1.c1))
+ -> HashAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Filter: (avg((ft1.c1 * ((random() <= '1'::double precision))::integer)) > '100'::numeric)
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(10 rows)
+
+-- Remote aggregate in combination with a local Param (for the output
+-- of an initplan) can be trouble, per bug #15781
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ QUERY PLAN
+--------------------------------------------------
+ Foreign Scan
+ Output: $0, (sum(ft1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1"
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+(6 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ QUERY PLAN
+---------------------------------------------------
+ GroupAggregate
+ Output: ($0), sum(ft1.c1)
+ Group Key: $0
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+ -> Foreign Scan on public.ft1
+ Output: $0, ft1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(8 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY 2 ORDER BY array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1,11,21,31,41,51,61,71,81,91}
+ {2,12,22,32,42,52,62,72,82,92}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {5,15,25,35,45,55,65,75,85,95}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+(10 rows)
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5)) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY 2 ORDER BY sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))) ASC NULLS LAST
+(4 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+(10 rows)
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3) ORDER BY (("C 1" % 3)) ASC NULLS LAST) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY 3
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft2 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where (c1 / c1) * random() <= 1) from ft1 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((((ft1.c1 / ft1.c1))::double precision * random()) <= '1'::double precision)))
+ -> HashAggregate
+ Output: sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST), percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
+(7 rows)
+
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | rank | percentile_cont
+----+------+-----------------
+ 0 | 101 | 10
+ 1 | 101 | 100
+ 2 | 1 | 200
+ 3 | 1 | 300
+ 4 | 1 | 400
+(5 rows)
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY 1, 3
+(4 rows)
+
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ c1 | rank
+----+------
+ 6 | 1
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Disable hash aggregation for plan stability.
+set enable_hashagg to false;
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY 1
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 0 | 10
+ 1 | 1
+ 2 | 2
+ 3 | 3
+ 4 | 4
+ 5 | 5
+ 6 | 6
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(10 rows)
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Cleanup
+reset enable_hashagg;
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+create operator family my_op_family using btree;
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- This should not be pushed either.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- Update local stats on ft2
+ANALYZE ft2;
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now this will be pushed as sort operator is part of the extension.
+alter server loopback options (add fdw_tuple_cost '0.5');
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY 2
+(4 rows)
+
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+alter server loopback options (drop fdw_tuple_cost);
+-- This should be pushed too.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST
+(3 rows)
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft2 t1 left join ft2 t2 on (t1.c1 = random() * t2.c2);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop Left Join
+ Output: t1.c3
+ Join Filter: ((t1.c1)::double precision = (random() * (t2.c2)::double precision))
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c3, t1.c1
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1"
+ -> Materialize
+ Output: t2.c2
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(13 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Inner Unique: true
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1 ft1_1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1
+(21 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 100 | 49600
+ 100 | 49700
+ 100 | 49800
+ 100 | 49900
+ 100 | 50000
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(10 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY 3 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL))) ORDER BY avg(r1.c1) ASC NULLS LAST, sum(r2.c1) ASC NULLS LAST
+(4 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- Aggregate over FULL join needing to deparse the joining relations as
+-- subqueries.
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(ft4.c1)), (avg(ft5.c1))
+ Relations: Aggregate on ((public.ft4) FULL JOIN (public.ft5))
+ Remote SQL: SELECT count(*), sum(s4.c1), avg(s5.c1) FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ count | sum | avg
+-------+-----+---------------------
+ 8 | 330 | 55.5000000000000000
+(1 row)
+
+-- ORDER BY expression is part of the target list but not pushed down to
+-- foreign server.
+explain (verbose, costs off)
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: (((sum(c2)) * ((random() <= '1'::double precision))::integer))
+ Sort Key: (((sum(ft1.c2)) * ((random() <= '1'::double precision))::integer))
+ -> Foreign Scan
+ Output: ((sum(c2)) * ((random() <= '1'::double precision))::integer)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
+(7 rows)
+
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ sum
+------
+ 4500
+(1 row)
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c2, qry.sum
+ Sort Key: t1.c2
+ -> Nested Loop
+ Output: t1.c2, qry.sum
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Index Cond: (t1."C 1" < 100)
+ Filter: (t1.c2 < 3)
+ -> Subquery Scan on qry
+ Output: qry.sum, t2.c1
+ Filter: ((t1.c2 * 2) = qry.sum)
+ -> Foreign Scan
+ Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY 2
+(16 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ c2 | sum
+----+-----
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+reset enable_hashagg;
+-- bug #15613: bad plan for foreign table scan with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: ref_0.c2, ref_0."C 1", (ref_0.c2), ref_1.c3, ref_0."C 1"
+ -> Nested Loop
+ Output: ref_0.c2, ref_0."C 1", ref_1.c3, (ref_0.c2)
+ -> Index Scan using t1_pkey on "S 1"."T 1" ref_0
+ Output: ref_0."C 1", ref_0.c2, ref_0.c3, ref_0.c4, ref_0.c5, ref_0.c6, ref_0.c7, ref_0.c8
+ Index Cond: (ref_0."C 1" < 10)
+ -> Foreign Scan on public.ft1 ref_1
+ Output: ref_1.c3, ref_0.c2
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+ -> Materialize
+ Output: ref_3.c3
+ -> Foreign Scan on public.ft2 ref_3
+ Output: ref_3.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+(15 rows)
+
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ c2 | c1 | c2 | c3
+----+----+----+-------
+ 1 | 1 | 1 | 00001
+ 2 | 2 | 2 | 00001
+ 3 | 3 | 3 | 00001
+ 4 | 4 | 4 | 00001
+ 5 | 5 | 5 | 00001
+ 6 | 6 | 6 | 00001
+ 7 | 7 | 7 | 00001
+ 8 | 8 | 8 | 00001
+ 9 | 9 | 9 | 00001
+(9 rows)
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(q.a), count(q.b)
+ -> Nested Loop Left Join
+ Output: q.a, q.b
+ Inner Unique: true
+ Join Filter: ((ft4.c1)::numeric <= q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Materialize
+ Output: q.a, q.b
+ -> Subquery Scan on q
+ Output: q.a, q.b
+ -> Foreign Scan
+ Output: 13, (avg(ft1.c1)), NULL::bigint
+ Relations: Aggregate on ((public.ft2) LEFT JOIN (public.ft1))
+ Remote SQL: SELECT 13, avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1"))))
+(17 rows)
+
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ sum | count
+-----+-------
+ 650 | 50
+(1 row)
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: c2, c6, (sum(c1))
+ Sort Key: ft1.c2, ft1.c6
+ -> HashAggregate
+ Output: c2, c6, sum(c1)
+ Hash Key: ft1.c2
+ Hash Key: ft1.c6
+ -> Foreign Scan on public.ft1
+ Output: c2, c6, c1
+ Remote SQL: SELECT "C 1", c2, c6 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 0 | | 50500
+ 1 | | 49600
+ 2 | | 49700
+ | 0 | 50500
+ | 1 | 49600
+ | 2 | 49700
+(6 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1)), (GROUPING(c2))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, sum(c1), GROUPING(c2)
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(9 rows)
+
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 0 | 50500 | 0
+ 1 | 49600 | 0
+ 2 | 49700 | 0
+(3 rows)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((sum(c1) / 1000)), c2
+ -> Sort
+ Output: ((sum(c1) / 1000)), c2
+ Sort Key: ((sum(ft2.c1) / 1000))
+ -> Foreign Scan
+ Output: ((sum(c1) / 1000)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT (sum("C 1") / 1000), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY 2
+(9 rows)
+
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ s
+----
+ 49
+ 50
+(2 rows)
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2)), (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, (sum(c2)), count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ c2 | sum | count
+----+-----+-------
+ 0 | 0 | 5
+ 1 | 100 | 5
+ 2 | 200 | 5
+ 3 | 300 | 5
+ 4 | 400 | 5
+ 5 | 500 | 5
+ 6 | 600 | 5
+ 7 | 700 | 5
+ 8 | 800 | 5
+ 9 | 900 | 5
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2 DESC
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {8,6,4,2,0}
+ 1 | {9,7,5,3,1}
+ 2 | {8,6,4,2}
+ 3 | {9,7,5,3}
+ 4 | {8,6,4}
+ 5 | {9,7,5}
+ 6 | {8,6}
+ 7 | {9,7}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {0,2,4,6,8}
+ 1 | {1,3,5,7,9}
+ 2 | {2,4,6,8}
+ 3 | {3,5,7,9}
+ 4 | {4,6,8}
+ 5 | {5,7,9}
+ 6 | {6,8}
+ 7 | {7,9}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+-- ===================================================================
+-- parameterized queries
+-- ===================================================================
+-- simple join
+PREPARE st1(int, int) AS SELECT t1.c3, t2.c3 FROM ft1 t1, ft2 t2 WHERE t1.c1 = $1 AND t2.c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st1(1, 2);
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c3, t2.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.c3, r2.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 2)) AND ((r1."C 1" = 1))))
+(4 rows)
+
+EXECUTE st1(1, 1);
+ c3 | c3
+-------+-------
+ 00001 | 00001
+(1 row)
+
+EXECUTE st1(101, 101);
+ c3 | c3
+-------+-------
+ 00101 | 00101
+(1 row)
+
+-- subquery using stable function (can't be sent to remote)
+PREPARE st2(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c4) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st2(10, 20);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t2.c3 = t1.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Filter: (date(t2.c4) = '01-17-1970'::date)
+ Remote SQL: SELECT c3, c4 FROM "S 1"."T 1" WHERE (("C 1" > 10))
+(15 rows)
+
+EXECUTE st2(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st2(101, 121);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+-- subquery using immutable function (can be sent to remote)
+PREPARE st3(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c5) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st3(10, 20);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t2.c3 = t1.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" > 10)) AND ((date(c5) = '1970-01-17'::date))
+(14 rows)
+
+EXECUTE st3(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st3(20, 30);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- custom plan should be chosen initially
+PREPARE st4(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 = $1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+-- once we try it enough times, should switch to generic plan
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(3 rows)
+
+-- value of $1 should not be sent to remote
+PREPARE st5(user_enum,int) AS SELECT * FROM ft1 t1 WHERE c8 = $1 and c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = $1)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(4 rows)
+
+EXECUTE st5('foo', 1);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- altering FDW options requires replanning
+PREPARE st6 AS SELECT * FROM ft1 t1 WHERE t1.c1 = t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(3 rows)
+
+PREPARE st7 AS INSERT INTO ft1 (c1,c2,c3) VALUES (1001,101,'foo');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 1" RENAME TO "T 0";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 0');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 0" WHERE (("C 1" = c2))
+(3 rows)
+
+EXECUTE st6;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 0"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 0" RENAME TO "T 1";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 1');
+PREPARE st8 AS SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+EXECUTE st8;
+ count
+-------
+ 9
+(1 row)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- cleanup
+DEALLOCATE st1;
+DEALLOCATE st2;
+DEALLOCATE st3;
+DEALLOCATE st4;
+DEALLOCATE st5;
+DEALLOCATE st6;
+DEALLOCATE st7;
+DEALLOCATE st8;
+-- System columns, except ctid and oid, should not be sent to remote
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'pg_class'::regclass LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.tableoid = '1259'::oid)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'ft1'::regclass LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: (tableoid)::regclass, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ tableoid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ ft1 | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((ctid = '(0,2)'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: ctid, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ ctid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ (0,1) | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- ===================================================================
+-- used in PL/pgSQL function
+-- ===================================================================
+CREATE OR REPLACE FUNCTION f_test(p_c1 int) RETURNS int AS $$
+DECLARE
+ v_c1 int;
+BEGIN
+ SELECT c1 INTO v_c1 FROM ft1 WHERE c1 = p_c1 LIMIT 1;
+ PERFORM c1 FROM ft1 WHERE c1 = p_c1 AND p_c1 = v_c1 LIMIT 1;
+ RETURN v_c1;
+END;
+$$ LANGUAGE plpgsql;
+SELECT f_test(100);
+ f_test
+--------
+ 100
+(1 row)
+
+DROP FUNCTION f_test(int);
+-- ===================================================================
+-- REINDEX
+-- ===================================================================
+-- remote table is not created here
+CREATE FOREIGN TABLE reindex_foreign (c1 int, c2 int)
+ SERVER loopback2 OPTIONS (table_name 'reindex_local');
+REINDEX TABLE reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+REINDEX TABLE CONCURRENTLY reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+DROP FOREIGN TABLE reindex_foreign;
+-- partitions and foreign tables
+CREATE TABLE reind_fdw_parent (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE reind_fdw_0_10 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (0) TO (10);
+CREATE FOREIGN TABLE reind_fdw_10_20 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (10) TO (20)
+ SERVER loopback OPTIONS (table_name 'reind_local_10_20');
+REINDEX TABLE reind_fdw_parent; -- ok
+REINDEX TABLE CONCURRENTLY reind_fdw_parent; -- ok
+DROP TABLE reind_fdw_parent;
+-- ===================================================================
+-- conversion error
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int;
+SELECT * FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8) WHERE x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx.x8 FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: whole-row reference to foreign table "ftx"
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: processing expression at position 2 in select list
+ANALYZE ft1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "c8" of foreign table "ft1"
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- local type can be different from remote type in some cases,
+-- in particular if similarly-named operators do equivalent things
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE text;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 = 'foo')) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (('foo' = c8)) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- we declared c8 to be text locally, but it's still the same type on
+-- the remote which will balk if we try to do anything incompatible
+-- with that remote type
+SELECT * FROM ft1 WHERE c8 LIKE 'foo' LIMIT 1; -- ERROR
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+SELECT * FROM ft1 WHERE c8::text LIKE 'foo' LIMIT 1; -- ERROR; cast not pushed down
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- subtransaction
+-- + local/remote error doesn't break cursor
+-- ===================================================================
+BEGIN;
+DECLARE c CURSOR FOR SELECT * FROM ft1 ORDER BY c1;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+SAVEPOINT s;
+ERROR OUT; -- ERROR
+ERROR: syntax error at or near "ERROR"
+LINE 1: ERROR OUT;
+ ^
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+SAVEPOINT s;
+SELECT * FROM ft1 WHERE 1 / (c1 - 1) > 0; -- ERROR
+ERROR: division by zero
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (((1 / ("C 1" - 1)) > 0))
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c1 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+COMMIT;
+-- ===================================================================
+-- test handling of collations
+-- ===================================================================
+create table loct3 (f1 text collate "C" unique, f2 text, f3 varchar(10) unique);
+create foreign table ft3 (f1 text collate "C", f2 text, f3 varchar(10))
+ server loopback options (table_name 'loct3', use_remote_estimate 'true');
+-- can be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "C" = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f2 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f3 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 and l.f1 = 'foo';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = $1::character varying(10)))
+(8 rows)
+
+-- can't be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "POSIX" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f1)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f1 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 COLLATE "C" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f2)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f2 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 COLLATE "POSIX" and l.f1 = 'foo';
+ QUERY PLAN
+-------------------------------------------------------------
+ Hash Join
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ Inner Unique: true
+ Hash Cond: ((f.f3)::text = (l.f3)::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+ -> Hash
+ Output: l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+(12 rows)
+
+-- ===================================================================
+-- test writable foreign table stuff
+-- ===================================================================
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Subquery Scan on "*SELECT*"
+ Output: "*SELECT*"."?column?", "*SELECT*"."?column?_1", NULL::integer, "*SELECT*"."?column?_2", NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+ -> Foreign Scan on public.ft2 ft2_1
+ Output: (ft2_1.c1 + 1000), (ft2_1.c2 + 100), (ft2_1.c3 || ft2_1.c3)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" LIMIT 20::bigint
+(8 rows)
+
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+INSERT INTO ft2 (c1,c2,c3)
+ VALUES (1101,201,'aaa'), (1102,202,'bbb'), (1103,203,'ccc') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----+----+----+----+------------+----
+ 1101 | 201 | aaa | | | | ft2 |
+ 1102 | 202 | bbb | | | | ft2 |
+ 1103 | 203 | ccc | | | | ft2 |
+(3 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1104,204,'ddd'), (1105,205,'eee');
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 300), c3 = (c3 || '_update3') WHERE ((("C 1" % 10) = 3))
+(3 rows)
+
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 400), c3 = (c3 || '_update7') WHERE ((("C 1" % 10) = 7)) RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+(4 rows)
+
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+----+------------+-----
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 1007 | 507 | 0000700007_update7 | | | | ft2 |
+ 1017 | 507 | 0001700017_update7 | | | | ft2 |
+(102 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9; -- can be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c2 = (r1.c2 + 500), c3 = (r1.c3 || '_update9'), c7 = 'ft2 '::character(10) FROM "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 9))
+(3 rows)
+
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9;
+EXPLAIN (verbose, costs off)
+ DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: c1, c4
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 5)) RETURNING "C 1", c4
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4;
+ c1 | c4
+------+------------------------------
+ 5 | Tue Jan 06 00:00:00 1970 PST
+ 15 | Fri Jan 16 00:00:00 1970 PST
+ 25 | Mon Jan 26 00:00:00 1970 PST
+ 35 | Thu Feb 05 00:00:00 1970 PST
+ 45 | Sun Feb 15 00:00:00 1970 PST
+ 55 | Wed Feb 25 00:00:00 1970 PST
+ 65 | Sat Mar 07 00:00:00 1970 PST
+ 75 | Tue Mar 17 00:00:00 1970 PST
+ 85 | Fri Mar 27 00:00:00 1970 PST
+ 95 | Mon Apr 06 00:00:00 1970 PST
+ 105 | Tue Jan 06 00:00:00 1970 PST
+ 115 | Fri Jan 16 00:00:00 1970 PST
+ 125 | Mon Jan 26 00:00:00 1970 PST
+ 135 | Thu Feb 05 00:00:00 1970 PST
+ 145 | Sun Feb 15 00:00:00 1970 PST
+ 155 | Wed Feb 25 00:00:00 1970 PST
+ 165 | Sat Mar 07 00:00:00 1970 PST
+ 175 | Tue Mar 17 00:00:00 1970 PST
+ 185 | Fri Mar 27 00:00:00 1970 PST
+ 195 | Mon Apr 06 00:00:00 1970 PST
+ 205 | Tue Jan 06 00:00:00 1970 PST
+ 215 | Fri Jan 16 00:00:00 1970 PST
+ 225 | Mon Jan 26 00:00:00 1970 PST
+ 235 | Thu Feb 05 00:00:00 1970 PST
+ 245 | Sun Feb 15 00:00:00 1970 PST
+ 255 | Wed Feb 25 00:00:00 1970 PST
+ 265 | Sat Mar 07 00:00:00 1970 PST
+ 275 | Tue Mar 17 00:00:00 1970 PST
+ 285 | Fri Mar 27 00:00:00 1970 PST
+ 295 | Mon Apr 06 00:00:00 1970 PST
+ 305 | Tue Jan 06 00:00:00 1970 PST
+ 315 | Fri Jan 16 00:00:00 1970 PST
+ 325 | Mon Jan 26 00:00:00 1970 PST
+ 335 | Thu Feb 05 00:00:00 1970 PST
+ 345 | Sun Feb 15 00:00:00 1970 PST
+ 355 | Wed Feb 25 00:00:00 1970 PST
+ 365 | Sat Mar 07 00:00:00 1970 PST
+ 375 | Tue Mar 17 00:00:00 1970 PST
+ 385 | Fri Mar 27 00:00:00 1970 PST
+ 395 | Mon Apr 06 00:00:00 1970 PST
+ 405 | Tue Jan 06 00:00:00 1970 PST
+ 415 | Fri Jan 16 00:00:00 1970 PST
+ 425 | Mon Jan 26 00:00:00 1970 PST
+ 435 | Thu Feb 05 00:00:00 1970 PST
+ 445 | Sun Feb 15 00:00:00 1970 PST
+ 455 | Wed Feb 25 00:00:00 1970 PST
+ 465 | Sat Mar 07 00:00:00 1970 PST
+ 475 | Tue Mar 17 00:00:00 1970 PST
+ 485 | Fri Mar 27 00:00:00 1970 PST
+ 495 | Mon Apr 06 00:00:00 1970 PST
+ 505 | Tue Jan 06 00:00:00 1970 PST
+ 515 | Fri Jan 16 00:00:00 1970 PST
+ 525 | Mon Jan 26 00:00:00 1970 PST
+ 535 | Thu Feb 05 00:00:00 1970 PST
+ 545 | Sun Feb 15 00:00:00 1970 PST
+ 555 | Wed Feb 25 00:00:00 1970 PST
+ 565 | Sat Mar 07 00:00:00 1970 PST
+ 575 | Tue Mar 17 00:00:00 1970 PST
+ 585 | Fri Mar 27 00:00:00 1970 PST
+ 595 | Mon Apr 06 00:00:00 1970 PST
+ 605 | Tue Jan 06 00:00:00 1970 PST
+ 615 | Fri Jan 16 00:00:00 1970 PST
+ 625 | Mon Jan 26 00:00:00 1970 PST
+ 635 | Thu Feb 05 00:00:00 1970 PST
+ 645 | Sun Feb 15 00:00:00 1970 PST
+ 655 | Wed Feb 25 00:00:00 1970 PST
+ 665 | Sat Mar 07 00:00:00 1970 PST
+ 675 | Tue Mar 17 00:00:00 1970 PST
+ 685 | Fri Mar 27 00:00:00 1970 PST
+ 695 | Mon Apr 06 00:00:00 1970 PST
+ 705 | Tue Jan 06 00:00:00 1970 PST
+ 715 | Fri Jan 16 00:00:00 1970 PST
+ 725 | Mon Jan 26 00:00:00 1970 PST
+ 735 | Thu Feb 05 00:00:00 1970 PST
+ 745 | Sun Feb 15 00:00:00 1970 PST
+ 755 | Wed Feb 25 00:00:00 1970 PST
+ 765 | Sat Mar 07 00:00:00 1970 PST
+ 775 | Tue Mar 17 00:00:00 1970 PST
+ 785 | Fri Mar 27 00:00:00 1970 PST
+ 795 | Mon Apr 06 00:00:00 1970 PST
+ 805 | Tue Jan 06 00:00:00 1970 PST
+ 815 | Fri Jan 16 00:00:00 1970 PST
+ 825 | Mon Jan 26 00:00:00 1970 PST
+ 835 | Thu Feb 05 00:00:00 1970 PST
+ 845 | Sun Feb 15 00:00:00 1970 PST
+ 855 | Wed Feb 25 00:00:00 1970 PST
+ 865 | Sat Mar 07 00:00:00 1970 PST
+ 875 | Tue Mar 17 00:00:00 1970 PST
+ 885 | Fri Mar 27 00:00:00 1970 PST
+ 895 | Mon Apr 06 00:00:00 1970 PST
+ 905 | Tue Jan 06 00:00:00 1970 PST
+ 915 | Fri Jan 16 00:00:00 1970 PST
+ 925 | Mon Jan 26 00:00:00 1970 PST
+ 935 | Thu Feb 05 00:00:00 1970 PST
+ 945 | Sun Feb 15 00:00:00 1970 PST
+ 955 | Wed Feb 25 00:00:00 1970 PST
+ 965 | Sat Mar 07 00:00:00 1970 PST
+ 975 | Tue Mar 17 00:00:00 1970 PST
+ 985 | Fri Mar 27 00:00:00 1970 PST
+ 995 | Mon Apr 06 00:00:00 1970 PST
+ 1005 |
+ 1015 |
+ 1105 |
+(103 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 2))
+(3 rows)
+
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2;
+SELECT c1,c2,c3,c4 FROM ft2 ORDER BY c1;
+ c1 | c2 | c3 | c4
+------+-----+--------------------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 3 | 303 | 00003_update3 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+ 11 | 1 | 00011 | Mon Jan 12 00:00:00 1970 PST
+ 13 | 303 | 00013_update3 | Wed Jan 14 00:00:00 1970 PST
+ 14 | 4 | 00014 | Thu Jan 15 00:00:00 1970 PST
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST
+ 18 | 8 | 00018 | Mon Jan 19 00:00:00 1970 PST
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST
+ 20 | 0 | 00020 | Wed Jan 21 00:00:00 1970 PST
+ 21 | 1 | 00021 | Thu Jan 22 00:00:00 1970 PST
+ 23 | 303 | 00023_update3 | Sat Jan 24 00:00:00 1970 PST
+ 24 | 4 | 00024 | Sun Jan 25 00:00:00 1970 PST
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST
+ 28 | 8 | 00028 | Thu Jan 29 00:00:00 1970 PST
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST
+ 30 | 0 | 00030 | Sat Jan 31 00:00:00 1970 PST
+ 31 | 1 | 00031 | Sun Feb 01 00:00:00 1970 PST
+ 33 | 303 | 00033_update3 | Tue Feb 03 00:00:00 1970 PST
+ 34 | 4 | 00034 | Wed Feb 04 00:00:00 1970 PST
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST
+ 38 | 8 | 00038 | Sun Feb 08 00:00:00 1970 PST
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST
+ 40 | 0 | 00040 | Tue Feb 10 00:00:00 1970 PST
+ 41 | 1 | 00041 | Wed Feb 11 00:00:00 1970 PST
+ 43 | 303 | 00043_update3 | Fri Feb 13 00:00:00 1970 PST
+ 44 | 4 | 00044 | Sat Feb 14 00:00:00 1970 PST
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST
+ 48 | 8 | 00048 | Wed Feb 18 00:00:00 1970 PST
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST
+ 50 | 0 | 00050 | Fri Feb 20 00:00:00 1970 PST
+ 51 | 1 | 00051 | Sat Feb 21 00:00:00 1970 PST
+ 53 | 303 | 00053_update3 | Mon Feb 23 00:00:00 1970 PST
+ 54 | 4 | 00054 | Tue Feb 24 00:00:00 1970 PST
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST
+ 58 | 8 | 00058 | Sat Feb 28 00:00:00 1970 PST
+ 59 | 509 | 00059_update9 | Sun Mar 01 00:00:00 1970 PST
+ 60 | 0 | 00060 | Mon Mar 02 00:00:00 1970 PST
+ 61 | 1 | 00061 | Tue Mar 03 00:00:00 1970 PST
+ 63 | 303 | 00063_update3 | Thu Mar 05 00:00:00 1970 PST
+ 64 | 4 | 00064 | Fri Mar 06 00:00:00 1970 PST
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST
+ 68 | 8 | 00068 | Tue Mar 10 00:00:00 1970 PST
+ 69 | 509 | 00069_update9 | Wed Mar 11 00:00:00 1970 PST
+ 70 | 0 | 00070 | Thu Mar 12 00:00:00 1970 PST
+ 71 | 1 | 00071 | Fri Mar 13 00:00:00 1970 PST
+ 73 | 303 | 00073_update3 | Sun Mar 15 00:00:00 1970 PST
+ 74 | 4 | 00074 | Mon Mar 16 00:00:00 1970 PST
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST
+ 78 | 8 | 00078 | Fri Mar 20 00:00:00 1970 PST
+ 79 | 509 | 00079_update9 | Sat Mar 21 00:00:00 1970 PST
+ 80 | 0 | 00080 | Sun Mar 22 00:00:00 1970 PST
+ 81 | 1 | 00081 | Mon Mar 23 00:00:00 1970 PST
+ 83 | 303 | 00083_update3 | Wed Mar 25 00:00:00 1970 PST
+ 84 | 4 | 00084 | Thu Mar 26 00:00:00 1970 PST
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST
+ 88 | 8 | 00088 | Mon Mar 30 00:00:00 1970 PST
+ 89 | 509 | 00089_update9 | Tue Mar 31 00:00:00 1970 PST
+ 90 | 0 | 00090 | Wed Apr 01 00:00:00 1970 PST
+ 91 | 1 | 00091 | Thu Apr 02 00:00:00 1970 PST
+ 93 | 303 | 00093_update3 | Sat Apr 04 00:00:00 1970 PST
+ 94 | 4 | 00094 | Sun Apr 05 00:00:00 1970 PST
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST
+ 98 | 8 | 00098 | Thu Apr 09 00:00:00 1970 PST
+ 99 | 509 | 00099_update9 | Fri Apr 10 00:00:00 1970 PST
+ 100 | 0 | 00100 | Thu Jan 01 00:00:00 1970 PST
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST
+ 103 | 303 | 00103_update3 | Sun Jan 04 00:00:00 1970 PST
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST
+ 109 | 509 | 00109_update9 | Sat Jan 10 00:00:00 1970 PST
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST
+ 111 | 1 | 00111 | Mon Jan 12 00:00:00 1970 PST
+ 113 | 303 | 00113_update3 | Wed Jan 14 00:00:00 1970 PST
+ 114 | 4 | 00114 | Thu Jan 15 00:00:00 1970 PST
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST
+ 118 | 8 | 00118 | Mon Jan 19 00:00:00 1970 PST
+ 119 | 509 | 00119_update9 | Tue Jan 20 00:00:00 1970 PST
+ 120 | 0 | 00120 | Wed Jan 21 00:00:00 1970 PST
+ 121 | 1 | 00121 | Thu Jan 22 00:00:00 1970 PST
+ 123 | 303 | 00123_update3 | Sat Jan 24 00:00:00 1970 PST
+ 124 | 4 | 00124 | Sun Jan 25 00:00:00 1970 PST
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST
+ 128 | 8 | 00128 | Thu Jan 29 00:00:00 1970 PST
+ 129 | 509 | 00129_update9 | Fri Jan 30 00:00:00 1970 PST
+ 130 | 0 | 00130 | Sat Jan 31 00:00:00 1970 PST
+ 131 | 1 | 00131 | Sun Feb 01 00:00:00 1970 PST
+ 133 | 303 | 00133_update3 | Tue Feb 03 00:00:00 1970 PST
+ 134 | 4 | 00134 | Wed Feb 04 00:00:00 1970 PST
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST
+ 138 | 8 | 00138 | Sun Feb 08 00:00:00 1970 PST
+ 139 | 509 | 00139_update9 | Mon Feb 09 00:00:00 1970 PST
+ 140 | 0 | 00140 | Tue Feb 10 00:00:00 1970 PST
+ 141 | 1 | 00141 | Wed Feb 11 00:00:00 1970 PST
+ 143 | 303 | 00143_update3 | Fri Feb 13 00:00:00 1970 PST
+ 144 | 4 | 00144 | Sat Feb 14 00:00:00 1970 PST
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST
+ 148 | 8 | 00148 | Wed Feb 18 00:00:00 1970 PST
+ 149 | 509 | 00149_update9 | Thu Feb 19 00:00:00 1970 PST
+ 150 | 0 | 00150 | Fri Feb 20 00:00:00 1970 PST
+ 151 | 1 | 00151 | Sat Feb 21 00:00:00 1970 PST
+ 153 | 303 | 00153_update3 | Mon Feb 23 00:00:00 1970 PST
+ 154 | 4 | 00154 | Tue Feb 24 00:00:00 1970 PST
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST
+ 158 | 8 | 00158 | Sat Feb 28 00:00:00 1970 PST
+ 159 | 509 | 00159_update9 | Sun Mar 01 00:00:00 1970 PST
+ 160 | 0 | 00160 | Mon Mar 02 00:00:00 1970 PST
+ 161 | 1 | 00161 | Tue Mar 03 00:00:00 1970 PST
+ 163 | 303 | 00163_update3 | Thu Mar 05 00:00:00 1970 PST
+ 164 | 4 | 00164 | Fri Mar 06 00:00:00 1970 PST
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST
+ 168 | 8 | 00168 | Tue Mar 10 00:00:00 1970 PST
+ 169 | 509 | 00169_update9 | Wed Mar 11 00:00:00 1970 PST
+ 170 | 0 | 00170 | Thu Mar 12 00:00:00 1970 PST
+ 171 | 1 | 00171 | Fri Mar 13 00:00:00 1970 PST
+ 173 | 303 | 00173_update3 | Sun Mar 15 00:00:00 1970 PST
+ 174 | 4 | 00174 | Mon Mar 16 00:00:00 1970 PST
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST
+ 178 | 8 | 00178 | Fri Mar 20 00:00:00 1970 PST
+ 179 | 509 | 00179_update9 | Sat Mar 21 00:00:00 1970 PST
+ 180 | 0 | 00180 | Sun Mar 22 00:00:00 1970 PST
+ 181 | 1 | 00181 | Mon Mar 23 00:00:00 1970 PST
+ 183 | 303 | 00183_update3 | Wed Mar 25 00:00:00 1970 PST
+ 184 | 4 | 00184 | Thu Mar 26 00:00:00 1970 PST
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST
+ 188 | 8 | 00188 | Mon Mar 30 00:00:00 1970 PST
+ 189 | 509 | 00189_update9 | Tue Mar 31 00:00:00 1970 PST
+ 190 | 0 | 00190 | Wed Apr 01 00:00:00 1970 PST
+ 191 | 1 | 00191 | Thu Apr 02 00:00:00 1970 PST
+ 193 | 303 | 00193_update3 | Sat Apr 04 00:00:00 1970 PST
+ 194 | 4 | 00194 | Sun Apr 05 00:00:00 1970 PST
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST
+ 198 | 8 | 00198 | Thu Apr 09 00:00:00 1970 PST
+ 199 | 509 | 00199_update9 | Fri Apr 10 00:00:00 1970 PST
+ 200 | 0 | 00200 | Thu Jan 01 00:00:00 1970 PST
+ 201 | 1 | 00201 | Fri Jan 02 00:00:00 1970 PST
+ 203 | 303 | 00203_update3 | Sun Jan 04 00:00:00 1970 PST
+ 204 | 4 | 00204 | Mon Jan 05 00:00:00 1970 PST
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST
+ 208 | 8 | 00208 | Fri Jan 09 00:00:00 1970 PST
+ 209 | 509 | 00209_update9 | Sat Jan 10 00:00:00 1970 PST
+ 210 | 0 | 00210 | Sun Jan 11 00:00:00 1970 PST
+ 211 | 1 | 00211 | Mon Jan 12 00:00:00 1970 PST
+ 213 | 303 | 00213_update3 | Wed Jan 14 00:00:00 1970 PST
+ 214 | 4 | 00214 | Thu Jan 15 00:00:00 1970 PST
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST
+ 218 | 8 | 00218 | Mon Jan 19 00:00:00 1970 PST
+ 219 | 509 | 00219_update9 | Tue Jan 20 00:00:00 1970 PST
+ 220 | 0 | 00220 | Wed Jan 21 00:00:00 1970 PST
+ 221 | 1 | 00221 | Thu Jan 22 00:00:00 1970 PST
+ 223 | 303 | 00223_update3 | Sat Jan 24 00:00:00 1970 PST
+ 224 | 4 | 00224 | Sun Jan 25 00:00:00 1970 PST
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST
+ 228 | 8 | 00228 | Thu Jan 29 00:00:00 1970 PST
+ 229 | 509 | 00229_update9 | Fri Jan 30 00:00:00 1970 PST
+ 230 | 0 | 00230 | Sat Jan 31 00:00:00 1970 PST
+ 231 | 1 | 00231 | Sun Feb 01 00:00:00 1970 PST
+ 233 | 303 | 00233_update3 | Tue Feb 03 00:00:00 1970 PST
+ 234 | 4 | 00234 | Wed Feb 04 00:00:00 1970 PST
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST
+ 238 | 8 | 00238 | Sun Feb 08 00:00:00 1970 PST
+ 239 | 509 | 00239_update9 | Mon Feb 09 00:00:00 1970 PST
+ 240 | 0 | 00240 | Tue Feb 10 00:00:00 1970 PST
+ 241 | 1 | 00241 | Wed Feb 11 00:00:00 1970 PST
+ 243 | 303 | 00243_update3 | Fri Feb 13 00:00:00 1970 PST
+ 244 | 4 | 00244 | Sat Feb 14 00:00:00 1970 PST
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST
+ 248 | 8 | 00248 | Wed Feb 18 00:00:00 1970 PST
+ 249 | 509 | 00249_update9 | Thu Feb 19 00:00:00 1970 PST
+ 250 | 0 | 00250 | Fri Feb 20 00:00:00 1970 PST
+ 251 | 1 | 00251 | Sat Feb 21 00:00:00 1970 PST
+ 253 | 303 | 00253_update3 | Mon Feb 23 00:00:00 1970 PST
+ 254 | 4 | 00254 | Tue Feb 24 00:00:00 1970 PST
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST
+ 258 | 8 | 00258 | Sat Feb 28 00:00:00 1970 PST
+ 259 | 509 | 00259_update9 | Sun Mar 01 00:00:00 1970 PST
+ 260 | 0 | 00260 | Mon Mar 02 00:00:00 1970 PST
+ 261 | 1 | 00261 | Tue Mar 03 00:00:00 1970 PST
+ 263 | 303 | 00263_update3 | Thu Mar 05 00:00:00 1970 PST
+ 264 | 4 | 00264 | Fri Mar 06 00:00:00 1970 PST
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST
+ 268 | 8 | 00268 | Tue Mar 10 00:00:00 1970 PST
+ 269 | 509 | 00269_update9 | Wed Mar 11 00:00:00 1970 PST
+ 270 | 0 | 00270 | Thu Mar 12 00:00:00 1970 PST
+ 271 | 1 | 00271 | Fri Mar 13 00:00:00 1970 PST
+ 273 | 303 | 00273_update3 | Sun Mar 15 00:00:00 1970 PST
+ 274 | 4 | 00274 | Mon Mar 16 00:00:00 1970 PST
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST
+ 278 | 8 | 00278 | Fri Mar 20 00:00:00 1970 PST
+ 279 | 509 | 00279_update9 | Sat Mar 21 00:00:00 1970 PST
+ 280 | 0 | 00280 | Sun Mar 22 00:00:00 1970 PST
+ 281 | 1 | 00281 | Mon Mar 23 00:00:00 1970 PST
+ 283 | 303 | 00283_update3 | Wed Mar 25 00:00:00 1970 PST
+ 284 | 4 | 00284 | Thu Mar 26 00:00:00 1970 PST
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST
+ 288 | 8 | 00288 | Mon Mar 30 00:00:00 1970 PST
+ 289 | 509 | 00289_update9 | Tue Mar 31 00:00:00 1970 PST
+ 290 | 0 | 00290 | Wed Apr 01 00:00:00 1970 PST
+ 291 | 1 | 00291 | Thu Apr 02 00:00:00 1970 PST
+ 293 | 303 | 00293_update3 | Sat Apr 04 00:00:00 1970 PST
+ 294 | 4 | 00294 | Sun Apr 05 00:00:00 1970 PST
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST
+ 298 | 8 | 00298 | Thu Apr 09 00:00:00 1970 PST
+ 299 | 509 | 00299_update9 | Fri Apr 10 00:00:00 1970 PST
+ 300 | 0 | 00300 | Thu Jan 01 00:00:00 1970 PST
+ 301 | 1 | 00301 | Fri Jan 02 00:00:00 1970 PST
+ 303 | 303 | 00303_update3 | Sun Jan 04 00:00:00 1970 PST
+ 304 | 4 | 00304 | Mon Jan 05 00:00:00 1970 PST
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST
+ 308 | 8 | 00308 | Fri Jan 09 00:00:00 1970 PST
+ 309 | 509 | 00309_update9 | Sat Jan 10 00:00:00 1970 PST
+ 310 | 0 | 00310 | Sun Jan 11 00:00:00 1970 PST
+ 311 | 1 | 00311 | Mon Jan 12 00:00:00 1970 PST
+ 313 | 303 | 00313_update3 | Wed Jan 14 00:00:00 1970 PST
+ 314 | 4 | 00314 | Thu Jan 15 00:00:00 1970 PST
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST
+ 318 | 8 | 00318 | Mon Jan 19 00:00:00 1970 PST
+ 319 | 509 | 00319_update9 | Tue Jan 20 00:00:00 1970 PST
+ 320 | 0 | 00320 | Wed Jan 21 00:00:00 1970 PST
+ 321 | 1 | 00321 | Thu Jan 22 00:00:00 1970 PST
+ 323 | 303 | 00323_update3 | Sat Jan 24 00:00:00 1970 PST
+ 324 | 4 | 00324 | Sun Jan 25 00:00:00 1970 PST
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST
+ 328 | 8 | 00328 | Thu Jan 29 00:00:00 1970 PST
+ 329 | 509 | 00329_update9 | Fri Jan 30 00:00:00 1970 PST
+ 330 | 0 | 00330 | Sat Jan 31 00:00:00 1970 PST
+ 331 | 1 | 00331 | Sun Feb 01 00:00:00 1970 PST
+ 333 | 303 | 00333_update3 | Tue Feb 03 00:00:00 1970 PST
+ 334 | 4 | 00334 | Wed Feb 04 00:00:00 1970 PST
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST
+ 338 | 8 | 00338 | Sun Feb 08 00:00:00 1970 PST
+ 339 | 509 | 00339_update9 | Mon Feb 09 00:00:00 1970 PST
+ 340 | 0 | 00340 | Tue Feb 10 00:00:00 1970 PST
+ 341 | 1 | 00341 | Wed Feb 11 00:00:00 1970 PST
+ 343 | 303 | 00343_update3 | Fri Feb 13 00:00:00 1970 PST
+ 344 | 4 | 00344 | Sat Feb 14 00:00:00 1970 PST
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST
+ 348 | 8 | 00348 | Wed Feb 18 00:00:00 1970 PST
+ 349 | 509 | 00349_update9 | Thu Feb 19 00:00:00 1970 PST
+ 350 | 0 | 00350 | Fri Feb 20 00:00:00 1970 PST
+ 351 | 1 | 00351 | Sat Feb 21 00:00:00 1970 PST
+ 353 | 303 | 00353_update3 | Mon Feb 23 00:00:00 1970 PST
+ 354 | 4 | 00354 | Tue Feb 24 00:00:00 1970 PST
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST
+ 358 | 8 | 00358 | Sat Feb 28 00:00:00 1970 PST
+ 359 | 509 | 00359_update9 | Sun Mar 01 00:00:00 1970 PST
+ 360 | 0 | 00360 | Mon Mar 02 00:00:00 1970 PST
+ 361 | 1 | 00361 | Tue Mar 03 00:00:00 1970 PST
+ 363 | 303 | 00363_update3 | Thu Mar 05 00:00:00 1970 PST
+ 364 | 4 | 00364 | Fri Mar 06 00:00:00 1970 PST
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST
+ 368 | 8 | 00368 | Tue Mar 10 00:00:00 1970 PST
+ 369 | 509 | 00369_update9 | Wed Mar 11 00:00:00 1970 PST
+ 370 | 0 | 00370 | Thu Mar 12 00:00:00 1970 PST
+ 371 | 1 | 00371 | Fri Mar 13 00:00:00 1970 PST
+ 373 | 303 | 00373_update3 | Sun Mar 15 00:00:00 1970 PST
+ 374 | 4 | 00374 | Mon Mar 16 00:00:00 1970 PST
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST
+ 378 | 8 | 00378 | Fri Mar 20 00:00:00 1970 PST
+ 379 | 509 | 00379_update9 | Sat Mar 21 00:00:00 1970 PST
+ 380 | 0 | 00380 | Sun Mar 22 00:00:00 1970 PST
+ 381 | 1 | 00381 | Mon Mar 23 00:00:00 1970 PST
+ 383 | 303 | 00383_update3 | Wed Mar 25 00:00:00 1970 PST
+ 384 | 4 | 00384 | Thu Mar 26 00:00:00 1970 PST
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST
+ 388 | 8 | 00388 | Mon Mar 30 00:00:00 1970 PST
+ 389 | 509 | 00389_update9 | Tue Mar 31 00:00:00 1970 PST
+ 390 | 0 | 00390 | Wed Apr 01 00:00:00 1970 PST
+ 391 | 1 | 00391 | Thu Apr 02 00:00:00 1970 PST
+ 393 | 303 | 00393_update3 | Sat Apr 04 00:00:00 1970 PST
+ 394 | 4 | 00394 | Sun Apr 05 00:00:00 1970 PST
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST
+ 398 | 8 | 00398 | Thu Apr 09 00:00:00 1970 PST
+ 399 | 509 | 00399_update9 | Fri Apr 10 00:00:00 1970 PST
+ 400 | 0 | 00400 | Thu Jan 01 00:00:00 1970 PST
+ 401 | 1 | 00401 | Fri Jan 02 00:00:00 1970 PST
+ 403 | 303 | 00403_update3 | Sun Jan 04 00:00:00 1970 PST
+ 404 | 4 | 00404 | Mon Jan 05 00:00:00 1970 PST
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST
+ 408 | 8 | 00408 | Fri Jan 09 00:00:00 1970 PST
+ 409 | 509 | 00409_update9 | Sat Jan 10 00:00:00 1970 PST
+ 410 | 0 | 00410 | Sun Jan 11 00:00:00 1970 PST
+ 411 | 1 | 00411 | Mon Jan 12 00:00:00 1970 PST
+ 413 | 303 | 00413_update3 | Wed Jan 14 00:00:00 1970 PST
+ 414 | 4 | 00414 | Thu Jan 15 00:00:00 1970 PST
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST
+ 418 | 8 | 00418 | Mon Jan 19 00:00:00 1970 PST
+ 419 | 509 | 00419_update9 | Tue Jan 20 00:00:00 1970 PST
+ 420 | 0 | 00420 | Wed Jan 21 00:00:00 1970 PST
+ 421 | 1 | 00421 | Thu Jan 22 00:00:00 1970 PST
+ 423 | 303 | 00423_update3 | Sat Jan 24 00:00:00 1970 PST
+ 424 | 4 | 00424 | Sun Jan 25 00:00:00 1970 PST
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST
+ 428 | 8 | 00428 | Thu Jan 29 00:00:00 1970 PST
+ 429 | 509 | 00429_update9 | Fri Jan 30 00:00:00 1970 PST
+ 430 | 0 | 00430 | Sat Jan 31 00:00:00 1970 PST
+ 431 | 1 | 00431 | Sun Feb 01 00:00:00 1970 PST
+ 433 | 303 | 00433_update3 | Tue Feb 03 00:00:00 1970 PST
+ 434 | 4 | 00434 | Wed Feb 04 00:00:00 1970 PST
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST
+ 438 | 8 | 00438 | Sun Feb 08 00:00:00 1970 PST
+ 439 | 509 | 00439_update9 | Mon Feb 09 00:00:00 1970 PST
+ 440 | 0 | 00440 | Tue Feb 10 00:00:00 1970 PST
+ 441 | 1 | 00441 | Wed Feb 11 00:00:00 1970 PST
+ 443 | 303 | 00443_update3 | Fri Feb 13 00:00:00 1970 PST
+ 444 | 4 | 00444 | Sat Feb 14 00:00:00 1970 PST
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST
+ 448 | 8 | 00448 | Wed Feb 18 00:00:00 1970 PST
+ 449 | 509 | 00449_update9 | Thu Feb 19 00:00:00 1970 PST
+ 450 | 0 | 00450 | Fri Feb 20 00:00:00 1970 PST
+ 451 | 1 | 00451 | Sat Feb 21 00:00:00 1970 PST
+ 453 | 303 | 00453_update3 | Mon Feb 23 00:00:00 1970 PST
+ 454 | 4 | 00454 | Tue Feb 24 00:00:00 1970 PST
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST
+ 458 | 8 | 00458 | Sat Feb 28 00:00:00 1970 PST
+ 459 | 509 | 00459_update9 | Sun Mar 01 00:00:00 1970 PST
+ 460 | 0 | 00460 | Mon Mar 02 00:00:00 1970 PST
+ 461 | 1 | 00461 | Tue Mar 03 00:00:00 1970 PST
+ 463 | 303 | 00463_update3 | Thu Mar 05 00:00:00 1970 PST
+ 464 | 4 | 00464 | Fri Mar 06 00:00:00 1970 PST
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST
+ 468 | 8 | 00468 | Tue Mar 10 00:00:00 1970 PST
+ 469 | 509 | 00469_update9 | Wed Mar 11 00:00:00 1970 PST
+ 470 | 0 | 00470 | Thu Mar 12 00:00:00 1970 PST
+ 471 | 1 | 00471 | Fri Mar 13 00:00:00 1970 PST
+ 473 | 303 | 00473_update3 | Sun Mar 15 00:00:00 1970 PST
+ 474 | 4 | 00474 | Mon Mar 16 00:00:00 1970 PST
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST
+ 478 | 8 | 00478 | Fri Mar 20 00:00:00 1970 PST
+ 479 | 509 | 00479_update9 | Sat Mar 21 00:00:00 1970 PST
+ 480 | 0 | 00480 | Sun Mar 22 00:00:00 1970 PST
+ 481 | 1 | 00481 | Mon Mar 23 00:00:00 1970 PST
+ 483 | 303 | 00483_update3 | Wed Mar 25 00:00:00 1970 PST
+ 484 | 4 | 00484 | Thu Mar 26 00:00:00 1970 PST
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST
+ 488 | 8 | 00488 | Mon Mar 30 00:00:00 1970 PST
+ 489 | 509 | 00489_update9 | Tue Mar 31 00:00:00 1970 PST
+ 490 | 0 | 00490 | Wed Apr 01 00:00:00 1970 PST
+ 491 | 1 | 00491 | Thu Apr 02 00:00:00 1970 PST
+ 493 | 303 | 00493_update3 | Sat Apr 04 00:00:00 1970 PST
+ 494 | 4 | 00494 | Sun Apr 05 00:00:00 1970 PST
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST
+ 498 | 8 | 00498 | Thu Apr 09 00:00:00 1970 PST
+ 499 | 509 | 00499_update9 | Fri Apr 10 00:00:00 1970 PST
+ 500 | 0 | 00500 | Thu Jan 01 00:00:00 1970 PST
+ 501 | 1 | 00501 | Fri Jan 02 00:00:00 1970 PST
+ 503 | 303 | 00503_update3 | Sun Jan 04 00:00:00 1970 PST
+ 504 | 4 | 00504 | Mon Jan 05 00:00:00 1970 PST
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST
+ 508 | 8 | 00508 | Fri Jan 09 00:00:00 1970 PST
+ 509 | 509 | 00509_update9 | Sat Jan 10 00:00:00 1970 PST
+ 510 | 0 | 00510 | Sun Jan 11 00:00:00 1970 PST
+ 511 | 1 | 00511 | Mon Jan 12 00:00:00 1970 PST
+ 513 | 303 | 00513_update3 | Wed Jan 14 00:00:00 1970 PST
+ 514 | 4 | 00514 | Thu Jan 15 00:00:00 1970 PST
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST
+ 518 | 8 | 00518 | Mon Jan 19 00:00:00 1970 PST
+ 519 | 509 | 00519_update9 | Tue Jan 20 00:00:00 1970 PST
+ 520 | 0 | 00520 | Wed Jan 21 00:00:00 1970 PST
+ 521 | 1 | 00521 | Thu Jan 22 00:00:00 1970 PST
+ 523 | 303 | 00523_update3 | Sat Jan 24 00:00:00 1970 PST
+ 524 | 4 | 00524 | Sun Jan 25 00:00:00 1970 PST
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST
+ 528 | 8 | 00528 | Thu Jan 29 00:00:00 1970 PST
+ 529 | 509 | 00529_update9 | Fri Jan 30 00:00:00 1970 PST
+ 530 | 0 | 00530 | Sat Jan 31 00:00:00 1970 PST
+ 531 | 1 | 00531 | Sun Feb 01 00:00:00 1970 PST
+ 533 | 303 | 00533_update3 | Tue Feb 03 00:00:00 1970 PST
+ 534 | 4 | 00534 | Wed Feb 04 00:00:00 1970 PST
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST
+ 538 | 8 | 00538 | Sun Feb 08 00:00:00 1970 PST
+ 539 | 509 | 00539_update9 | Mon Feb 09 00:00:00 1970 PST
+ 540 | 0 | 00540 | Tue Feb 10 00:00:00 1970 PST
+ 541 | 1 | 00541 | Wed Feb 11 00:00:00 1970 PST
+ 543 | 303 | 00543_update3 | Fri Feb 13 00:00:00 1970 PST
+ 544 | 4 | 00544 | Sat Feb 14 00:00:00 1970 PST
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST
+ 548 | 8 | 00548 | Wed Feb 18 00:00:00 1970 PST
+ 549 | 509 | 00549_update9 | Thu Feb 19 00:00:00 1970 PST
+ 550 | 0 | 00550 | Fri Feb 20 00:00:00 1970 PST
+ 551 | 1 | 00551 | Sat Feb 21 00:00:00 1970 PST
+ 553 | 303 | 00553_update3 | Mon Feb 23 00:00:00 1970 PST
+ 554 | 4 | 00554 | Tue Feb 24 00:00:00 1970 PST
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST
+ 558 | 8 | 00558 | Sat Feb 28 00:00:00 1970 PST
+ 559 | 509 | 00559_update9 | Sun Mar 01 00:00:00 1970 PST
+ 560 | 0 | 00560 | Mon Mar 02 00:00:00 1970 PST
+ 561 | 1 | 00561 | Tue Mar 03 00:00:00 1970 PST
+ 563 | 303 | 00563_update3 | Thu Mar 05 00:00:00 1970 PST
+ 564 | 4 | 00564 | Fri Mar 06 00:00:00 1970 PST
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST
+ 568 | 8 | 00568 | Tue Mar 10 00:00:00 1970 PST
+ 569 | 509 | 00569_update9 | Wed Mar 11 00:00:00 1970 PST
+ 570 | 0 | 00570 | Thu Mar 12 00:00:00 1970 PST
+ 571 | 1 | 00571 | Fri Mar 13 00:00:00 1970 PST
+ 573 | 303 | 00573_update3 | Sun Mar 15 00:00:00 1970 PST
+ 574 | 4 | 00574 | Mon Mar 16 00:00:00 1970 PST
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST
+ 578 | 8 | 00578 | Fri Mar 20 00:00:00 1970 PST
+ 579 | 509 | 00579_update9 | Sat Mar 21 00:00:00 1970 PST
+ 580 | 0 | 00580 | Sun Mar 22 00:00:00 1970 PST
+ 581 | 1 | 00581 | Mon Mar 23 00:00:00 1970 PST
+ 583 | 303 | 00583_update3 | Wed Mar 25 00:00:00 1970 PST
+ 584 | 4 | 00584 | Thu Mar 26 00:00:00 1970 PST
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST
+ 588 | 8 | 00588 | Mon Mar 30 00:00:00 1970 PST
+ 589 | 509 | 00589_update9 | Tue Mar 31 00:00:00 1970 PST
+ 590 | 0 | 00590 | Wed Apr 01 00:00:00 1970 PST
+ 591 | 1 | 00591 | Thu Apr 02 00:00:00 1970 PST
+ 593 | 303 | 00593_update3 | Sat Apr 04 00:00:00 1970 PST
+ 594 | 4 | 00594 | Sun Apr 05 00:00:00 1970 PST
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST
+ 598 | 8 | 00598 | Thu Apr 09 00:00:00 1970 PST
+ 599 | 509 | 00599_update9 | Fri Apr 10 00:00:00 1970 PST
+ 600 | 0 | 00600 | Thu Jan 01 00:00:00 1970 PST
+ 601 | 1 | 00601 | Fri Jan 02 00:00:00 1970 PST
+ 603 | 303 | 00603_update3 | Sun Jan 04 00:00:00 1970 PST
+ 604 | 4 | 00604 | Mon Jan 05 00:00:00 1970 PST
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST
+ 608 | 8 | 00608 | Fri Jan 09 00:00:00 1970 PST
+ 609 | 509 | 00609_update9 | Sat Jan 10 00:00:00 1970 PST
+ 610 | 0 | 00610 | Sun Jan 11 00:00:00 1970 PST
+ 611 | 1 | 00611 | Mon Jan 12 00:00:00 1970 PST
+ 613 | 303 | 00613_update3 | Wed Jan 14 00:00:00 1970 PST
+ 614 | 4 | 00614 | Thu Jan 15 00:00:00 1970 PST
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST
+ 618 | 8 | 00618 | Mon Jan 19 00:00:00 1970 PST
+ 619 | 509 | 00619_update9 | Tue Jan 20 00:00:00 1970 PST
+ 620 | 0 | 00620 | Wed Jan 21 00:00:00 1970 PST
+ 621 | 1 | 00621 | Thu Jan 22 00:00:00 1970 PST
+ 623 | 303 | 00623_update3 | Sat Jan 24 00:00:00 1970 PST
+ 624 | 4 | 00624 | Sun Jan 25 00:00:00 1970 PST
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST
+ 628 | 8 | 00628 | Thu Jan 29 00:00:00 1970 PST
+ 629 | 509 | 00629_update9 | Fri Jan 30 00:00:00 1970 PST
+ 630 | 0 | 00630 | Sat Jan 31 00:00:00 1970 PST
+ 631 | 1 | 00631 | Sun Feb 01 00:00:00 1970 PST
+ 633 | 303 | 00633_update3 | Tue Feb 03 00:00:00 1970 PST
+ 634 | 4 | 00634 | Wed Feb 04 00:00:00 1970 PST
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST
+ 638 | 8 | 00638 | Sun Feb 08 00:00:00 1970 PST
+ 639 | 509 | 00639_update9 | Mon Feb 09 00:00:00 1970 PST
+ 640 | 0 | 00640 | Tue Feb 10 00:00:00 1970 PST
+ 641 | 1 | 00641 | Wed Feb 11 00:00:00 1970 PST
+ 643 | 303 | 00643_update3 | Fri Feb 13 00:00:00 1970 PST
+ 644 | 4 | 00644 | Sat Feb 14 00:00:00 1970 PST
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST
+ 648 | 8 | 00648 | Wed Feb 18 00:00:00 1970 PST
+ 649 | 509 | 00649_update9 | Thu Feb 19 00:00:00 1970 PST
+ 650 | 0 | 00650 | Fri Feb 20 00:00:00 1970 PST
+ 651 | 1 | 00651 | Sat Feb 21 00:00:00 1970 PST
+ 653 | 303 | 00653_update3 | Mon Feb 23 00:00:00 1970 PST
+ 654 | 4 | 00654 | Tue Feb 24 00:00:00 1970 PST
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST
+ 658 | 8 | 00658 | Sat Feb 28 00:00:00 1970 PST
+ 659 | 509 | 00659_update9 | Sun Mar 01 00:00:00 1970 PST
+ 660 | 0 | 00660 | Mon Mar 02 00:00:00 1970 PST
+ 661 | 1 | 00661 | Tue Mar 03 00:00:00 1970 PST
+ 663 | 303 | 00663_update3 | Thu Mar 05 00:00:00 1970 PST
+ 664 | 4 | 00664 | Fri Mar 06 00:00:00 1970 PST
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST
+ 668 | 8 | 00668 | Tue Mar 10 00:00:00 1970 PST
+ 669 | 509 | 00669_update9 | Wed Mar 11 00:00:00 1970 PST
+ 670 | 0 | 00670 | Thu Mar 12 00:00:00 1970 PST
+ 671 | 1 | 00671 | Fri Mar 13 00:00:00 1970 PST
+ 673 | 303 | 00673_update3 | Sun Mar 15 00:00:00 1970 PST
+ 674 | 4 | 00674 | Mon Mar 16 00:00:00 1970 PST
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST
+ 678 | 8 | 00678 | Fri Mar 20 00:00:00 1970 PST
+ 679 | 509 | 00679_update9 | Sat Mar 21 00:00:00 1970 PST
+ 680 | 0 | 00680 | Sun Mar 22 00:00:00 1970 PST
+ 681 | 1 | 00681 | Mon Mar 23 00:00:00 1970 PST
+ 683 | 303 | 00683_update3 | Wed Mar 25 00:00:00 1970 PST
+ 684 | 4 | 00684 | Thu Mar 26 00:00:00 1970 PST
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST
+ 688 | 8 | 00688 | Mon Mar 30 00:00:00 1970 PST
+ 689 | 509 | 00689_update9 | Tue Mar 31 00:00:00 1970 PST
+ 690 | 0 | 00690 | Wed Apr 01 00:00:00 1970 PST
+ 691 | 1 | 00691 | Thu Apr 02 00:00:00 1970 PST
+ 693 | 303 | 00693_update3 | Sat Apr 04 00:00:00 1970 PST
+ 694 | 4 | 00694 | Sun Apr 05 00:00:00 1970 PST
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST
+ 698 | 8 | 00698 | Thu Apr 09 00:00:00 1970 PST
+ 699 | 509 | 00699_update9 | Fri Apr 10 00:00:00 1970 PST
+ 700 | 0 | 00700 | Thu Jan 01 00:00:00 1970 PST
+ 701 | 1 | 00701 | Fri Jan 02 00:00:00 1970 PST
+ 703 | 303 | 00703_update3 | Sun Jan 04 00:00:00 1970 PST
+ 704 | 4 | 00704 | Mon Jan 05 00:00:00 1970 PST
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST
+ 708 | 8 | 00708 | Fri Jan 09 00:00:00 1970 PST
+ 709 | 509 | 00709_update9 | Sat Jan 10 00:00:00 1970 PST
+ 710 | 0 | 00710 | Sun Jan 11 00:00:00 1970 PST
+ 711 | 1 | 00711 | Mon Jan 12 00:00:00 1970 PST
+ 713 | 303 | 00713_update3 | Wed Jan 14 00:00:00 1970 PST
+ 714 | 4 | 00714 | Thu Jan 15 00:00:00 1970 PST
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST
+ 718 | 8 | 00718 | Mon Jan 19 00:00:00 1970 PST
+ 719 | 509 | 00719_update9 | Tue Jan 20 00:00:00 1970 PST
+ 720 | 0 | 00720 | Wed Jan 21 00:00:00 1970 PST
+ 721 | 1 | 00721 | Thu Jan 22 00:00:00 1970 PST
+ 723 | 303 | 00723_update3 | Sat Jan 24 00:00:00 1970 PST
+ 724 | 4 | 00724 | Sun Jan 25 00:00:00 1970 PST
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST
+ 728 | 8 | 00728 | Thu Jan 29 00:00:00 1970 PST
+ 729 | 509 | 00729_update9 | Fri Jan 30 00:00:00 1970 PST
+ 730 | 0 | 00730 | Sat Jan 31 00:00:00 1970 PST
+ 731 | 1 | 00731 | Sun Feb 01 00:00:00 1970 PST
+ 733 | 303 | 00733_update3 | Tue Feb 03 00:00:00 1970 PST
+ 734 | 4 | 00734 | Wed Feb 04 00:00:00 1970 PST
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST
+ 738 | 8 | 00738 | Sun Feb 08 00:00:00 1970 PST
+ 739 | 509 | 00739_update9 | Mon Feb 09 00:00:00 1970 PST
+ 740 | 0 | 00740 | Tue Feb 10 00:00:00 1970 PST
+ 741 | 1 | 00741 | Wed Feb 11 00:00:00 1970 PST
+ 743 | 303 | 00743_update3 | Fri Feb 13 00:00:00 1970 PST
+ 744 | 4 | 00744 | Sat Feb 14 00:00:00 1970 PST
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST
+ 748 | 8 | 00748 | Wed Feb 18 00:00:00 1970 PST
+ 749 | 509 | 00749_update9 | Thu Feb 19 00:00:00 1970 PST
+ 750 | 0 | 00750 | Fri Feb 20 00:00:00 1970 PST
+ 751 | 1 | 00751 | Sat Feb 21 00:00:00 1970 PST
+ 753 | 303 | 00753_update3 | Mon Feb 23 00:00:00 1970 PST
+ 754 | 4 | 00754 | Tue Feb 24 00:00:00 1970 PST
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST
+ 758 | 8 | 00758 | Sat Feb 28 00:00:00 1970 PST
+ 759 | 509 | 00759_update9 | Sun Mar 01 00:00:00 1970 PST
+ 760 | 0 | 00760 | Mon Mar 02 00:00:00 1970 PST
+ 761 | 1 | 00761 | Tue Mar 03 00:00:00 1970 PST
+ 763 | 303 | 00763_update3 | Thu Mar 05 00:00:00 1970 PST
+ 764 | 4 | 00764 | Fri Mar 06 00:00:00 1970 PST
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST
+ 768 | 8 | 00768 | Tue Mar 10 00:00:00 1970 PST
+ 769 | 509 | 00769_update9 | Wed Mar 11 00:00:00 1970 PST
+ 770 | 0 | 00770 | Thu Mar 12 00:00:00 1970 PST
+ 771 | 1 | 00771 | Fri Mar 13 00:00:00 1970 PST
+ 773 | 303 | 00773_update3 | Sun Mar 15 00:00:00 1970 PST
+ 774 | 4 | 00774 | Mon Mar 16 00:00:00 1970 PST
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST
+ 778 | 8 | 00778 | Fri Mar 20 00:00:00 1970 PST
+ 779 | 509 | 00779_update9 | Sat Mar 21 00:00:00 1970 PST
+ 780 | 0 | 00780 | Sun Mar 22 00:00:00 1970 PST
+ 781 | 1 | 00781 | Mon Mar 23 00:00:00 1970 PST
+ 783 | 303 | 00783_update3 | Wed Mar 25 00:00:00 1970 PST
+ 784 | 4 | 00784 | Thu Mar 26 00:00:00 1970 PST
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST
+ 788 | 8 | 00788 | Mon Mar 30 00:00:00 1970 PST
+ 789 | 509 | 00789_update9 | Tue Mar 31 00:00:00 1970 PST
+ 790 | 0 | 00790 | Wed Apr 01 00:00:00 1970 PST
+ 791 | 1 | 00791 | Thu Apr 02 00:00:00 1970 PST
+ 793 | 303 | 00793_update3 | Sat Apr 04 00:00:00 1970 PST
+ 794 | 4 | 00794 | Sun Apr 05 00:00:00 1970 PST
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST
+ 798 | 8 | 00798 | Thu Apr 09 00:00:00 1970 PST
+ 799 | 509 | 00799_update9 | Fri Apr 10 00:00:00 1970 PST
+ 800 | 0 | 00800 | Thu Jan 01 00:00:00 1970 PST
+ 801 | 1 | 00801 | Fri Jan 02 00:00:00 1970 PST
+ 803 | 303 | 00803_update3 | Sun Jan 04 00:00:00 1970 PST
+ 804 | 4 | 00804 | Mon Jan 05 00:00:00 1970 PST
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST
+ 808 | 8 | 00808 | Fri Jan 09 00:00:00 1970 PST
+ 809 | 509 | 00809_update9 | Sat Jan 10 00:00:00 1970 PST
+ 810 | 0 | 00810 | Sun Jan 11 00:00:00 1970 PST
+ 811 | 1 | 00811 | Mon Jan 12 00:00:00 1970 PST
+ 813 | 303 | 00813_update3 | Wed Jan 14 00:00:00 1970 PST
+ 814 | 4 | 00814 | Thu Jan 15 00:00:00 1970 PST
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST
+ 818 | 8 | 00818 | Mon Jan 19 00:00:00 1970 PST
+ 819 | 509 | 00819_update9 | Tue Jan 20 00:00:00 1970 PST
+ 820 | 0 | 00820 | Wed Jan 21 00:00:00 1970 PST
+ 821 | 1 | 00821 | Thu Jan 22 00:00:00 1970 PST
+ 823 | 303 | 00823_update3 | Sat Jan 24 00:00:00 1970 PST
+ 824 | 4 | 00824 | Sun Jan 25 00:00:00 1970 PST
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST
+ 828 | 8 | 00828 | Thu Jan 29 00:00:00 1970 PST
+ 829 | 509 | 00829_update9 | Fri Jan 30 00:00:00 1970 PST
+ 830 | 0 | 00830 | Sat Jan 31 00:00:00 1970 PST
+ 831 | 1 | 00831 | Sun Feb 01 00:00:00 1970 PST
+ 833 | 303 | 00833_update3 | Tue Feb 03 00:00:00 1970 PST
+ 834 | 4 | 00834 | Wed Feb 04 00:00:00 1970 PST
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST
+ 838 | 8 | 00838 | Sun Feb 08 00:00:00 1970 PST
+ 839 | 509 | 00839_update9 | Mon Feb 09 00:00:00 1970 PST
+ 840 | 0 | 00840 | Tue Feb 10 00:00:00 1970 PST
+ 841 | 1 | 00841 | Wed Feb 11 00:00:00 1970 PST
+ 843 | 303 | 00843_update3 | Fri Feb 13 00:00:00 1970 PST
+ 844 | 4 | 00844 | Sat Feb 14 00:00:00 1970 PST
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST
+ 848 | 8 | 00848 | Wed Feb 18 00:00:00 1970 PST
+ 849 | 509 | 00849_update9 | Thu Feb 19 00:00:00 1970 PST
+ 850 | 0 | 00850 | Fri Feb 20 00:00:00 1970 PST
+ 851 | 1 | 00851 | Sat Feb 21 00:00:00 1970 PST
+ 853 | 303 | 00853_update3 | Mon Feb 23 00:00:00 1970 PST
+ 854 | 4 | 00854 | Tue Feb 24 00:00:00 1970 PST
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST
+ 858 | 8 | 00858 | Sat Feb 28 00:00:00 1970 PST
+ 859 | 509 | 00859_update9 | Sun Mar 01 00:00:00 1970 PST
+ 860 | 0 | 00860 | Mon Mar 02 00:00:00 1970 PST
+ 861 | 1 | 00861 | Tue Mar 03 00:00:00 1970 PST
+ 863 | 303 | 00863_update3 | Thu Mar 05 00:00:00 1970 PST
+ 864 | 4 | 00864 | Fri Mar 06 00:00:00 1970 PST
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST
+ 868 | 8 | 00868 | Tue Mar 10 00:00:00 1970 PST
+ 869 | 509 | 00869_update9 | Wed Mar 11 00:00:00 1970 PST
+ 870 | 0 | 00870 | Thu Mar 12 00:00:00 1970 PST
+ 871 | 1 | 00871 | Fri Mar 13 00:00:00 1970 PST
+ 873 | 303 | 00873_update3 | Sun Mar 15 00:00:00 1970 PST
+ 874 | 4 | 00874 | Mon Mar 16 00:00:00 1970 PST
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST
+ 878 | 8 | 00878 | Fri Mar 20 00:00:00 1970 PST
+ 879 | 509 | 00879_update9 | Sat Mar 21 00:00:00 1970 PST
+ 880 | 0 | 00880 | Sun Mar 22 00:00:00 1970 PST
+ 881 | 1 | 00881 | Mon Mar 23 00:00:00 1970 PST
+ 883 | 303 | 00883_update3 | Wed Mar 25 00:00:00 1970 PST
+ 884 | 4 | 00884 | Thu Mar 26 00:00:00 1970 PST
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST
+ 888 | 8 | 00888 | Mon Mar 30 00:00:00 1970 PST
+ 889 | 509 | 00889_update9 | Tue Mar 31 00:00:00 1970 PST
+ 890 | 0 | 00890 | Wed Apr 01 00:00:00 1970 PST
+ 891 | 1 | 00891 | Thu Apr 02 00:00:00 1970 PST
+ 893 | 303 | 00893_update3 | Sat Apr 04 00:00:00 1970 PST
+ 894 | 4 | 00894 | Sun Apr 05 00:00:00 1970 PST
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST
+ 898 | 8 | 00898 | Thu Apr 09 00:00:00 1970 PST
+ 899 | 509 | 00899_update9 | Fri Apr 10 00:00:00 1970 PST
+ 900 | 0 | 00900 | Thu Jan 01 00:00:00 1970 PST
+ 901 | 1 | 00901 | Fri Jan 02 00:00:00 1970 PST
+ 903 | 303 | 00903_update3 | Sun Jan 04 00:00:00 1970 PST
+ 904 | 4 | 00904 | Mon Jan 05 00:00:00 1970 PST
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST
+ 908 | 8 | 00908 | Fri Jan 09 00:00:00 1970 PST
+ 909 | 509 | 00909_update9 | Sat Jan 10 00:00:00 1970 PST
+ 910 | 0 | 00910 | Sun Jan 11 00:00:00 1970 PST
+ 911 | 1 | 00911 | Mon Jan 12 00:00:00 1970 PST
+ 913 | 303 | 00913_update3 | Wed Jan 14 00:00:00 1970 PST
+ 914 | 4 | 00914 | Thu Jan 15 00:00:00 1970 PST
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST
+ 918 | 8 | 00918 | Mon Jan 19 00:00:00 1970 PST
+ 919 | 509 | 00919_update9 | Tue Jan 20 00:00:00 1970 PST
+ 920 | 0 | 00920 | Wed Jan 21 00:00:00 1970 PST
+ 921 | 1 | 00921 | Thu Jan 22 00:00:00 1970 PST
+ 923 | 303 | 00923_update3 | Sat Jan 24 00:00:00 1970 PST
+ 924 | 4 | 00924 | Sun Jan 25 00:00:00 1970 PST
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST
+ 928 | 8 | 00928 | Thu Jan 29 00:00:00 1970 PST
+ 929 | 509 | 00929_update9 | Fri Jan 30 00:00:00 1970 PST
+ 930 | 0 | 00930 | Sat Jan 31 00:00:00 1970 PST
+ 931 | 1 | 00931 | Sun Feb 01 00:00:00 1970 PST
+ 933 | 303 | 00933_update3 | Tue Feb 03 00:00:00 1970 PST
+ 934 | 4 | 00934 | Wed Feb 04 00:00:00 1970 PST
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST
+ 938 | 8 | 00938 | Sun Feb 08 00:00:00 1970 PST
+ 939 | 509 | 00939_update9 | Mon Feb 09 00:00:00 1970 PST
+ 940 | 0 | 00940 | Tue Feb 10 00:00:00 1970 PST
+ 941 | 1 | 00941 | Wed Feb 11 00:00:00 1970 PST
+ 943 | 303 | 00943_update3 | Fri Feb 13 00:00:00 1970 PST
+ 944 | 4 | 00944 | Sat Feb 14 00:00:00 1970 PST
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST
+ 948 | 8 | 00948 | Wed Feb 18 00:00:00 1970 PST
+ 949 | 509 | 00949_update9 | Thu Feb 19 00:00:00 1970 PST
+ 950 | 0 | 00950 | Fri Feb 20 00:00:00 1970 PST
+ 951 | 1 | 00951 | Sat Feb 21 00:00:00 1970 PST
+ 953 | 303 | 00953_update3 | Mon Feb 23 00:00:00 1970 PST
+ 954 | 4 | 00954 | Tue Feb 24 00:00:00 1970 PST
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST
+ 958 | 8 | 00958 | Sat Feb 28 00:00:00 1970 PST
+ 959 | 509 | 00959_update9 | Sun Mar 01 00:00:00 1970 PST
+ 960 | 0 | 00960 | Mon Mar 02 00:00:00 1970 PST
+ 961 | 1 | 00961 | Tue Mar 03 00:00:00 1970 PST
+ 963 | 303 | 00963_update3 | Thu Mar 05 00:00:00 1970 PST
+ 964 | 4 | 00964 | Fri Mar 06 00:00:00 1970 PST
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST
+ 968 | 8 | 00968 | Tue Mar 10 00:00:00 1970 PST
+ 969 | 509 | 00969_update9 | Wed Mar 11 00:00:00 1970 PST
+ 970 | 0 | 00970 | Thu Mar 12 00:00:00 1970 PST
+ 971 | 1 | 00971 | Fri Mar 13 00:00:00 1970 PST
+ 973 | 303 | 00973_update3 | Sun Mar 15 00:00:00 1970 PST
+ 974 | 4 | 00974 | Mon Mar 16 00:00:00 1970 PST
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST
+ 978 | 8 | 00978 | Fri Mar 20 00:00:00 1970 PST
+ 979 | 509 | 00979_update9 | Sat Mar 21 00:00:00 1970 PST
+ 980 | 0 | 00980 | Sun Mar 22 00:00:00 1970 PST
+ 981 | 1 | 00981 | Mon Mar 23 00:00:00 1970 PST
+ 983 | 303 | 00983_update3 | Wed Mar 25 00:00:00 1970 PST
+ 984 | 4 | 00984 | Thu Mar 26 00:00:00 1970 PST
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST
+ 988 | 8 | 00988 | Mon Mar 30 00:00:00 1970 PST
+ 989 | 509 | 00989_update9 | Tue Mar 31 00:00:00 1970 PST
+ 990 | 0 | 00990 | Wed Apr 01 00:00:00 1970 PST
+ 991 | 1 | 00991 | Thu Apr 02 00:00:00 1970 PST
+ 993 | 303 | 00993_update3 | Sat Apr 04 00:00:00 1970 PST
+ 994 | 4 | 00994 | Sun Apr 05 00:00:00 1970 PST
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST
+ 998 | 8 | 00998 | Thu Apr 09 00:00:00 1970 PST
+ 999 | 509 | 00999_update9 | Fri Apr 10 00:00:00 1970 PST
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST
+ 1001 | 101 | 0000100001 |
+ 1003 | 403 | 0000300003_update3 |
+ 1004 | 104 | 0000400004 |
+ 1006 | 106 | 0000600006 |
+ 1007 | 507 | 0000700007_update7 |
+ 1008 | 108 | 0000800008 |
+ 1009 | 609 | 0000900009_update9 |
+ 1010 | 100 | 0001000010 |
+ 1011 | 101 | 0001100011 |
+ 1013 | 403 | 0001300013_update3 |
+ 1014 | 104 | 0001400014 |
+ 1016 | 106 | 0001600016 |
+ 1017 | 507 | 0001700017_update7 |
+ 1018 | 108 | 0001800018 |
+ 1019 | 609 | 0001900019_update9 |
+ 1020 | 100 | 0002000020 |
+ 1101 | 201 | aaa |
+ 1103 | 503 | ccc_update3 |
+ 1104 | 204 | ddd |
+(819 rows)
+
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Output: (ft2.tableoid)::regclass
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: 1200, 999, NULL::integer, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+(6 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = 'bar'::text WHERE (("C 1" = 1200))
+(4 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------
+ Delete on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE (("C 1" = 1200))
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+-- Test UPDATE/DELETE with RETURNING on a three-table join
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id - 1200, to_char(id, 'FM00000') FROM generate_series(1201, 1300) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.*, ft4.c1, ft4.c2, ft4.c3
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c3 = 'foo'::text FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (TRUE)) WHERE ((r2.c1 = r3.c1)) AND ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) RETURNING r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3
+(4 rows)
+
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*;
+ ft2 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | ft4 | c1 | c2 | c3
+--------------------------------+------+----+-----+----+----+----+------------+----+----------------+----+----+--------
+ (1206,6,foo,,,,"ft2 ",) | 1206 | 6 | foo | | | | ft2 | | (6,7,AAA006) | 6 | 7 | AAA006
+ (1212,12,foo,,,,"ft2 ",) | 1212 | 12 | foo | | | | ft2 | | (12,13,AAA012) | 12 | 13 | AAA012
+ (1218,18,foo,,,,"ft2 ",) | 1218 | 18 | foo | | | | ft2 | | (18,19,AAA018) | 18 | 19 | AAA018
+ (1224,24,foo,,,,"ft2 ",) | 1224 | 24 | foo | | | | ft2 | | (24,25,AAA024) | 24 | 25 | AAA024
+ (1230,30,foo,,,,"ft2 ",) | 1230 | 30 | foo | | | | ft2 | | (30,31,AAA030) | 30 | 31 | AAA030
+ (1236,36,foo,,,,"ft2 ",) | 1236 | 36 | foo | | | | ft2 | | (36,37,AAA036) | 36 | 37 | AAA036
+ (1242,42,foo,,,,"ft2 ",) | 1242 | 42 | foo | | | | ft2 | | (42,43,AAA042) | 42 | 43 | AAA042
+ (1248,48,foo,,,,"ft2 ",) | 1248 | 48 | foo | | | | ft2 | | (48,49,AAA048) | 48 | 49 | AAA048
+ (1254,54,foo,,,,"ft2 ",) | 1254 | 54 | foo | | | | ft2 | | (54,55,AAA054) | 54 | 55 | AAA054
+ (1260,60,foo,,,,"ft2 ",) | 1260 | 60 | foo | | | | ft2 | | (60,61,AAA060) | 60 | 61 | AAA060
+ (1266,66,foo,,,,"ft2 ",) | 1266 | 66 | foo | | | | ft2 | | (66,67,AAA066) | 66 | 67 | AAA066
+ (1272,72,foo,,,,"ft2 ",) | 1272 | 72 | foo | | | | ft2 | | (72,73,AAA072) | 72 | 73 | AAA072
+ (1278,78,foo,,,,"ft2 ",) | 1278 | 78 | foo | | | | ft2 | | (78,79,AAA078) | 78 | 79 | AAA078
+ (1284,84,foo,,,,"ft2 ",) | 1284 | 84 | foo | | | | ft2 | | (84,85,AAA084) | 84 | 85 | AAA084
+ (1290,90,foo,,,,"ft2 ",) | 1290 | 90 | foo | | | | ft2 | | (90,91,AAA090) | 90 | 91 | AAA090
+ (1296,96,foo,,,,"ft2 ",) | 1296 | 96 | foo | | | | ft2 | | (96,97,AAA096) | 96 | 97 | AAA096
+(16 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: 100
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1)))) WHERE ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) AND (((r1."C 1" % 10) = 0))
+(4 rows)
+
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100;
+ ?column?
+----------
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+(10 rows)
+
+DELETE FROM ft2 WHERE ft2.c1 > 1200;
+-- Test UPDATE with a MULTIEXPR sub-select
+-- (maybe someday this'll be remotely executable, but not today)
+EXPLAIN (verbose, costs off)
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 target
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2, c7 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.ft2 target
+ Output: $1, $2, (SubPlan 1 (returns $1,$2)), target.ctid, target.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1100)) FOR UPDATE
+ SubPlan 1 (returns $1,$2)
+ -> Foreign Scan on public.ft2 src
+ Output: (src.c2 * 10), src.c7
+ Remote SQL: SELECT c2, c7 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(9 rows)
+
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+UPDATE ft2 AS target SET (c2) = (
+ SELECT c2 / 10
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+-- Test UPDATE involving a join that can be pushed down,
+-- but a SET clause that can't be
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 d
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2 WHERE ctid = $1
+ -> Foreign Scan
+ Output: CASE WHEN (random() >= '0'::double precision) THEN d.c2 ELSE 0 END, d.ctid, d.*, t.*
+ Relations: (public.ft2 d) INNER JOIN (public.ft2 t)
+ Remote SQL: SELECT r1.c2, r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r1."C 1" > 1000)))) FOR UPDATE OF r1
+ -> Hash Join
+ Output: d.c2, d.ctid, d.*, t.*
+ Hash Cond: (d.c1 = t.c1)
+ -> Foreign Scan on public.ft2 d
+ Output: d.c2, d.ctid, d.*, d.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1000)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Hash
+ Output: t.*, t.c1
+ -> Foreign Scan on public.ft2 t
+ Output: t.*, t.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(17 rows)
+
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+-- Test UPDATE/DELETE with WHERE or JOIN/ON conditions containing
+-- user-defined operators/functions
+ALTER SERVER loopback OPTIONS (DROP extensions);
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id % 10, to_char(id, 'FM00000') FROM generate_series(2001, 2010) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft2
+ Output: 'bar'::text, ctid, ft2.*
+ Filter: (postgres_fdw_abs(ft2.c1) > 2000)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" FOR UPDATE
+(7 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-----+----+----+----+------------+----
+ 2001 | 1 | bar | | | | ft2 |
+ 2002 | 2 | bar | | | | ft2 |
+ 2003 | 3 | bar | | | | ft2 |
+ 2004 | 4 | bar | | | | ft2 |
+ 2005 | 5 | bar | | | | ft2 |
+ 2006 | 6 | bar | | | | ft2 |
+ 2007 | 7 | bar | | | | ft2 |
+ 2008 | 8 | bar | | | | ft2 |
+ 2009 | 9 | bar | | | | ft2 |
+ 2010 | 0 | bar | | | | ft2 |
+(10 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Nested Loop
+ Output: 'baz'::text, ft2.ctid, ft2.*, ft4.*, ft5.*, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Join Filter: (ft2.c2 === ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.*, ft2.c2
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Relations: (public.ft4) INNER JOIN (public.ft5)
+ Remote SQL: SELECT CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r3.c1, r3.c2, r3.c3 FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1))))
+ -> Hash Join
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(24 rows)
+
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3
+------+----+-----+----+----+----+------------+----+----+----+--------+----+----+--------
+ 2006 | 6 | baz | | | | ft2 | | 6 | 7 | AAA006 | 6 | 7 | AAA006
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ctid = $1 RETURNING "C 1", c2, c3
+ -> Foreign Scan
+ Output: ft2.ctid, ft4.*, ft5.*
+ Filter: (ft4.c1 === ft5.c1)
+ Relations: ((public.ft2) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r2.c1, r3.c1 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c2 = r2.c1)) AND ((r1."C 1" > 2000)))) INNER JOIN "S 1"."T 4" r3 ON (TRUE)) FOR UPDATE OF r1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft5.*, ft4.c1, ft5.c1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft4.c1
+ Join Filter: (ft2.c2 = ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.c2
+ Remote SQL: SELECT c2, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(22 rows)
+
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3;
+ c1 | c2 | c3
+------+----+-----
+ 2006 | 6 | baz
+(1 row)
+
+DELETE FROM ft2 WHERE ft2.c1 > 2000;
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- Test that trigger on remote table works as expected
+CREATE OR REPLACE FUNCTION "S 1".F_BRTRIG() RETURNS trigger AS $$
+BEGIN
+ NEW.c3 = NEW.c3 || '_trig_update';
+ RETURN NEW;
+END;
+$$ LANGUAGE plpgsql;
+CREATE TRIGGER t1_br_insert BEFORE INSERT OR UPDATE
+ ON "S 1"."T 1" FOR EACH ROW EXECUTE PROCEDURE "S 1".F_BRTRIG();
+INSERT INTO ft2 (c1,c2,c3) VALUES (1208, 818, 'fff') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+----+------------+----
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+(1 row)
+
+INSERT INTO ft2 (c1,c2,c3,c6) VALUES (1218, 818, 'ggg', '(--;') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+------+------------+----
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+(1 row)
+
+UPDATE ft2 SET c2 = c2 + 600 WHERE c1 % 10 = 8 AND c1 < 1200 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+------------------------+------------------------------+--------------------------+----+------------+-----
+ 8 | 608 | 00008_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 18 | 608 | 00018_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 28 | 608 | 00028_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 38 | 608 | 00038_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 48 | 608 | 00048_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 58 | 608 | 00058_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 68 | 608 | 00068_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 78 | 608 | 00078_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 88 | 608 | 00088_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 98 | 608 | 00098_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 108 | 608 | 00108_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 118 | 608 | 00118_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 128 | 608 | 00128_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 138 | 608 | 00138_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 148 | 608 | 00148_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 158 | 608 | 00158_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 168 | 608 | 00168_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 178 | 608 | 00178_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 188 | 608 | 00188_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 198 | 608 | 00198_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 208 | 608 | 00208_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 218 | 608 | 00218_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 228 | 608 | 00228_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 238 | 608 | 00238_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 248 | 608 | 00248_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 258 | 608 | 00258_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 268 | 608 | 00268_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 278 | 608 | 00278_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 288 | 608 | 00288_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 298 | 608 | 00298_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 308 | 608 | 00308_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 318 | 608 | 00318_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 328 | 608 | 00328_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 338 | 608 | 00338_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 348 | 608 | 00348_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 358 | 608 | 00358_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 368 | 608 | 00368_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 378 | 608 | 00378_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 388 | 608 | 00388_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 398 | 608 | 00398_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 408 | 608 | 00408_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 418 | 608 | 00418_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 428 | 608 | 00428_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 438 | 608 | 00438_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 448 | 608 | 00448_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 458 | 608 | 00458_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 468 | 608 | 00468_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 478 | 608 | 00478_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 488 | 608 | 00488_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 498 | 608 | 00498_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 508 | 608 | 00508_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 518 | 608 | 00518_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 528 | 608 | 00528_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 538 | 608 | 00538_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 548 | 608 | 00548_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 558 | 608 | 00558_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 568 | 608 | 00568_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 578 | 608 | 00578_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 588 | 608 | 00588_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 598 | 608 | 00598_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 608 | 608 | 00608_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 618 | 608 | 00618_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 628 | 608 | 00628_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 638 | 608 | 00638_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 648 | 608 | 00648_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 658 | 608 | 00658_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 668 | 608 | 00668_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 678 | 608 | 00678_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 688 | 608 | 00688_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 698 | 608 | 00698_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 708 | 608 | 00708_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 718 | 608 | 00718_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 728 | 608 | 00728_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 738 | 608 | 00738_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 748 | 608 | 00748_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 758 | 608 | 00758_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 768 | 608 | 00768_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 778 | 608 | 00778_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 788 | 608 | 00788_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 798 | 608 | 00798_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 808 | 608 | 00808_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 818 | 608 | 00818_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 828 | 608 | 00828_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 838 | 608 | 00838_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 848 | 608 | 00848_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 858 | 608 | 00858_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 868 | 608 | 00868_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 878 | 608 | 00878_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 888 | 608 | 00888_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 898 | 608 | 00898_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 908 | 608 | 00908_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 918 | 608 | 00918_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 928 | 608 | 00928_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 938 | 608 | 00938_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 948 | 608 | 00948_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 958 | 608 | 00958_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 968 | 608 | 00968_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 978 | 608 | 00978_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 988 | 608 | 00988_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 998 | 608 | 00998_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 1008 | 708 | 0000800008_trig_update | | | | ft2 |
+ 1018 | 708 | 0001800018_trig_update | | | | ft2 |
+(102 rows)
+
+-- Test errors thrown on remote side during update
+ALTER TABLE "S 1"."T 1" ADD CONSTRAINT c2positive CHECK (c2 >= 0);
+INSERT INTO ft1(c1, c2) VALUES(11, 12); -- duplicate key
+ERROR: duplicate key value violates unique constraint "t1_pkey"
+DETAIL: Key ("C 1")=(11) already exists.
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT DO NOTHING; -- works
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO NOTHING; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO UPDATE SET c3 = 'ffg'; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+-- Test savepoint/rollback behavior
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+begin;
+update ft2 set c2 = 42 where c2 = 0;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 42 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s1;
+update ft2 set c2 = 44 where c2 = 4;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s1;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s2;
+update ft2 set c2 = 46 where c2 = 6;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 42 | 100
+ 44 | 100
+ 46 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+rollback to savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s3;
+update ft2 set c2 = -2 where c2 = 42 and c1 = 10; -- fail on remote side
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (10, -2, 00010_trig_update_trig_update, 1970-01-11 08:00:00+00, 1970-01-11 00:00:00, 0, 0 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (-2) WHERE ((c2 = 42)) AND (("C 1" = 10))
+rollback to savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+-- none of the above is committed yet remotely
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+commit;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+VACUUM ANALYZE "S 1"."T 1";
+-- Above DMLs add data with c6 as NULL in ft1, so test ORDER BY NULLS LAST and NULLs
+-- FIRST behavior here.
+-- ORDER BY DESC NULLS LAST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 795::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+------+------------+-----
+ 960 | 42 | 00960_trig_update | Mon Mar 02 00:00:00 1970 PST | Mon Mar 02 00:00:00 1970 | 0 | 0 | foo
+ 970 | 42 | 00970_trig_update | Thu Mar 12 00:00:00 1970 PST | Thu Mar 12 00:00:00 1970 | 0 | 0 | foo
+ 980 | 42 | 00980_trig_update | Sun Mar 22 00:00:00 1970 PST | Sun Mar 22 00:00:00 1970 | 0 | 0 | foo
+ 990 | 42 | 00990_trig_update | Wed Apr 01 00:00:00 1970 PST | Wed Apr 01 00:00:00 1970 | 0 | 0 | foo
+ 1000 | 42 | 01000_trig_update | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 1001 | 101 | 0000100001 | | | | ft2 |
+ 1003 | 403 | 0000300003_update3 | | | | ft2 |
+ 1004 | 104 | 0000400004 | | | | ft2 |
+ 1006 | 106 | 0000600006 | | | | ft2 |
+(10 rows)
+
+-- ORDER BY DESC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+------------------------------+--------------------------+----+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | ft2 | foo
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST | Tue Jan 20 00:00:00 1970 | 9 | ft2 | foo
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST | Fri Jan 30 00:00:00 1970 | 9 | ft2 | foo
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST | Mon Feb 09 00:00:00 1970 | 9 | ft2 | foo
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST | Thu Feb 19 00:00:00 1970 | 9 | ft2 | foo
+(10 rows)
+
+-- ORDER BY ASC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 ASC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-------------------+------------------------------+--------------------------+------+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 10 | 42 | 00010_trig_update | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+ 20 | 42 | 00020_trig_update | Wed Jan 21 00:00:00 1970 PST | Wed Jan 21 00:00:00 1970 | 0 | 0 | foo
+ 30 | 42 | 00030_trig_update | Sat Jan 31 00:00:00 1970 PST | Sat Jan 31 00:00:00 1970 | 0 | 0 | foo
+ 40 | 42 | 00040_trig_update | Tue Feb 10 00:00:00 1970 PST | Tue Feb 10 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- ===================================================================
+-- test check constraints
+-- ===================================================================
+-- Consistent check constraints provide consistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- check constraint is enforced on the remote side, not locally
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
+-- But inconsistent check constraints provide inconsistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 821
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- local check constraint is not actually enforced
+INSERT INTO ft1(c1, c2) VALUES(1111, 2);
+UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
+-- ===================================================================
+-- test WITH CHECK OPTION constraints
+-- ===================================================================
+CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
+CREATE TABLE base_tbl (a int, b int);
+ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE VIEW rw_view AS SELECT * FROM foreign_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT foreign_tbl.a,
+ foreign_tbl.b
+ FROM foreign_tbl
+ WHERE foreign_tbl.a < foreign_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 5
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 15
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 5), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 15), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP TRIGGER row_before_insupd_trigger ON base_tbl;
+DROP TABLE base_tbl;
+-- test WCO for partitions
+CREATE TABLE child_tbl (a int, b int);
+ALTER TABLE child_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON child_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'child_tbl');
+CREATE TABLE parent_tbl (a int, b int) PARTITION BY RANGE(a);
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+-- Detach and re-attach once, to stress the concurrent detach case.
+ALTER TABLE parent_tbl DETACH PARTITION foreign_tbl CONCURRENTLY;
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+CREATE VIEW rw_view AS SELECT * FROM parent_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT parent_tbl.a,
+ parent_tbl.b
+ FROM parent_tbl
+ WHERE parent_tbl.a < parent_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 5
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 15
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 5), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 15), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------
+ Insert on public.parent_tbl
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+DROP TRIGGER row_before_insupd_trigger ON child_tbl;
+DROP TABLE parent_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP FUNCTION row_before_insupd_trigfunc;
+-- ===================================================================
+-- test serial columns (ie, sequence-based defaults)
+-- ===================================================================
+create table loc1 (f1 serial, f2 text);
+alter table loc1 set (autovacuum_enabled = 'false');
+create foreign table rem1 (f1 serial, f2 text)
+ server loopback options(table_name 'loc1');
+select pg_catalog.setval('rem1_f1_seq', 10, false);
+ setval
+--------
+ 10
+(1 row)
+
+insert into loc1(f2) values('hi');
+insert into rem1(f2) values('hi remote');
+insert into loc1(f2) values('bye');
+insert into rem1(f2) values('bye remote');
+select * from loc1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+select * from rem1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+-- ===================================================================
+-- test generated columns
+-- ===================================================================
+create table gloc1 (
+ a int,
+ b int generated always as (a * 2) stored);
+alter table gloc1 set (autovacuum_enabled = 'false');
+create foreign table grem1 (
+ a int,
+ b int generated always as (a * 2) stored)
+ server loopback options(table_name 'gloc1');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+explain (verbose, costs off)
+update grem1 set a = 22 where a = 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.grem1
+ Remote SQL: UPDATE public.gloc1 SET a = $2, b = DEFAULT WHERE ctid = $1
+ -> Foreign Scan on public.grem1
+ Output: 22, ctid, grem1.*
+ Remote SQL: SELECT a, b, ctid FROM public.gloc1 WHERE ((a = 2)) FOR UPDATE
+(5 rows)
+
+update grem1 set a = 22 where a = 2;
+select * from gloc1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+select * from grem1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+delete from grem1;
+-- test copy from
+copy grem1 from stdin;
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+-- test batch insert
+alter server loopback options (add batch_size '10');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 10
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test local triggers
+-- ===================================================================
+-- Trigger functions "borrowed" from triggers regress test.
+CREATE FUNCTION trigger_func() RETURNS trigger LANGUAGE plpgsql AS $$
+BEGIN
+ RAISE NOTICE 'trigger_func(%) called: action = %, when = %, level = %',
+ TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN NULL;
+END;$$;
+CREATE TRIGGER trig_stmt_before BEFORE DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE TRIGGER trig_stmt_after AFTER DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE OR REPLACE FUNCTION trigger_data() RETURNS trigger
+LANGUAGE plpgsql AS $$
+
+declare
+ oldnew text[];
+ relid text;
+ argstr text;
+begin
+
+ relid := TG_relid::regclass;
+ argstr := '';
+ for i in 0 .. TG_nargs - 1 loop
+ if i > 0 then
+ argstr := argstr || ', ';
+ end if;
+ argstr := argstr || TG_argv[i];
+ end loop;
+
+ RAISE NOTICE '%(%) % % % ON %',
+ tg_name, argstr, TG_when, TG_level, TG_OP, relid;
+ oldnew := '{}'::text[];
+ if TG_OP != 'INSERT' then
+ oldnew := array_append(oldnew, format('OLD: %s', OLD));
+ end if;
+
+ if TG_OP != 'DELETE' then
+ oldnew := array_append(oldnew, format('NEW: %s', NEW));
+ end if;
+
+ RAISE NOTICE '%', array_to_string(oldnew, ',');
+
+ if TG_OP = 'DELETE' then
+ return OLD;
+ else
+ return NEW;
+ end if;
+end;
+$$;
+-- Test basic functionality
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+delete from rem1;
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = AFTER, level = STATEMENT
+insert into rem1 values(1,'insert');
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+update rem1 set f2 = f2 || f2;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+truncate rem1;
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = BEFORE, level = STATEMENT
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = AFTER, level = STATEMENT
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_stmt_before ON rem1;
+DROP TRIGGER trig_stmt_after ON rem1;
+DELETE from rem1;
+-- Test multiple AFTER ROW triggers on a foreign table
+CREATE TRIGGER trig_row_after1
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after2
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+insert into rem1 values(1,'insert');
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+update rem1 set f2 = f2 || f2;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+delete from rem1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+-- cleanup
+DROP TRIGGER trig_row_after1 ON rem1;
+DROP TRIGGER trig_row_after2 ON rem1;
+-- Test WHEN conditions
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_insupd
+AFTER INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Insert or update not matching: nothing happens
+INSERT INTO rem1 values(1, 'insert');
+UPDATE rem1 set f2 = 'test';
+-- Insert or update matching: triggers are fired
+INSERT INTO rem1 values(2, 'update');
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+UPDATE rem1 set f2 = 'update update' where f1 = '2';
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Trigger is fired for f1=2, not for f1=1
+DELETE FROM rem1;
+NOTICE: trig_row_before_delete(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+NOTICE: trig_row_after_delete(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+-- cleanup
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_after_insupd ON rem1;
+DROP TRIGGER trig_row_before_delete ON rem1;
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- Test various RETURN statements in BEFORE triggers.
+CREATE FUNCTION trig_row_before_insupdate() RETURNS TRIGGER AS $$
+ BEGIN
+ NEW.f2 := NEW.f2 || ' triggered !';
+ RETURN NEW;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+-- The new values should have 'triggered' appended
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------
+ insert triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+ 2 | insert triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------
+ 1 | triggered !
+ 2 | triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------
+ skidoo triggered !
+ skidoo triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | skidoo triggered !
+ 2 | skidoo triggered !
+(2 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f1 = 10; -- all columns should be transmitted
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: 10, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+UPDATE rem1 set f1 = 10;
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 10 | skidoo triggered ! triggered !
+ 10 | skidoo triggered ! triggered !
+(2 rows)
+
+DELETE FROM rem1;
+-- Add a second trigger, to check that the changes are propagated correctly
+-- from trigger to trigger
+CREATE TRIGGER trig_row_before_insupd2
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------------------
+ insert triggered ! triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+ 2 | insert triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------
+ 1 | triggered ! triggered !
+ 2 | triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------------------
+ skidoo triggered ! triggered !
+ skidoo triggered ! triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | skidoo triggered ! triggered !
+ 2 | skidoo triggered ! triggered !
+(2 rows)
+
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_before_insupd2 ON rem1;
+DELETE from rem1;
+INSERT INTO rem1 VALUES (1, 'test');
+-- Test with a trigger returning NULL
+CREATE FUNCTION trig_null() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_null
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_null();
+-- Nothing should have changed.
+INSERT INTO rem1 VALUES (2, 'test2');
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+UPDATE rem1 SET f2 = 'test2';
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DELETE from rem1;
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DROP TRIGGER trig_null ON rem1;
+DELETE from rem1;
+-- Test a combination of local and remote triggers
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_local_before BEFORE INSERT OR UPDATE ON loc1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1(f2) VALUES ('test');
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (12,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (12,"test triggered !")
+UPDATE rem1 SET f2 = 'testo';
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,testo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,"testo triggered !")
+-- Test returning a system attribute
+INSERT INTO rem1(f2) VALUES ('test') RETURNING ctid;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (13,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (13,"test triggered !")
+ ctid
+--------
+ (0,25)
+(1 row)
+
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_local_before ON loc1;
+-- Test direct foreign table modification functionality
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1 WHERE false; -- currently can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Result
+ Output: ctid
+ One-Time Filter: false
+(5 rows)
+
+-- Test with statement-level triggers
+CREATE TRIGGER trig_stmt_before
+ BEFORE DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_before ON rem1;
+CREATE TRIGGER trig_stmt_after
+ AFTER DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_after ON rem1;
+-- Test with row-level ON INSERT triggers
+CREATE TRIGGER trig_row_before_insert
+BEFORE INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_insert ON rem1;
+CREATE TRIGGER trig_row_after_insert
+AFTER INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_insert ON rem1;
+-- Test with row-level ON UPDATE triggers
+CREATE TRIGGER trig_row_before_update
+BEFORE UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_update ON rem1;
+CREATE TRIGGER trig_row_after_update
+AFTER UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = $2 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_update ON rem1;
+-- Test with row-level ON DELETE triggers
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_before_delete ON rem1;
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- ===================================================================
+-- test inheritance features
+-- ===================================================================
+CREATE TABLE a (aa TEXT);
+CREATE TABLE loct (aa TEXT, bb TEXT);
+ALTER TABLE a SET (autovacuum_enabled = 'false');
+ALTER TABLE loct SET (autovacuum_enabled = 'false');
+CREATE FOREIGN TABLE b (bb TEXT) INHERITS (a)
+ SERVER loopback OPTIONS (table_name 'loct');
+INSERT INTO a(aa) VALUES('aaa');
+INSERT INTO a(aa) VALUES('aaaa');
+INSERT INTO a(aa) VALUES('aaaaa');
+INSERT INTO b(aa) VALUES('bbb');
+INSERT INTO b(aa) VALUES('bbbb');
+INSERT INTO b(aa) VALUES('bbbbb');
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+(3 rows)
+
+UPDATE a SET aa = 'zzzzzz' WHERE aa LIKE 'aaaa%';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE b SET aa = 'new';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | new
+ b | new
+ b | new
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-----+----
+ b | new |
+ b | new |
+ b | new |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE a SET aa = 'newtoo';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+ b | newtoo
+ b | newtoo
+ b | newtoo
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+--------+----
+ b | newtoo |
+ b | newtoo |
+ b | newtoo |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+(3 rows)
+
+DELETE FROM a;
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+----+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+DROP TABLE a CASCADE;
+NOTICE: drop cascades to foreign table b
+DROP TABLE loct;
+-- Check SELECT FOR UPDATE/SHARE with an inherited source table
+create table loct1 (f1 int, f2 int, f3 int);
+create table loct2 (f1 int, f2 int, f3 int);
+alter table loct1 set (autovacuum_enabled = 'false');
+alter table loct2 set (autovacuum_enabled = 'false');
+create table foo (f1 int, f2 int);
+create foreign table foo2 (f3 int) inherits (foo)
+ server loopback options (table_name 'loct1');
+create table bar (f1 int, f2 int);
+create foreign table bar2 (f3 int) inherits (bar)
+ server loopback options (table_name 'loct2');
+alter table foo set (autovacuum_enabled = 'false');
+alter table bar set (autovacuum_enabled = 'false');
+insert into foo values(1,1);
+insert into foo values(3,3);
+insert into foo2 values(2,2,2);
+insert into foo2 values(4,4,4);
+insert into bar values(1,11);
+insert into bar values(2,22);
+insert into bar values(6,66);
+insert into bar2 values(3,33,33);
+insert into bar2 values(4,44,44);
+insert into bar2 values(7,77,77);
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for update;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for update;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for share;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for share;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+-- Now check SELECT FOR UPDATE/SHARE with an inherited source table,
+-- where the parent is itself a foreign table
+create table loct4 (f1 int, f2 int, f3 int);
+create foreign table foo2child (f3 int) inherits (foo2)
+ server loopback options (table_name 'loct4');
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct1
+ -> Foreign Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct4
+(24 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop foreign table foo2child;
+-- And with a local child relation of the foreign table parent
+create table foo2child (f3 int) inherits (foo2);
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.ctid, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+ -> Seq Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.ctid, foo2_2.tableoid
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop table foo2child;
+-- Check UPDATE with inherited target and an inherited source table
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Hash Join
+ Output: (bar.f2 + 100), foo.ctid, bar.tableoid, bar.ctid, (NULL::record), foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(25 rows)
+
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 111
+ bar | 2 | 122
+ bar | 6 | 66
+ bar2 | 3 | 133
+ bar2 | 4 | 144
+ bar2 | 7 | 77
+(6 rows)
+
+-- Check UPDATE with inherited target and an appendrel subquery
+explain (verbose, costs off)
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Merge Join
+ Output: (bar.f2 + 100), (ROW(foo.f1)), bar.tableoid, bar.ctid, (NULL::record)
+ Merge Cond: (bar.f1 = foo.f1)
+ -> Sort
+ Output: bar.f2, bar.f1, bar.tableoid, bar.ctid, (NULL::record)
+ Sort Key: bar.f1
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Sort
+ Output: (ROW(foo.f1)), foo.f1
+ Sort Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: ROW(foo.f1), foo.f1
+ -> Foreign Scan on public.foo2 foo_1
+ Output: ROW(foo_1.f1), foo_1.f1
+ Remote SQL: SELECT f1 FROM public.loct1
+ -> Seq Scan on public.foo foo_2
+ Output: ROW((foo_2.f1 + 3)), (foo_2.f1 + 3)
+ -> Foreign Scan on public.foo2 foo_3
+ Output: ROW((foo_3.f1 + 3)), (foo_3.f1 + 3)
+ Remote SQL: SELECT f1 FROM public.loct1
+(30 rows)
+
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 211
+ bar | 2 | 222
+ bar | 6 | 166
+ bar2 | 3 | 233
+ bar2 | 4 | 244
+ bar2 | 7 | 177
+(6 rows)
+
+-- Test forcing the remote server to produce sorted data for a merge join,
+-- but the foreign table is an inheritance child.
+truncate table loct1;
+truncate table only foo;
+\set num_rows_foo 2000
+insert into loct1 select generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2);
+insert into foo select generate_series(1, :num_rows_foo, 2), generate_series(1, :num_rows_foo, 2);
+SET enable_hashjoin to false;
+SET enable_nestloop to false;
+alter foreign table foo2 options (use_remote_estimate 'true');
+create index i_loct1_f1 on loct1(f1);
+create index i_foo_f1 on foo(f1);
+analyze foo;
+analyze loct1;
+-- inner join; expressions in the clauses appear in the equivalence class list
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 20 | 20
+ 22 | 22
+ 24 | 24
+ 26 | 26
+ 28 | 28
+ 30 | 30
+ 32 | 32
+ 34 | 34
+ 36 | 36
+ 38 | 38
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Left Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 10 | 10
+ 11 |
+ 12 | 12
+ 13 |
+ 14 | 14
+ 15 |
+ 16 | 16
+ 17 |
+ 18 | 18
+ 19 |
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test that WHERE CURRENT OF is not supported
+begin;
+declare c cursor for select * from bar where f1 = 7;
+fetch from c;
+ f1 | f2
+----+-----
+ 7 | 177
+(1 row)
+
+update bar set f2 = null where current of c;
+ERROR: WHERE CURRENT OF is not supported for this table type
+rollback;
+explain (verbose, costs off)
+delete from foo where f1 < 5 returning *;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Delete on public.foo
+ Output: foo_1.f1, foo_1.f2
+ Delete on public.foo foo_1
+ Foreign Delete on public.foo2 foo_2
+ -> Append
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.tableoid, foo_1.ctid
+ Index Cond: (foo_1.f1 < 5)
+ -> Foreign Delete on public.foo2 foo_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ((f1 < 5)) RETURNING f1, f2
+(10 rows)
+
+delete from foo where f1 < 5 returning *;
+ f1 | f2
+----+----
+ 1 | 1
+ 3 | 3
+ 0 | 0
+ 2 | 2
+ 4 | 4
+(5 rows)
+
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Update on public.bar
+ Output: bar_1.f1, bar_1.f2
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = (f2 + 100) RETURNING f1, f2
+(11 rows)
+
+update bar set f2 = f2 + 100 returning *;
+ f1 | f2
+----+-----
+ 1 | 311
+ 2 | 322
+ 6 | 266
+ 3 | 333
+ 4 | 344
+ 7 | 277
+(6 rows)
+
+-- Test that UPDATE/DELETE with inherited target works with row-level triggers
+CREATE TRIGGER trig_row_before
+BEFORE UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+explain (verbose, costs off)
+update bar set f2 = f2 + 100;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f1 = $2, f2 = $3, f3 = $4 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+(12 rows)
+
+update bar set f2 = f2 + 100;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+explain (verbose, costs off)
+delete from bar where f2 < 400;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Delete on public.bar
+ Delete on public.bar bar_1
+ Foreign Delete on public.bar2 bar_2
+ Remote SQL: DELETE FROM public.loct2 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.tableoid, bar_1.ctid, NULL::record
+ Filter: (bar_1.f2 < 400)
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 WHERE ((f2 < 400)) FOR UPDATE
+(11 rows)
+
+delete from bar where f2 < 400;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+-- cleanup
+drop table foo cascade;
+NOTICE: drop cascades to foreign table foo2
+drop table bar cascade;
+NOTICE: drop cascades to foreign table bar2
+drop table loct1;
+drop table loct2;
+-- Test pushing down UPDATE/DELETE joins to the remote server
+create table parent (a int, b text);
+create table loct1 (a int, b text);
+create table loct2 (a int, b text);
+create foreign table remt1 (a int, b text)
+ server loopback options (table_name 'loct1');
+create foreign table remt2 (a int, b text)
+ server loopback options (table_name 'loct2');
+alter foreign table remt1 inherit parent;
+insert into remt1 values (1, 'foo');
+insert into remt1 values (2, 'bar');
+insert into remt2 values (1, 'foo');
+insert into remt2 values (2, 'bar');
+analyze remt1;
+analyze remt2;
+explain (verbose, costs off)
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.parent
+ Output: parent_1.a, parent_1.b, remt2.a, remt2.b
+ Update on public.parent parent_1
+ Foreign Update on public.remt1 parent_2
+ Remote SQL: UPDATE public.loct1 SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: (parent.b || remt2.b), remt2.*, remt2.a, remt2.b, parent.tableoid, parent.ctid, (NULL::record)
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.b, parent_1.a, parent_1.tableoid, parent_1.ctid, NULL::record
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.b, parent_2.a, parent_2.tableoid, parent_2.ctid, parent_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.b, remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.b, remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ a | b | a | b
+---+--------+---+-----
+ 1 | foofoo | 1 | foo
+ 2 | barbar | 2 | bar
+(2 rows)
+
+explain (verbose, costs off)
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Delete on public.parent
+ Output: parent_1.*
+ Delete on public.parent parent_1
+ Foreign Delete on public.remt1 parent_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: remt2.*, parent.tableoid, parent.ctid
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.a, parent_1.tableoid, parent_1.ctid
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.a, parent_2.tableoid, parent_2.ctid
+ Remote SQL: SELECT a, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ parent
+------------
+ (1,foofoo)
+ (2,barbar)
+(2 rows)
+
+-- cleanup
+drop foreign table remt1;
+drop foreign table remt2;
+drop table loct1;
+drop table loct2;
+drop table parent;
+-- ===================================================================
+-- test tuple routing for foreign-table partitions
+-- ===================================================================
+-- Test insert tuple routing
+create table itrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table itrtest attach partition remp1 for values in (1);
+alter table itrtest attach partition remp2 for values in (2);
+insert into itrtest values (1, 'foo');
+insert into itrtest values (1, 'bar') returning *;
+ a | b
+---+-----
+ 1 | bar
+(1 row)
+
+insert into itrtest values (2, 'baz');
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----
+ 2 | qux
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------
+ 1 | test1
+ 2 | test2
+(2 rows)
+
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from itrtest;
+-- MERGE ought to fail cleanly
+merge into itrtest using (select 1, 'foo') as source on (true)
+ when matched then do nothing;
+ERROR: cannot execute MERGE on relation "remp1"
+DETAIL: This operation is not supported for foreign tables.
+create unique index loct1_idx on loct1 (a);
+-- DO NOTHING without an inference specification is supported
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+-----
+ 1 | foo
+(1 row)
+
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+---
+(0 rows)
+
+-- But other cases are not supported
+insert into itrtest values (1, 'bar') on conflict (a) do nothing;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+insert into itrtest values (1, 'bar') on conflict (a) do update set b = excluded.b;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+delete from itrtest;
+drop index loct1_idx;
+-- Test that remote triggers work with insert tuple routing
+create function br_insert_trigfunc() returns trigger as $$
+begin
+ new.b := new.b || ' triggered !';
+ return new;
+end
+$$ language plpgsql;
+create trigger loct1_br_insert_trigger before insert on loct1
+ for each row execute procedure br_insert_trigfunc();
+create trigger loct2_br_insert_trigger before insert on loct2
+ for each row execute procedure br_insert_trigfunc();
+-- The new values are concatenated with ' triggered !'
+insert into itrtest values (1, 'foo') returning *;
+ a | b
+---+-----------------
+ 1 | foo triggered !
+(1 row)
+
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----------------
+ 2 | qux triggered !
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+with result as (insert into itrtest values (1, 'test1'), (2, 'test2') returning *) select * from result;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+drop trigger loct1_br_insert_trigger on loct1;
+drop trigger loct2_br_insert_trigger on loct2;
+drop table itrtest;
+drop table loct1;
+drop table loct2;
+-- Test update tuple routing
+create table utrtest (a int, b text) partition by list (a);
+create table loct (a int check (a in (1)), b text);
+create foreign table remp (a int check (a in (1)), b text) server loopback options (table_name 'loct');
+create table locp (a int check (a in (2)), b text);
+alter table utrtest attach partition remp for values in (1);
+alter table utrtest attach partition locp for values in (2);
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- It's not allowed to move a row from a partition that is foreign to another
+update utrtest set a = 2 where b = 'foo' returning *;
+ERROR: new row for relation "loct" violates check constraint "loct_a_check"
+DETAIL: Failing row contains (2, foo).
+CONTEXT: remote SQL command: UPDATE public.loct SET a = 2 WHERE ((b = 'foo')) RETURNING a, b
+-- But the reverse is allowed
+update utrtest set a = 1 where b = 'qux' returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- The executor should not let unexercised FDWs shut down
+update utrtest set a = 1 where b = 'foo';
+-- Test that remote triggers work with update tuple routing
+create trigger loct_br_insert_trigger before insert on loct
+ for each row execute procedure br_insert_trigfunc();
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition is a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 WHERE (((a = 1) OR (a = 2))) RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ Filter: ((utrtest_2.a = 1) OR (utrtest_2.a = 2))
+(10 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition isn't a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 2 returning *;
+ QUERY PLAN
+-------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ -> Seq Scan on public.locp utrtest_1
+ Output: 1, utrtest_1.tableoid, utrtest_1.ctid
+ Filter: (utrtest_1.a = 2)
+(6 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 2 returning *;
+ a | b
+---+-----------------
+ 1 | qux triggered !
+(1 row)
+
+drop trigger loct_br_insert_trigger on loct;
+-- We can move rows to a foreign partition that has been updated already,
+-- but can't move rows to a foreign partition that hasn't been updated yet
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- Test the former case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+(9 rows)
+
+update utrtest set a = 1 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ Update on public.locp utrtest_2
+ -> Hash Join
+ Output: 1, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, utrtest.*
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Foreign Scan on public.remp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, utrtest_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Seq Scan on public.locp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- Change the definition of utrtest so that the foreign partition get updated
+-- after the local partition
+delete from utrtest;
+alter table utrtest detach partition remp;
+drop foreign table remp;
+alter table loct drop constraint loct_a_check;
+alter table loct add check (a in (3));
+create foreign table remp (a int check (a in (3)), b text) server loopback options (table_name 'loct');
+alter table utrtest attach partition remp for values in (3);
+insert into utrtest values (2, 'qux');
+insert into utrtest values (3, 'xyzzy');
+-- Test the latter case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: 3, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = 3 RETURNING a, b
+(9 rows)
+
+update utrtest set a = 3 returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ -> Hash Join
+ Output: 3, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, (NULL::record)
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Scan on public.remp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, utrtest_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+drop table utrtest;
+drop table loct;
+-- Test copy tuple routing
+create table ctrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table ctrtest attach partition remp1 for values in (1);
+alter table ctrtest attach partition remp2 for values in (2);
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp2 | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-----+---
+ remp2 | qux | 2
+(1 row)
+
+-- Copying into foreign partitions directly should work as well
+copy remp1 from stdin;
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+(2 rows)
+
+delete from ctrtest;
+-- Test copy tuple routing with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from ctrtest;
+alter server loopback options (drop batch_size);
+drop table ctrtest;
+drop table loct1;
+drop table loct2;
+-- ===================================================================
+-- test COPY FROM
+-- ===================================================================
+create table loc2 (f1 int, f2 text);
+alter table loc2 set (autovacuum_enabled = 'false');
+create foreign table rem2 (f1 int, f2 text) server loopback options(table_name 'loc2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2, line 1: "-1 xyzzy"
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test local triggers
+create trigger trig_stmt_before before insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_stmt_after after insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+copy rem2 from stdin;
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop trigger trig_row_before on rem2;
+drop trigger trig_row_after on rem2;
+drop trigger trig_stmt_before on rem2;
+drop trigger trig_stmt_after on rem2;
+delete from rem2;
+create trigger trig_row_before_insert before insert on rem2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on rem2;
+delete from rem2;
+create trigger trig_null before insert on rem2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on rem2;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Test a combination of local and remote triggers
+create trigger rem2_trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger rem2_trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger loc2_trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+copy rem2 from stdin;
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,"foo triggered !")
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,"bar triggered !")
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger rem2_trig_row_before on rem2;
+drop trigger rem2_trig_row_after on rem2;
+drop trigger loc2_trig_row_before_insert on loc2;
+delete from rem2;
+-- test COPY FROM with foreign table created in the same transaction
+create table loc3 (f1 int, f2 text);
+begin;
+create foreign table rem3 (f1 int, f2 text)
+ server loopback options(table_name 'loc3');
+copy rem3 from stdin;
+commit;
+select * from rem3;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop foreign table rem3;
+drop table loc3;
+-- Test COPY FROM with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+ 3 | baz triggered !
+(3 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Check with zero-column foreign table; batch insert will be disabled
+alter table loc2 drop column f1;
+alter table loc2 drop column f2;
+alter table rem2 drop column f1;
+alter table rem2 drop column f2;
+copy rem2 from stdin;
+select * from rem2;
+--
+(3 rows)
+
+delete from rem2;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test for TRUNCATE
+-- ===================================================================
+CREATE TABLE tru_rtable0 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable0');
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(1,10) x);
+CREATE TABLE tru_ptable (id int) PARTITION BY HASH(id);
+CREATE TABLE tru_ptable__p0 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tru_rtable1 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable__p1 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback OPTIONS (table_name 'tru_rtable1');
+INSERT INTO tru_ptable (SELECT x FROM generate_series(11,20) x);
+CREATE TABLE tru_pk_table(id int primary key);
+CREATE TABLE tru_fk_table(fkey int references tru_pk_table(id));
+INSERT INTO tru_pk_table (SELECT x FROM generate_series(1,10) x);
+INSERT INTO tru_fk_table (SELECT x % 10 + 1 FROM generate_series(5,25) x);
+CREATE FOREIGN TABLE tru_pk_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_pk_table');
+CREATE TABLE tru_rtable_parent (id int);
+CREATE TABLE tru_rtable_child (id int);
+CREATE FOREIGN TABLE tru_ftable_parent (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_parent');
+CREATE FOREIGN TABLE tru_ftable_child () INHERITS (tru_ftable_parent)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_child');
+INSERT INTO tru_rtable_parent (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_rtable_child (SELECT x FROM generate_series(10, 18) x);
+-- normal truncate
+SELECT sum(id) FROM tru_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_ftable;
+SELECT count(*) FROM tru_rtable0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'truncatable' option
+ALTER SERVER loopback OPTIONS (ADD truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (ADD truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER SERVER loopback OPTIONS (DROP truncatable);
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+-- partitioned table with both local and foreign tables as partitions
+SELECT sum(id) FROM tru_ptable; -- 155
+ sum
+-----
+ 155
+(1 row)
+
+TRUNCATE tru_ptable;
+SELECT count(*) FROM tru_ptable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ptable__p0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable__p1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_rtable1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'CASCADE' option
+SELECT sum(id) FROM tru_pk_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_pk_ftable; -- failed by FK reference
+ERROR: cannot truncate a table referenced in a foreign key constraint
+DETAIL: Table "tru_fk_table" references "tru_pk_table".
+HINT: Truncate table "tru_fk_table" at the same time, or use TRUNCATE ... CASCADE.
+CONTEXT: remote SQL command: TRUNCATE public.tru_pk_table CONTINUE IDENTITY RESTRICT
+TRUNCATE tru_pk_ftable CASCADE;
+SELECT count(*) FROM tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_fk_table; -- also truncated,0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate two tables at a command
+INSERT INTO tru_ftable (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_pk_ftable (SELECT x FROM generate_series(3,10) x);
+SELECT count(*) from tru_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+TRUNCATE tru_ftable, tru_pk_ftable CASCADE;
+SELECT count(*) from tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate with ONLY clause
+-- Since ONLY is specified, the table tru_ftable_child that inherits
+-- tru_ftable_parent locally is not truncated.
+TRUNCATE ONLY tru_ftable_parent;
+SELECT sum(id) FROM tru_ftable_parent; -- 126
+ sum
+-----
+ 126
+(1 row)
+
+TRUNCATE tru_ftable_parent;
+SELECT count(*) FROM tru_ftable_parent; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- in case when remote table has inherited children
+CREATE TABLE tru_rtable0_child () INHERITS (tru_rtable0);
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(5,9) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(10,14) x);
+SELECT sum(id) FROM tru_ftable; -- 95
+ sum
+-----
+ 95
+(1 row)
+
+-- Both parent and child tables in the foreign server are truncated
+-- even though ONLY is specified because ONLY has no effect
+-- when truncating a foreign table.
+TRUNCATE ONLY tru_ftable;
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(21,25) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(26,30) x);
+SELECT sum(id) FROM tru_ftable; -- 255
+ sum
+-----
+ 255
+(1 row)
+
+TRUNCATE tru_ftable; -- truncate both of parent and child
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- cleanup
+DROP FOREIGN TABLE tru_ftable_parent, tru_ftable_child, tru_pk_ftable,tru_ftable__p1,tru_ftable;
+DROP TABLE tru_rtable0, tru_rtable1, tru_ptable, tru_ptable__p0, tru_pk_table, tru_fk_table,
+tru_rtable_parent,tru_rtable_child, tru_rtable0_child;
+-- ===================================================================
+-- test IMPORT FOREIGN SCHEMA
+-- ===================================================================
+CREATE SCHEMA import_source;
+CREATE TABLE import_source.t1 (c1 int, c2 varchar NOT NULL);
+CREATE TABLE import_source.t2 (c1 int default 42, c2 varchar NULL, c3 text collate "POSIX");
+CREATE TYPE typ1 AS (m1 int, m2 varchar);
+CREATE TABLE import_source.t3 (c1 timestamptz default now(), c2 typ1);
+CREATE TABLE import_source."x 4" (c1 float8, "C 2" text, c3 varchar(42));
+CREATE TABLE import_source."x 5" (c1 float8);
+ALTER TABLE import_source."x 5" DROP COLUMN c1;
+CREATE TABLE import_source."x 6" (c1 int, c2 int generated always as (c1 * 2) stored);
+CREATE TABLE import_source.t4 (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE import_source.t4_part PARTITION OF import_source.t4
+ FOR VALUES FROM (1) TO (100);
+CREATE TABLE import_source.t4_part2 PARTITION OF import_source.t4
+ FOR VALUES FROM (100) TO (200);
+CREATE SCHEMA import_dest1;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest1;
+\det+ import_dest1.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest1 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest1 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest1 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest1 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest1 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest1 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest1 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest1.*
+ Foreign table "import_dest1.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest1.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest1.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest1.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest1.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest1.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest1.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Options
+CREATE SCHEMA import_dest2;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest2
+ OPTIONS (import_default 'true');
+\det+ import_dest2.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest2 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest2 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest2 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest2 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest2 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest2 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest2 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest2.*
+ Foreign table "import_dest2.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest2.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | 42 | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest2.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | now() | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest2.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest2.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest2.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest2.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+CREATE SCHEMA import_dest3;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest3
+ OPTIONS (import_collate 'false', import_generated 'false', import_not_null 'false');
+\det+ import_dest3.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest3 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest3 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest3 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest3 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest3 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest3 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest3 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest3.*
+ Foreign table "import_dest3.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest3.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest3.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest3.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest3.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest3.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest3.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Check LIMIT TO and EXCEPT
+CREATE SCHEMA import_dest4;
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t1, nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+(2 rows)
+
+IMPORT FOREIGN SCHEMA import_source EXCEPT (t1, "x 4", nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest4 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest4 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+ import_dest4 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest4 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+-- Assorted error cases
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest4;
+ERROR: relation "t1" already exists
+CONTEXT: importing foreign table "t1"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO import_dest4;
+ERROR: schema "nonesuch" is not present on foreign server "loopback"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO notthere;
+ERROR: schema "notthere" does not exist
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER nowhere INTO notthere;
+ERROR: server "nowhere" does not exist
+-- Check case of a type present only on the remote server.
+-- We can fake this by dropping the type locally in our transaction.
+CREATE TYPE "Colors" AS ENUM ('red', 'green', 'blue');
+CREATE TABLE import_source.t5 (c1 int, c2 text collate "C", "Col" "Colors");
+CREATE SCHEMA import_dest5;
+BEGIN;
+DROP TYPE "Colors" CASCADE;
+NOTICE: drop cascades to column Col of table import_source.t5
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t5)
+ FROM SERVER loopback INTO import_dest5; -- ERROR
+ERROR: type "public.Colors" does not exist
+LINE 4: "Col" public."Colors" OPTIONS (column_name 'Col')
+ ^
+QUERY: CREATE FOREIGN TABLE t5 (
+ c1 integer OPTIONS (column_name 'c1'),
+ c2 text OPTIONS (column_name 'c2') COLLATE pg_catalog."C",
+ "Col" public."Colors" OPTIONS (column_name 'Col')
+) SERVER loopback
+OPTIONS (schema_name 'import_source', table_name 't5');
+CONTEXT: importing foreign table "t5"
+ROLLBACK;
+BEGIN;
+CREATE SERVER fetch101 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( fetch_size '101' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER fetch101 OPTIONS( SET fetch_size '202' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=202'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30000 ( x int ) SERVER fetch101 OPTIONS ( fetch_size '30000' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '60000');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=60000'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- ===================================================================
+-- test partitionwise joins
+-- ===================================================================
+SET enable_partitionwise_join=on;
+CREATE TABLE fprt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE fprt1_p1 (LIKE fprt1);
+CREATE TABLE fprt1_p2 (LIKE fprt1);
+ALTER TABLE fprt1_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt1_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt1_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 2) i;
+INSERT INTO fprt1_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 2) i;
+CREATE FOREIGN TABLE ftprt1_p1 PARTITION OF fprt1 FOR VALUES FROM (0) TO (250)
+ SERVER loopback OPTIONS (table_name 'fprt1_p1', use_remote_estimate 'true');
+CREATE FOREIGN TABLE ftprt1_p2 PARTITION OF fprt1 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (TABLE_NAME 'fprt1_p2');
+ANALYZE fprt1;
+ANALYZE fprt1_p1;
+ANALYZE fprt1_p2;
+CREATE TABLE fprt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE fprt2_p1 (LIKE fprt2);
+CREATE TABLE fprt2_p2 (LIKE fprt2);
+ALTER TABLE fprt2_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt2_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt2_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 3) i;
+INSERT INTO fprt2_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 3) i;
+CREATE FOREIGN TABLE ftprt2_p1 (b int, c varchar, a int)
+ SERVER loopback OPTIONS (table_name 'fprt2_p1', use_remote_estimate 'true');
+ALTER TABLE fprt2 ATTACH PARTITION ftprt2_p1 FOR VALUES FROM (0) TO (250);
+CREATE FOREIGN TABLE ftprt2_p2 PARTITION OF fprt2 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (table_name 'fprt2_p2', use_remote_estimate 'true');
+ANALYZE fprt2;
+ANALYZE fprt2_p1;
+ANALYZE fprt2_p2;
+-- inner join three tables
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t3.c
+ -> Append
+ -> Foreign Scan
+ Relations: ((ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)) INNER JOIN (ftprt1_p1 t3_1)
+ -> Foreign Scan
+ Relations: ((ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)) INNER JOIN (ftprt1_p2 t3_2)
+(7 rows)
+
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0003
+ 250 | 250 | 0005
+ 400 | 400 | 0008
+(4 rows)
+
+-- left outer join + nullable clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.a, fprt2.b, fprt2.c
+ Relations: (public.ftprt1_p1 t1) LEFT JOIN (public.ftprt2_p1 fprt2)
+ Remote SQL: SELECT r5.a, r6.b, r6.c FROM (public.fprt1_p1 r5 LEFT JOIN public.fprt2_p1 r6 ON (((r5.a = r6.b)) AND ((r5.b = r6.a)) AND ((r6.a < 10)))) WHERE ((r5.a < 10)) ORDER BY r5.a ASC NULLS LAST, r6.b ASC NULLS LAST, r6.c ASC NULLS LAST
+(4 rows)
+
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ a | b | c
+---+---+------
+ 0 | 0 | 0000
+ 2 | |
+ 4 | |
+ 6 | 6 | 0000
+ 8 | |
+(5 rows)
+
+-- with whole-row reference; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ QUERY PLAN
+--------------------------------------------------------
+ Sort
+ Sort Key: ((t1.*)::fprt1), ((t2.*)::fprt2)
+ -> Hash Full Join
+ Hash Cond: (t1.a = t2.b)
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+(11 rows)
+
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ wr | wr
+----------------+----------------
+ (0,0,0000) | (0,0,0000)
+ (50,50,0001) |
+ (100,100,0002) |
+ (150,150,0003) | (150,150,0003)
+ (200,200,0004) |
+ (250,250,0005) | (250,250,0005)
+ (300,300,0006) |
+ (350,350,0007) |
+ (400,400,0008) | (400,400,0008)
+ (450,450,0009) |
+ | (75,75,0001)
+ | (225,225,0004)
+ | (325,325,0006)
+ | (475,475,0009)
+(14 rows)
+
+-- join with lateral reference
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t1.b
+ -> Append
+ -> Foreign Scan
+ Relations: (ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)
+ -> Foreign Scan
+ Relations: (ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)
+(7 rows)
+
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+-- with PHVs, partitionwise join selected but no join pushdown
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: fprt1.a, fprt2.b
+ -> Append
+ -> Hash Full Join
+ Hash Cond: (fprt1_1.a = fprt2_1.b)
+ -> Foreign Scan on ftprt1_p1 fprt1_1
+ -> Hash
+ -> Foreign Scan on ftprt2_p1 fprt2_1
+ -> Hash Full Join
+ Hash Cond: (fprt1_2.a = fprt2_2.b)
+ -> Foreign Scan on ftprt1_p2 fprt1_2
+ -> Hash
+ -> Foreign Scan on ftprt2_p2 fprt2_2
+(13 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | phv | b | phv
+-----+--------+-----+--------
+ 0 | t1_phv | 0 | t2_phv
+ 50 | t1_phv | |
+ 100 | t1_phv | |
+ 150 | t1_phv | 150 | t2_phv
+ 200 | t1_phv | |
+ 250 | t1_phv | 250 | t2_phv
+ 300 | t1_phv | |
+ 350 | t1_phv | |
+ 400 | t1_phv | 400 | t2_phv
+ 450 | t1_phv | |
+ | | 75 | t2_phv
+ | | 225 | t2_phv
+ | | 325 | t2_phv
+ | | 475 | t2_phv
+(14 rows)
+
+-- test FOR UPDATE; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ QUERY PLAN
+--------------------------------------------------------------
+ LockRows
+ -> Sort
+ Sort Key: t1.a
+ -> Hash Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+(12 rows)
+
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+RESET enable_partitionwise_join;
+-- ===================================================================
+-- test partitionwise aggregates
+-- ===================================================================
+CREATE TABLE pagg_tab (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE pagg_tab_p1 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p2 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p3 (LIKE pagg_tab);
+INSERT INTO pagg_tab_p1 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 10;
+INSERT INTO pagg_tab_p2 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 20 and (i % 30) >= 10;
+INSERT INTO pagg_tab_p3 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 30 and (i % 30) >= 20;
+-- Create foreign partitions
+CREATE FOREIGN TABLE fpagg_tab_p1 PARTITION OF pagg_tab FOR VALUES FROM (0) TO (10) SERVER loopback OPTIONS (table_name 'pagg_tab_p1');
+CREATE FOREIGN TABLE fpagg_tab_p2 PARTITION OF pagg_tab FOR VALUES FROM (10) TO (20) SERVER loopback OPTIONS (table_name 'pagg_tab_p2');
+CREATE FOREIGN TABLE fpagg_tab_p3 PARTITION OF pagg_tab FOR VALUES FROM (20) TO (30) SERVER loopback OPTIONS (table_name 'pagg_tab_p3');
+ANALYZE pagg_tab;
+ANALYZE fpagg_tab_p1;
+ANALYZE fpagg_tab_p2;
+ANALYZE fpagg_tab_p3;
+-- When GROUP BY clause matches with PARTITION KEY.
+-- Plan with partitionwise aggregates is disabled
+SET enable_partitionwise_aggregate TO false;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> HashAggregate
+ Group Key: pagg_tab.a
+ Filter: (avg(pagg_tab.b) < '22'::numeric)
+ -> Append
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab_1
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_2
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_3
+(9 rows)
+
+-- Plan with partitionwise aggregates is enabled
+SET enable_partitionwise_aggregate TO true;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> Append
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p1 pagg_tab)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p2 pagg_tab_1)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p3 pagg_tab_2)
+(9 rows)
+
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | sum | min | count
+----+------+-----+-------
+ 0 | 2000 | 0 | 100
+ 1 | 2100 | 1 | 100
+ 10 | 2000 | 0 | 100
+ 11 | 2100 | 1 | 100
+ 20 | 2000 | 0 | 100
+ 21 | 2100 | 1 | 100
+(6 rows)
+
+-- Check with whole-row reference
+-- Should have all the columns in the target list for the given relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, (count(((t1.*)::pagg_tab)))
+ Sort Key: t1.a
+ -> Append
+ -> HashAggregate
+ Output: t1.a, count(((t1.*)::pagg_tab))
+ Group Key: t1.a
+ Filter: (avg(t1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p1 t1
+ Output: t1.a, t1.*, t1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p1
+ -> HashAggregate
+ Output: t1_1.a, count(((t1_1.*)::pagg_tab))
+ Group Key: t1_1.a
+ Filter: (avg(t1_1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p2 t1_1
+ Output: t1_1.a, t1_1.*, t1_1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p2
+ -> HashAggregate
+ Output: t1_2.a, count(((t1_2.*)::pagg_tab))
+ Group Key: t1_2.a
+ Filter: (avg(t1_2.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p3 t1_2
+ Output: t1_2.a, t1_2.*, t1_2.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p3
+(25 rows)
+
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | count
+----+-------
+ 0 | 100
+ 1 | 100
+ 10 | 100
+ 11 | 100
+ 20 | 100
+ 21 | 100
+(6 rows)
+
+-- When GROUP BY clause does not match with PARTITION KEY.
+EXPLAIN (COSTS OFF)
+SELECT b, avg(a), max(a), count(*) FROM pagg_tab GROUP BY b HAVING sum(a) < 700 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.b
+ -> Finalize HashAggregate
+ Group Key: pagg_tab.b
+ Filter: (sum(pagg_tab.a) < 700)
+ -> Append
+ -> Partial HashAggregate
+ Group Key: pagg_tab.b
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab
+ -> Partial HashAggregate
+ Group Key: pagg_tab_1.b
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_1
+ -> Partial HashAggregate
+ Group Key: pagg_tab_2.b
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_2
+(15 rows)
+
+-- ===================================================================
+-- access rights and superuser
+-- ===================================================================
+-- Non-superuser cannot create a FDW without a password in the connstr
+CREATE ROLE regress_nosuper NOSUPERUSER;
+GRANT USAGE ON FOREIGN DATA WRAPPER postgres_fdw TO regress_nosuper;
+SET ROLE regress_nosuper;
+SHOW is_superuser;
+ is_superuser
+--------------
+ off
+(1 row)
+
+-- This will be OK, we can create the FDW
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback_nopw FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+-- But creation of user mappings for non-superusers should fail
+CREATE USER MAPPING FOR public SERVER loopback_nopw;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+CREATE FOREIGN TABLE pg_temp.ft1_nopw (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback_nopw OPTIONS (schema_name 'public', table_name 'ft1');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+-- If we add a password to the connstr it'll fail, because we don't allow passwords
+-- in connstrs only in user mappings.
+ALTER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+ERROR: invalid option "password"
+HINT: Perhaps you meant the option "passfile".
+-- If we add a password for our user mapping instead, we should get a different
+-- error because the password wasn't actually *used* when we run with trust auth.
+--
+-- This won't work with installcheck, but neither will most of the FDW checks.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+-- Unpriv user cannot make the mapping passwordless
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+ERROR: password_required=false is superuser-only
+HINT: User mappings with the password_required option set to false may only be created or modified by the superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+RESET ROLE;
+-- But the superuser can
+ALTER USER MAPPING FOR regress_nosuper SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+SET ROLE regress_nosuper;
+-- Should finally work now
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- unpriv user also cannot set sslcert / sslkey on the user mapping
+-- first set password_required so we see the right error messages
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (SET password_required 'true');
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslcert 'foo.crt');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslkey 'foo.key');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+-- We're done with the role named after a specific user and need to check the
+-- changes to the public mapping.
+DROP USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+-- This will fail again as it'll resolve the user mapping for public, which
+-- lacks password_required=false
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+RESET ROLE;
+-- The user mapping for public is passwordless and lacks the password_required=false
+-- mapping option, but will work because the current user is a superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- cleanup
+DROP USER MAPPING FOR public SERVER loopback_nopw;
+DROP OWNED BY regress_nosuper;
+DROP ROLE regress_nosuper;
+-- Clean-up
+RESET enable_partitionwise_aggregate;
+-- Two-phase transactions are not supported.
+BEGIN;
+SELECT count(*) FROM ft1;
+ count
+-------
+ 822
+(1 row)
+
+-- error here
+PREPARE TRANSACTION 'fdw_tpc';
+ERROR: cannot PREPARE a transaction that has operated on postgres_fdw foreign tables
+ROLLBACK;
+WARNING: there is no transaction in progress
+-- ===================================================================
+-- reestablish new connection
+-- ===================================================================
+-- Change application_name of remote connection to special one
+-- so that we can easily terminate the connection later.
+ALTER SERVER loopback OPTIONS (application_name 'fdw_retry_check');
+-- If debug_discard_caches is active, it results in
+-- dropping remote connections after every transaction, making it
+-- impossible to test termination meaningfully. So turn that off
+-- for this test.
+SET debug_discard_caches = 0;
+-- Make sure we have a remote connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- This query should detect the broken connection when starting new remote
+-- transaction, reestablish new connection, and then succeed.
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- If we detect the broken connection when starting a new remote
+-- subtransaction, we should fail instead of establishing a new connection.
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+SAVEPOINT s;
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT 1 FROM ft1 LIMIT 1; -- should fail
+ERROR: 08006
+\set VERBOSITY default
+COMMIT;
+RESET debug_discard_caches;
+-- =============================================================================
+-- test connection invalidation cases and postgres_fdw_get_connections function
+-- =============================================================================
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- This test case is for closing the connection in pgfdw_xact_callback
+BEGIN;
+-- Connection xact depth becomes 1 i.e. the connection is in midst of the xact.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT 1 FROM ft7 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback3 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback3
+(2 rows)
+
+-- Connections are not closed at the end of the alter and drop statements.
+-- That's because the connections are in midst of this xact,
+-- they are just marked as invalid in pgfdw_inval_callback.
+ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
+DROP SERVER loopback3 CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to user mapping for public on server loopback3
+drop cascades to foreign table ft7
+-- List all the existing cached connections. loopback and loopback3
+-- should be output as invalid connections. Also the server name for
+-- loopback3 should be NULL because the server was dropped.
+SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | valid
+-------------+-------
+ loopback | f
+ | f
+(2 rows)
+
+-- The invalid connections get closed in pgfdw_xact_callback during commit.
+COMMIT;
+-- All cached connections were closed while committing above xact, so no
+-- records should be output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+(0 rows)
+
+-- =======================================================================
+-- test postgres_fdw_disconnect and postgres_fdw_disconnect_all functions
+-- =======================================================================
+BEGIN;
+-- Ensure to cache loopback connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Ensure to cache loopback2 connection.
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Issue a warning and return false as loopback connection is still in use and
+-- can not be closed.
+SELECT postgres_fdw_disconnect('loopback');
+WARNING: cannot close connection for server "loopback" because it is still in use
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Return false as connections are still in use, warnings are issued.
+-- But disable warnings temporarily because the order of them is not stable.
+SET client_min_messages = 'ERROR';
+SELECT postgres_fdw_disconnect_all();
+ postgres_fdw_disconnect_all
+-----------------------------
+ f
+(1 row)
+
+RESET client_min_messages;
+COMMIT;
+-- Ensure that loopback2 connection is closed.
+SELECT 1 FROM postgres_fdw_disconnect('loopback2');
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT server_name FROM postgres_fdw_get_connections() WHERE server_name = 'loopback2';
+ server_name
+-------------
+(0 rows)
+
+-- Return false as loopback2 connection is closed already.
+SELECT postgres_fdw_disconnect('loopback2');
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- Return an error as there is no foreign server with given name.
+SELECT postgres_fdw_disconnect('unknownserver');
+ERROR: server "unknownserver" does not exist
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- =============================================================================
+-- test case for having multiple cached connections for a foreign server
+-- =============================================================================
+CREATE ROLE regress_multi_conn_user1 SUPERUSER;
+CREATE ROLE regress_multi_conn_user2 SUPERUSER;
+CREATE USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+CREATE USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+BEGIN;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user1
+SET ROLE regress_multi_conn_user1;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user2
+SET ROLE regress_multi_conn_user2;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Should output two connections for loopback server
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback
+(2 rows)
+
+COMMIT;
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- Clean up
+DROP USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+DROP USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+DROP ROLE regress_multi_conn_user1;
+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
+-- ===================================================================
+BEGIN;
+CREATE SERVER batch10 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( batch_size '10' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER batch10 OPTIONS( SET batch_size '20' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=20'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30 ( x int ) SERVER batch10 OPTIONS ( batch_size '30' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30 OPTIONS ( SET batch_size '40');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=40'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+CREATE TABLE batch_table ( x int );
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '10' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 10
+ -> Function Scan on pg_catalog.generate_series i
+ Output: i.i
+ Function Call: generate_series(1, 10)
+(6 rows)
+
+INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+INSERT INTO ftable SELECT * FROM generate_series(11, 31) i;
+INSERT INTO ftable VALUES (32);
+INSERT INTO ftable VALUES (33), (34);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 34
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- try if large batches exceed max number of bind parameters
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '100000' );
+INSERT INTO ftable SELECT * FROM generate_series(1, 70000) i;
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 70000
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- Disable batch insert
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '1' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (1), (2);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 2
+(1 row)
+
+-- Disable batch inserting into foreign tables with BEFORE ROW INSERT triggers
+-- even if the batch_size option is enabled.
+ALTER FOREIGN TABLE ftable OPTIONS ( SET batch_size '10' );
+CREATE TRIGGER trig_row_before BEFORE INSERT ON ftable
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (3), (4);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (3), (4);
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (3)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (4)
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 4
+(1 row)
+
+-- Clean up
+DROP TRIGGER trig_row_before ON ftable;
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+-- Use partitioning
+CREATE TABLE batch_table ( x int ) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0', batch_size '10');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1', batch_size '1');
+CREATE TABLE batch_table_p2
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 2);
+INSERT INTO batch_table SELECT * FROM generate_series(1, 66) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 66
+(1 row)
+
+-- Check that enabling batched inserts doesn't interfere with cross-partition
+-- updates
+CREATE TABLE batch_cp_upd_test (a int) PARTITION BY LIST (a);
+CREATE TABLE batch_cp_upd_test1 (LIKE batch_cp_upd_test);
+CREATE FOREIGN TABLE batch_cp_upd_test1_f
+ PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_cp_upd_test1', batch_size '10');
+CREATE TABLE batch_cp_up_test1 PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (2);
+INSERT INTO batch_cp_upd_test VALUES (1), (2);
+-- The following moves a row from the local partition to the foreign one
+UPDATE batch_cp_upd_test t SET a = 1 FROM (VALUES (1), (2)) s(a) WHERE t.a = s.a;
+ERROR: cannot route tuples into foreign table to be updated "batch_cp_upd_test1_f"
+SELECT tableoid::regclass, * FROM batch_cp_upd_test;
+ tableoid | a
+----------------------+---
+ batch_cp_upd_test1_f | 1
+ batch_cp_up_test1 | 2
+(2 rows)
+
+-- Clean up
+DROP TABLE batch_table, batch_cp_upd_test, batch_table_p0, batch_table_p1 CASCADE;
+-- Use partitioning
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+CREATE TABLE batch_table ( x int, field1 text, field2 text) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+ALTER TABLE batch_table_p0 ADD CONSTRAINT p0_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+ALTER TABLE batch_table_p1 ADD CONSTRAINT p1_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1');
+INSERT INTO batch_table SELECT i, 'test'||i, 'test'|| i FROM generate_series(1, 50) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 50
+(1 row)
+
+SELECT * FROM batch_table ORDER BY x;
+ x | field1 | field2
+----+--------+--------
+ 1 | test1 | test1
+ 2 | test2 | test2
+ 3 | test3 | test3
+ 4 | test4 | test4
+ 5 | test5 | test5
+ 6 | test6 | test6
+ 7 | test7 | test7
+ 8 | test8 | test8
+ 9 | test9 | test9
+ 10 | test10 | test10
+ 11 | test11 | test11
+ 12 | test12 | test12
+ 13 | test13 | test13
+ 14 | test14 | test14
+ 15 | test15 | test15
+ 16 | test16 | test16
+ 17 | test17 | test17
+ 18 | test18 | test18
+ 19 | test19 | test19
+ 20 | test20 | test20
+ 21 | test21 | test21
+ 22 | test22 | test22
+ 23 | test23 | test23
+ 24 | test24 | test24
+ 25 | test25 | test25
+ 26 | test26 | test26
+ 27 | test27 | test27
+ 28 | test28 | test28
+ 29 | test29 | test29
+ 30 | test30 | test30
+ 31 | test31 | test31
+ 32 | test32 | test32
+ 33 | test33 | test33
+ 34 | test34 | test34
+ 35 | test35 | test35
+ 36 | test36 | test36
+ 37 | test37 | test37
+ 38 | test38 | test38
+ 39 | test39 | test39
+ 40 | test40 | test40
+ 41 | test41 | test41
+ 42 | test42 | test42
+ 43 | test43 | test43
+ 44 | test44 | test44
+ 45 | test45 | test45
+ 46 | test46 | test46
+ 47 | test47 | test47
+ 48 | test48 | test48
+ 49 | test49 | test49
+ 50 | test50 | test50
+(50 rows)
+
+-- Clean up
+DROP TABLE batch_table;
+DROP TABLE batch_table_p0;
+DROP TABLE batch_table_p1;
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+-- Test that pending inserts are handled properly when needed
+CREATE TABLE batch_table (a text, b int);
+CREATE FOREIGN TABLE ftable (a text, b int)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table', batch_size '2');
+CREATE TABLE ltable (a text, b int);
+CREATE FUNCTION ftable_rowcount_trigf() RETURNS trigger LANGUAGE plpgsql AS
+$$
+begin
+ raise notice '%: there are % rows in ftable',
+ TG_NAME, (SELECT count(*) FROM ftable);
+ if TG_OP = 'DELETE' then
+ return OLD;
+ else
+ return NEW;
+ end if;
+end;
+$$;
+CREATE TRIGGER ftable_rowcount_trigger
+BEFORE INSERT OR UPDATE OR DELETE ON ltable
+FOR EACH ROW EXECUTE PROCEDURE ftable_rowcount_trigf();
+WITH t AS (
+ INSERT INTO ltable VALUES ('AAA', 42), ('BBB', 42) RETURNING *
+)
+INSERT INTO ftable SELECT * FROM t;
+NOTICE: ftable_rowcount_trigger: there are 0 rows in ftable
+NOTICE: ftable_rowcount_trigger: there are 1 rows in ftable
+SELECT * FROM ltable;
+ a | b
+-----+----
+ AAA | 42
+ BBB | 42
+(2 rows)
+
+SELECT * FROM ftable;
+ a | b
+-----+----
+ AAA | 42
+ BBB | 42
+(2 rows)
+
+DELETE FROM ftable;
+WITH t AS (
+ UPDATE ltable SET b = b + 100 RETURNING *
+)
+INSERT INTO ftable SELECT * FROM t;
+NOTICE: ftable_rowcount_trigger: there are 0 rows in ftable
+NOTICE: ftable_rowcount_trigger: there are 1 rows in ftable
+SELECT * FROM ltable;
+ a | b
+-----+-----
+ AAA | 142
+ BBB | 142
+(2 rows)
+
+SELECT * FROM ftable;
+ a | b
+-----+-----
+ AAA | 142
+ BBB | 142
+(2 rows)
+
+DELETE FROM ftable;
+WITH t AS (
+ DELETE FROM ltable RETURNING *
+)
+INSERT INTO ftable SELECT * FROM t;
+NOTICE: ftable_rowcount_trigger: there are 0 rows in ftable
+NOTICE: ftable_rowcount_trigger: there are 1 rows in ftable
+SELECT * FROM ltable;
+ a | b
+---+---
+(0 rows)
+
+SELECT * FROM ftable;
+ a | b
+-----+-----
+ AAA | 142
+ BBB | 142
+(2 rows)
+
+DELETE FROM ftable;
+-- Clean up
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+DROP TRIGGER ftable_rowcount_trigger ON ltable;
+DROP TABLE ltable;
+CREATE TABLE parent (a text, b int) PARTITION BY LIST (a);
+CREATE TABLE batch_table (a text, b int);
+CREATE FOREIGN TABLE ftable
+ PARTITION OF parent
+ FOR VALUES IN ('AAA')
+ SERVER loopback
+ OPTIONS (table_name 'batch_table', batch_size '2');
+CREATE TABLE ltable
+ PARTITION OF parent
+ FOR VALUES IN ('BBB');
+CREATE TRIGGER ftable_rowcount_trigger
+BEFORE INSERT ON ltable
+FOR EACH ROW EXECUTE PROCEDURE ftable_rowcount_trigf();
+INSERT INTO parent VALUES ('AAA', 42), ('BBB', 42), ('AAA', 42), ('BBB', 42);
+NOTICE: ftable_rowcount_trigger: there are 1 rows in ftable
+NOTICE: ftable_rowcount_trigger: there are 2 rows in ftable
+SELECT tableoid::regclass, * FROM parent;
+ tableoid | a | b
+----------+-----+----
+ ftable | AAA | 42
+ ftable | AAA | 42
+ ltable | BBB | 42
+ ltable | BBB | 42
+(4 rows)
+
+-- Clean up
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+DROP TRIGGER ftable_rowcount_trigger ON ltable;
+DROP TABLE ltable;
+DROP TABLE parent;
+DROP FUNCTION ftable_rowcount_trigf;
+-- ===================================================================
+-- test asynchronous execution
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD async_capable 'true');
+ALTER SERVER loopback2 OPTIONS (ADD async_capable 'true');
+CREATE TABLE async_pt (a int, b int, c text) PARTITION BY RANGE (a);
+CREATE TABLE base_tbl1 (a int, b int, c text);
+CREATE TABLE base_tbl2 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p1 PARTITION OF async_pt FOR VALUES FROM (1000) TO (2000)
+ SERVER loopback OPTIONS (table_name 'base_tbl1');
+CREATE FOREIGN TABLE async_p2 PARTITION OF async_pt FOR VALUES FROM (2000) TO (3000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl2');
+INSERT INTO async_p1 SELECT 1000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+INSERT INTO async_p2 SELECT 2000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+-- simple queries
+CREATE TABLE result_tbl (a int, b int, c text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE (((b % 100) = 0))
+(8 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1000 | 0 | 0000
+ 1100 | 100 | 0100
+ 1200 | 200 | 0200
+ 1300 | 300 | 0300
+ 1400 | 400 | 0400
+ 1500 | 500 | 0500
+ 1600 | 600 | 0600
+ 1700 | 700 | 0700
+ 1800 | 800 | 0800
+ 1900 | 900 | 0900
+ 2000 | 0 | 0000
+ 2100 | 100 | 0100
+ 2200 | 200 | 0200
+ 2300 | 300 | 0300
+ 2400 | 400 | 0400
+ 2500 | 500 | 0500
+ 2600 | 600 | 0600
+ 2700 | 700 | 0700
+ 2800 | 800 | 0800
+ 2900 | 900 | 0900
+(20 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, ('AAA'::text || async_pt_1.c)
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, ('AAA'::text || async_pt_2.c)
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+---------
+ 1505 | 505 | AAA0505
+ 2505 | 505 | AAA0505
+(2 rows)
+
+DELETE FROM result_tbl;
+-- Check case where multiple partitions use the same connection
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl3');
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Async Foreign Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(14 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+DROP FOREIGN TABLE async_p3;
+DROP TABLE base_tbl3;
+-- Check case where the partitioned table has local/remote partitions
+CREATE TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000);
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+(13 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+-- partitionwise joins
+SET enable_partitionwise_join TO true;
+CREATE TABLE join_tbl (a1 int, b1 int, c1 text, a2 int, b2 int, c2 text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t2_1.b, t2_1.c
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t2_2.b, t2_2.c
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, t1_3.c, t2_3.a, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+ 2000 | 0 | 0000 | 2000 | 0 | 0000
+ 2100 | 100 | 0100 | 2100 | 100 | 0100
+ 2200 | 200 | 0200 | 2200 | 200 | 0200
+ 2300 | 300 | 0300 | 2300 | 300 | 0300
+ 2400 | 400 | 0400 | 2400 | 400 | 0400
+ 2500 | 500 | 0500 | 2500 | 500 | 0500
+ 2600 | 600 | 0600 | 2600 | 600 | 0600
+ 2700 | 700 | 0700 | 2700 | 700 | 0700
+ 2800 | 800 | 0800 | 2800 | 800 | 0800
+ 2900 | 900 | 0900 | 2900 | 900 | 0900
+ 3000 | 0 | 0000 | 3000 | 0 | 0000
+ 3100 | 100 | 0100 | 3100 | 100 | 0100
+ 3200 | 200 | 0200 | 3200 | 200 | 0200
+ 3300 | 300 | 0300 | 3300 | 300 | 0300
+ 3400 | 400 | 0400 | 3400 | 400 | 0400
+ 3500 | 500 | 0500 | 3500 | 500 | 0500
+ 3600 | 600 | 0600 | 3600 | 600 | 0600
+ 3700 | 700 | 0700 | 3700 | 700 | 0700
+ 3800 | 800 | 0800 | 3800 | 800 | 0800
+ 3900 | 900 | 0900 | 3900 | 900 | 0900
+(30 rows)
+
+DELETE FROM join_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, ('AAA'::text || t1_1.c), t2_1.a, t2_1.b, ('AAA'::text || t2_1.c)
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, ('AAA'::text || t1_2.c), t2_2.a, t2_2.b, ('AAA'::text || t2_2.c)
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, ('AAA'::text || t1_3.c), t2_3.a, t2_3.b, ('AAA'::text || t2_3.c)
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+---------+------+-----+---------
+ 1000 | 0 | AAA0000 | 1000 | 0 | AAA0000
+ 1100 | 100 | AAA0100 | 1100 | 100 | AAA0100
+ 1200 | 200 | AAA0200 | 1200 | 200 | AAA0200
+ 1300 | 300 | AAA0300 | 1300 | 300 | AAA0300
+ 1400 | 400 | AAA0400 | 1400 | 400 | AAA0400
+ 1500 | 500 | AAA0500 | 1500 | 500 | AAA0500
+ 1600 | 600 | AAA0600 | 1600 | 600 | AAA0600
+ 1700 | 700 | AAA0700 | 1700 | 700 | AAA0700
+ 1800 | 800 | AAA0800 | 1800 | 800 | AAA0800
+ 1900 | 900 | AAA0900 | 1900 | 900 | AAA0900
+ 2000 | 0 | AAA0000 | 2000 | 0 | AAA0000
+ 2100 | 100 | AAA0100 | 2100 | 100 | AAA0100
+ 2200 | 200 | AAA0200 | 2200 | 200 | AAA0200
+ 2300 | 300 | AAA0300 | 2300 | 300 | AAA0300
+ 2400 | 400 | AAA0400 | 2400 | 400 | AAA0400
+ 2500 | 500 | AAA0500 | 2500 | 500 | AAA0500
+ 2600 | 600 | AAA0600 | 2600 | 600 | AAA0600
+ 2700 | 700 | AAA0700 | 2700 | 700 | AAA0700
+ 2800 | 800 | AAA0800 | 2800 | 800 | AAA0800
+ 2900 | 900 | AAA0900 | 2900 | 900 | AAA0900
+ 3000 | 0 | AAA0000 | 3000 | 0 | AAA0000
+ 3100 | 100 | AAA0100 | 3100 | 100 | AAA0100
+ 3200 | 200 | AAA0200 | 3200 | 200 | AAA0200
+ 3300 | 300 | AAA0300 | 3300 | 300 | AAA0300
+ 3400 | 400 | AAA0400 | 3400 | 400 | AAA0400
+ 3500 | 500 | AAA0500 | 3500 | 500 | AAA0500
+ 3600 | 600 | AAA0600 | 3600 | 600 | AAA0600
+ 3700 | 700 | AAA0700 | 3700 | 700 | AAA0700
+ 3800 | 800 | AAA0800 | 3800 | 800 | AAA0800
+ 3900 | 900 | AAA0900 | 3900 | 900 | AAA0900
+(30 rows)
+
+DELETE FROM join_tbl;
+RESET enable_partitionwise_join;
+-- Test rescan of an async Append node with do_exec_prune=false
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: ((t1.a = t2.a) AND (t1.b = t2.b))
+ -> Foreign Scan on public.async_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t2_1
+ Output: t2_1.a, t2_1.b, t2_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t2_2
+ Output: t2_2.a, t2_2.b, t2_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+(16 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+(10 rows)
+
+DELETE FROM join_tbl;
+RESET enable_hashjoin;
+-- Test interaction of async execution with plan-time partition pruning
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 3000;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(7 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 2000;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Foreign Scan on public.async_p1 async_pt
+ Output: async_pt.a, async_pt.b, async_pt.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 2000))
+(3 rows)
+
+-- Test interaction of async execution with run-time partition pruning
+SET plan_cache_mode TO force_generic_plan;
+PREPARE async_pt_query (int, int) AS
+ INSERT INTO result_tbl SELECT * FROM async_pt WHERE a < $1 AND b === $2;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (3000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 1
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < $1::integer))
+(11 rows)
+
+EXECUTE async_pt_query (3000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (2000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 2
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+(7 rows)
+
+EXECUTE async_pt_query (2000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+(1 row)
+
+DELETE FROM result_tbl;
+RESET plan_cache_mode;
+CREATE TABLE local_tbl(a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo'), (2505, 505, 'bar');
+ANALYZE local_tbl;
+CREATE INDEX base_tbl1_idx ON base_tbl1 (a);
+CREATE INDEX base_tbl2_idx ON base_tbl2 (a);
+CREATE INDEX async_p3_idx ON async_p3 (a);
+ANALYZE base_tbl1;
+ANALYZE base_tbl2;
+ANALYZE async_p3;
+ALTER FOREIGN TABLE async_p1 OPTIONS (use_remote_estimate 'true');
+ALTER FOREIGN TABLE async_p2 OPTIONS (use_remote_estimate 'true');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: local_tbl.a, local_tbl.b, local_tbl.c, async_pt.a, async_pt.b, async_pt.c
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ Filter: (local_tbl.c = 'bar'::text)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a = $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a = $1::integer))
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.a = local_tbl.a)
+(15 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Nested Loop (actual rows=1 loops=1)
+ -> Seq Scan on local_tbl (actual rows=1 loops=1)
+ Filter: (c = 'bar'::text)
+ Rows Removed by Filter: 1
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (never executed)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=1 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (never executed)
+ Filter: (a = local_tbl.a)
+(9 rows)
+
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ a | b | c | a | b | c
+------+-----+-----+------+-----+------
+ 2505 | 505 | bar | 2505 | 505 | 0505
+(1 row)
+
+ALTER FOREIGN TABLE async_p1 OPTIONS (DROP use_remote_estimate);
+ALTER FOREIGN TABLE async_p2 OPTIONS (DROP use_remote_estimate);
+DROP TABLE local_tbl;
+DROP INDEX base_tbl1_idx;
+DROP INDEX base_tbl2_idx;
+DROP INDEX async_p3_idx;
+-- UNION queries
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> HashAggregate
+ Output: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ Group Key: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(11 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(8 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+-- Disable async execution if we use gating Result nodes for pseudoconstant
+-- quals
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Result
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+(18 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+(SELECT * FROM async_p1 WHERE CURRENT_USER = SESSION_USER)
+UNION ALL
+(SELECT * FROM async_p2 WHERE CURRENT_USER = SESSION_USER);
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(13 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ((SELECT * FROM async_p1 WHERE b < 10) UNION ALL (SELECT * FROM async_p2 WHERE b < 10)) s WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((b < 10))
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(13 rows)
+
+-- Test that pending requests are processed properly
+SET enable_mergejoin TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: (t1.a = t2.a)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+ -> Materialize
+ Output: t2.a, t2.b, t2.c
+ -> Foreign Scan on public.async_p2 t2
+ Output: t2.a, t2.b, t2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(20 rows)
+
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ a | b | c | a | b | c
+------+-----+------+------+-----+------
+ 2505 | 505 | 0505 | 2505 | 505 | 0505
+(1 row)
+
+CREATE TABLE local_tbl (a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo');
+ANALYZE local_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, async_pt.a, async_pt.b, async_pt.c, ($0)
+ Join Filter: (t1.a = async_pt.a)
+ InitPlan 1 (returns $0)
+ -> Aggregate
+ Output: count(*)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_4
+ Remote SQL: SELECT NULL FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_5
+ Remote SQL: SELECT NULL FROM public.base_tbl2 WHERE ((a < 3000))
+ -> Seq Scan on public.local_tbl t1
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(20 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Nested Loop Left Join (actual rows=1 loops=1)
+ Join Filter: (t1.a = async_pt.a)
+ Rows Removed by Join Filter: 399
+ InitPlan 1 (returns $0)
+ -> Aggregate (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_4 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_5 (actual rows=200 loops=1)
+ -> Seq Scan on local_tbl t1 (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=200 loops=1)
+(12 rows)
+
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ a | b | c | a | b | c | count
+------+-----+-----+------+-----+------+-------
+ 1505 | 505 | foo | 1505 | 505 | 0505 | 400
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+----------------------------------------------------------------
+ Limit
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+(14 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit (actual rows=1 loops=1)
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 t1_1 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Async Foreign Scan on async_p2 t1_2 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Seq Scan on async_p3 t1_3 (actual rows=1 loops=1)
+ Filter: (b === 505)
+ Rows Removed by Filter: 101
+(9 rows)
+
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ a | b | c
+------+-----+------
+ 3505 | 505 | 0505
+(1 row)
+
+-- Check with foreign modify
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE remote_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl3');
+INSERT INTO remote_tbl VALUES (2505, 505, 'bar');
+CREATE TABLE base_tbl4 (a int, b int, c text);
+CREATE FOREIGN TABLE insert_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl4');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Insert on public.insert_tbl
+ Remote SQL: INSERT INTO public.base_tbl4(a, b, c) VALUES ($1, $2, $3)
+ Batch Size: 1
+ -> Append
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ -> Async Foreign Scan on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(9 rows)
+
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+SELECT * FROM insert_tbl ORDER BY a;
+ a | b | c
+------+-----+-----
+ 1505 | 505 | foo
+ 2505 | 505 | bar
+(2 rows)
+
+-- Check with direct modify
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ CTE t
+ -> Update on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ -> Foreign Update on public.remote_tbl
+ Remote SQL: UPDATE public.base_tbl3 SET c = (c || c) RETURNING a, b, c
+ -> Nested Loop Left Join
+ Output: async_pt.a, async_pt.b, async_pt.c, t.a, t.b, t.c
+ Join Filter: ((async_pt.a = t.a) AND (async_pt.b = t.b))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ -> CTE Scan on t
+ Output: t.a, t.b, t.c
+(23 rows)
+
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+--------
+ 1505 | 505 | 0505 | | |
+ 2505 | 505 | 0505 | 2505 | 505 | barbar
+ 3505 | 505 | 0505 | | |
+(3 rows)
+
+DELETE FROM join_tbl;
+DROP TABLE local_tbl;
+DROP FOREIGN TABLE remote_tbl;
+DROP FOREIGN TABLE insert_tbl;
+DROP TABLE base_tbl3;
+DROP TABLE base_tbl4;
+RESET enable_mergejoin;
+RESET enable_hashjoin;
+-- Test that UPDATE/DELETE with inherited target works with async_capable enabled
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Update on public.async_p1 async_pt_1
+ Foreign Update on public.async_p2 async_pt_2
+ Update on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Update on public.async_p1 async_pt_1
+ Remote SQL: UPDATE public.base_tbl1 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Update on public.async_p2 async_pt_2
+ Remote SQL: UPDATE public.base_tbl2 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: (async_pt_3.c || async_pt_3.c), async_pt_3.tableoid, async_pt_3.ctid, NULL::record
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Delete on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Delete on public.async_p1 async_pt_1
+ Foreign Delete on public.async_p2 async_pt_2
+ Delete on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Delete on public.async_p1 async_pt_1
+ Remote SQL: DELETE FROM public.base_tbl1 WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Delete on public.async_p2 async_pt_2
+ Remote SQL: DELETE FROM public.base_tbl2 WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.tableoid, async_pt_3.ctid
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+-- Check EXPLAIN ANALYZE for a query that scans empty partitions asynchronously
+DELETE FROM async_p1;
+DELETE FROM async_p2;
+DELETE FROM async_p3;
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Append (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=0 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (actual rows=0 loops=1)
+(4 rows)
+
+-- Clean up
+DROP TABLE async_pt;
+DROP TABLE base_tbl1;
+DROP TABLE base_tbl2;
+DROP TABLE result_tbl;
+DROP TABLE join_tbl;
+-- Test that an asynchronous fetch is processed before restarting the scan in
+-- ReScanForeignScan
+CREATE TABLE base_tbl (a int, b int);
+INSERT INTO base_tbl VALUES (1, 11), (2, 22), (3, 33);
+CREATE FOREIGN TABLE foreign_tbl (b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE FOREIGN TABLE foreign_tbl2 () INHERITS (foreign_tbl)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Seq Scan on public.base_tbl
+ Output: base_tbl.a
+ Filter: (SubPlan 1)
+ SubPlan 1
+ -> Result
+ Output: base_tbl.a
+ -> Append
+ -> Async Foreign Scan on public.foreign_tbl foreign_tbl_1
+ Remote SQL: SELECT NULL FROM public.base_tbl
+ -> Async Foreign Scan on public.foreign_tbl2 foreign_tbl_2
+ Remote SQL: SELECT NULL FROM public.base_tbl
+(11 rows)
+
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ a
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+-- Clean up
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to foreign table foreign_tbl2
+DROP TABLE base_tbl;
+ALTER SERVER loopback OPTIONS (DROP async_capable);
+ALTER SERVER loopback2 OPTIONS (DROP async_capable);
+-- ===================================================================
+-- test invalid server, foreign table and foreign data wrapper options
+-- ===================================================================
+-- Invalid fdw_startup_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_startup_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_startup_cost": 100$%$#$#
+-- Invalid fdw_tuple_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_tuple_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_tuple_cost": 100$%$#$#
+-- Invalid fetch_size option
+CREATE FOREIGN TABLE inv_fsz (c1 int )
+ SERVER loopback OPTIONS (fetch_size '100$%$#$#');
+ERROR: invalid value for integer option "fetch_size": 100$%$#$#
+-- Invalid batch_size option
+CREATE FOREIGN TABLE inv_bsz (c1 int )
+ SERVER loopback OPTIONS (batch_size '100$%$#$#');
+ERROR: invalid value for integer option "batch_size": 100$%$#$#
+-- No option is allowed to be specified at foreign data wrapper level
+ALTER FOREIGN DATA WRAPPER postgres_fdw OPTIONS (nonexistent 'fdw');
+ERROR: invalid option "nonexistent"
+HINT: There are no valid options in this context.
+-- ===================================================================
+-- test postgres_fdw.application_name GUC
+-- ===================================================================
+--- Turn debug_discard_caches off for this test to make sure that
+--- the remote connection is alive when checking its application_name.
+SET debug_discard_caches = 0;
+-- Specify escape sequences in application_name option of a server
+-- object so as to test that they are replaced with status information
+-- expectedly.
+--
+-- Since pg_stat_activity.application_name may be truncated to less than
+-- NAMEDATALEN characters, note that substring() needs to be used
+-- at the condition of test query to make sure that the string consisting
+-- of database name and process ID is also less than that.
+ALTER SERVER loopback2 OPTIONS (application_name 'fdw_%d%p');
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_database() || pg_backend_pid() for
+ current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- postgres_fdw.application_name overrides application_name option
+-- of a server object if both settings are present.
+SET postgres_fdw.application_name TO 'fdw_%a%u%%';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('application_name') ||
+ CURRENT_USER || '%' for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- Test %c (session ID) and %C (cluster name) escape sequences.
+SET postgres_fdw.application_name TO 'fdw_%C%c';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('cluster_name') ||
+ to_hex(trunc(EXTRACT(EPOCH FROM (SELECT backend_start FROM
+ pg_stat_get_activity(pg_backend_pid()))))::integer) || '.' ||
+ to_hex(pg_backend_pid())
+ for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+--Clean up
+RESET postgres_fdw.application_name;
+RESET debug_discard_caches;
+-- ===================================================================
+-- test parallel commit
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (ADD parallel_commit 'true');
+ALTER SERVER loopback2 OPTIONS (ADD parallel_commit 'true');
+CREATE TABLE ploc1 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem1 (f1 int, f2 text)
+ SERVER loopback OPTIONS (table_name 'ploc1');
+CREATE TABLE ploc2 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem2 (f1 int, f2 text)
+ SERVER loopback2 OPTIONS (table_name 'ploc2');
+BEGIN;
+INSERT INTO prem1 VALUES (101, 'foo');
+INSERT INTO prem2 VALUES (201, 'bar');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+-----
+ 101 | foo
+(1 row)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+-----
+ 201 | bar
+(1 row)
+
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (102, 'foofoo');
+INSERT INTO prem2 VALUES (202, 'barbar');
+RELEASE SAVEPOINT s;
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+(2 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+(2 rows)
+
+-- This tests executing DEALLOCATE ALL against foreign servers in parallel
+-- during pre-commit
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (103, 'baz');
+INSERT INTO prem2 VALUES (203, 'qux');
+ROLLBACK TO SAVEPOINT s;
+RELEASE SAVEPOINT s;
+INSERT INTO prem1 VALUES (104, 'bazbaz');
+INSERT INTO prem2 VALUES (204, 'quxqux');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+ 104 | bazbaz
+(3 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+ 204 | quxqux
+(3 rows)
+
+ALTER SERVER loopback OPTIONS (DROP parallel_commit);
+ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- execute check function. This should return false on supported platforms,
+-- otherwise return true.
+SELECT postgres_fdw_verify_connection_states('loopback');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+(1 row)
+
+ABORT;
+WARNING: 08006
+\set VERBOSITY default
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index bfcac4ea14..bd7f249f25 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3876,3 +3876,33 @@ SELECT * FROM prem2;
ALTER SERVER loopback OPTIONS (DROP parallel_commit);
ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+-- execute check function. This should return false on supported platforms,
+-- otherwise return true.
+SELECT postgres_fdw_verify_connection_states('loopback');
+ABORT;
+
+\set VERBOSITY default
+
+-- Clean up
+RESET debug_discard_caches;
--
2.27.0
On Tue, 20 Dec 2022 at 07:22, Hayato Kuroda (Fujitsu)
<kuroda.hayato@fujitsu.com> wrote:
Dear hackers,
PSA rebased patches.
The patch does not apply on top of HEAD as in [1]http://cfbot.cputube.org/patch_41_3388.log, please post a rebased patch:
=== Applying patches on top of PostgreSQL commit ID
92957ed98c5c565362ce665266132a7f08f6b0c0 ===
=== applying patch ./v21-0003-add-test.patch
patching file contrib/postgres_fdw/expected/postgres_fdw.out
Hunk #1 FAILED at 11701.
1 out of 1 hunk FAILED -- saving rejects to file
contrib/postgres_fdw/expected/postgres_fdw.out.rej
patching file contrib/postgres_fdw/expected/postgres_fdw_1.out
patching file contrib/postgres_fdw/sql/postgres_fdw.sql
Hunk #1 FAILED at 3876.
1 out of 1 hunk FAILED -- saving rejects to file
contrib/postgres_fdw/sql/postgres_fdw.sql.rej
[1]: http://cfbot.cputube.org/patch_41_3388.log
Regards,
Vignesh
Dear Vignesh,
Thanks for reporting. PSA rebased version.
These can be applied work well on my HEAD(bd8d45).
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v22-0001-Add-PQConncheck-to-libpq.patchapplication/octet-stream; name=v22-0001-Add-PQConncheck-to-libpq.patchDownload
From 46463139a9f70bf475861175a8ff76729ebd879b Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:20 +0000
Subject: [PATCH v22 1/3] Add PQConncheck to libpq
This new libpq function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
---
doc/src/sgml/libpq.sgml | 24 ++++++++++++++++++
src/interfaces/libpq/exports.txt | 1 +
src/interfaces/libpq/fe-misc.c | 42 ++++++++++++++++++++++++++++++++
src/interfaces/libpq/libpq-fe.h | 3 +++
4 files changed, 70 insertions(+)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 0e7ae70c70..513cf4505e 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,30 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQConncheck">
+ <term><function>PQConncheck</function><indexterm><primary>PQConncheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQConncheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQConncheck"/> returns <literal>1</literal>
+ if the remote peer seems to be closed, returns <literal>0</literal> if
+ the socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..3c4f946b51 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,4 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQConncheck 187
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..ea52ab9379 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -1218,6 +1218,48 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Helper function for PQconncheck().
+ *
+ * Return >0 if opposite side seems to be disconnected.
+ */
+static int
+pqConncheck_internal(int sock)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ struct pollfd input_fd;
+ int errflags = POLLHUP | POLLERR | POLLNVAL;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP | errflags;
+ input_fd.revents = 0;
+
+ poll(&input_fd, 1, 0);
+
+ return input_fd.revents;
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad.
+ */
+int
+PQConncheck(PGconn *conn)
+{
+ /* quick exit if invalid connection has come */
+ if (conn == NULL ||
+ conn->sock == PGINVALID_SOCKET ||
+ conn->status != CONNECTION_OK)
+ return -1;
+
+ return pqConncheck_internal(conn->sock);
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..bc9d1ae972 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,9 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQConncheck(PGconn *conn);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v22-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v22-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From 6e619a367d7d0c079b6f087064045a0300ff2666 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:42 +0000
Subject: [PATCH v22 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQConncheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if checked connection is still valid, or the checking is
not supported on this platform. False is returned if the connection seems
to be closed.
---
contrib/postgres_fdw/connection.c | 100 ++++++++++++++++++
.../postgres_fdw/postgres_fdw--1.0--1.1.sql | 10 ++
doc/src/sgml/postgres-fdw.sgml | 49 +++++++++
3 files changed, 159 insertions(+)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index ed75ce3f79..94890f312b 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -86,6 +86,8 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -116,6 +118,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1862,3 +1865,100 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+
+ /* quick exit if connection cache has been not initialized yet. */
+ if (!ConnectionHash)
+ return true;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQConncheck(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so throw ereport(WARNING).
+ */
+ ForeignServer *server;
+
+ server = GetForeignServer(entry->serverid);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("could not connect to server \"%s\"",
+ server->servername),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of the server.")));
+
+ result = false;
+ }
+ }
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found, and this returns
+ * false only when the verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
diff --git a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
index ed4ca378d4..f1e2ee442f 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
@@ -18,3 +18,13 @@ CREATE FUNCTION postgres_fdw_disconnect_all ()
RETURNS bool
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 78f2d7d8d5..6c9bd3b40e 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -825,6 +825,55 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if a checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports that
+ the connection is closed. This function is currently available only on
+ systems that support the non-standard <symbol>POLLRDHUP</symbol> extension
+ to the <symbol>poll</symbol> system call, including Linux. This returns
+ <literal>true</literal> if a lastly checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
</variablelist>
</sect2>
--
2.27.0
v22-0003-add-test.patchapplication/octet-stream; name=v22-0003-add-test.patchDownload
From b935e4031f8621a16aedacf2d3b684fd2c13670f Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v22 3/3] add test
Note that this test has two comparison files. Alternative comparison file is needed
because some platforms like Windows cannot check the status of the socket.
---
.../postgres_fdw/expected/postgres_fdw.out | 44 +
.../postgres_fdw/expected/postgres_fdw_1.out | 11849 ++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 30 +
3 files changed, 11923 insertions(+)
create mode 100644 contrib/postgres_fdw/expected/postgres_fdw_1.out
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index c0267a99d2..44db8fa0ec 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11804,3 +11804,47 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- execute check function. This should return false on supported platforms,
+-- otherwise return true.
+SELECT postgres_fdw_verify_connection_states('loopback');
+WARNING: 08006
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ f
+(1 row)
+
+ABORT;
+WARNING: 08006
+\set VERBOSITY default
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/expected/postgres_fdw_1.out b/contrib/postgres_fdw/expected/postgres_fdw_1.out
new file mode 100644
index 0000000000..ca472af917
--- /dev/null
+++ b/contrib/postgres_fdw/expected/postgres_fdw_1.out
@@ -0,0 +1,11849 @@
+-- ===================================================================
+-- create FDW objects
+-- ===================================================================
+CREATE EXTENSION postgres_fdw;
+CREATE SERVER testserver1 FOREIGN DATA WRAPPER postgres_fdw;
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback2 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ EXECUTE $$CREATE SERVER loopback3 FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+CREATE USER MAPPING FOR public SERVER testserver1
+ OPTIONS (user 'value', password 'value');
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback2;
+CREATE USER MAPPING FOR public SERVER loopback3;
+-- ===================================================================
+-- create objects used through FDW loopback server
+-- ===================================================================
+CREATE TYPE user_enum AS ENUM ('foo', 'bar', 'buz');
+CREATE SCHEMA "S 1";
+CREATE TABLE "S 1"."T 1" (
+ "C 1" int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10),
+ c8 user_enum,
+ CONSTRAINT t1_pkey PRIMARY KEY ("C 1")
+);
+CREATE TABLE "S 1"."T 2" (
+ c1 int NOT NULL,
+ c2 text,
+ CONSTRAINT t2_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 3" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t3_pkey PRIMARY KEY (c1)
+);
+CREATE TABLE "S 1"."T 4" (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ CONSTRAINT t4_pkey PRIMARY KEY (c1)
+);
+-- Disable autovacuum for these tables to avoid unexpected effects of that
+ALTER TABLE "S 1"."T 1" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 2" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 3" SET (autovacuum_enabled = 'false');
+ALTER TABLE "S 1"."T 4" SET (autovacuum_enabled = 'false');
+INSERT INTO "S 1"."T 1"
+ SELECT id,
+ id % 10,
+ to_char(id, 'FM00000'),
+ '1970-01-01'::timestamptz + ((id % 100) || ' days')::interval,
+ '1970-01-01'::timestamp + ((id % 100) || ' days')::interval,
+ id % 10,
+ id % 10,
+ 'foo'::user_enum
+ FROM generate_series(1, 1000) id;
+INSERT INTO "S 1"."T 2"
+ SELECT id,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+INSERT INTO "S 1"."T 3"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 3" WHERE c1 % 2 != 0; -- delete for outer join tests
+INSERT INTO "S 1"."T 4"
+ SELECT id,
+ id + 1,
+ 'AAA' || to_char(id, 'FM000')
+ FROM generate_series(1, 100) id;
+DELETE FROM "S 1"."T 4" WHERE c1 % 3 != 0; -- delete for outer join tests
+ANALYZE "S 1"."T 1";
+ANALYZE "S 1"."T 2";
+ANALYZE "S 1"."T 3";
+ANALYZE "S 1"."T 4";
+-- ===================================================================
+-- create foreign tables
+-- ===================================================================
+CREATE FOREIGN TABLE ft1 (
+ c0 int,
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft1 DROP COLUMN c0;
+CREATE FOREIGN TABLE ft2 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ cx int,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft2',
+ c8 user_enum
+) SERVER loopback;
+ALTER FOREIGN TABLE ft2 DROP COLUMN cx;
+CREATE FOREIGN TABLE ft4 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 3');
+CREATE FOREIGN TABLE ft5 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft6 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback2 OPTIONS (schema_name 'S 1', table_name 'T 4');
+CREATE FOREIGN TABLE ft7 (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text
+) SERVER loopback3 OPTIONS (schema_name 'S 1', table_name 'T 4');
+-- ===================================================================
+-- tests for validator
+-- ===================================================================
+-- requiressl and some other parameters are omitted because
+-- valid values for them depend on configure options
+ALTER SERVER testserver1 OPTIONS (
+ use_remote_estimate 'false',
+ updatable 'true',
+ fdw_startup_cost '123.456',
+ fdw_tuple_cost '0.123',
+ service 'value',
+ connect_timeout 'value',
+ dbname 'value',
+ host 'value',
+ hostaddr 'value',
+ port 'value',
+ --client_encoding 'value',
+ application_name 'value',
+ --fallback_application_name 'value',
+ keepalives 'value',
+ keepalives_idle 'value',
+ keepalives_interval 'value',
+ tcp_user_timeout 'value',
+ -- requiressl 'value',
+ sslcompression 'value',
+ sslmode 'value',
+ sslcert 'value',
+ sslkey 'value',
+ sslrootcert 'value',
+ sslcrl 'value',
+ --requirepeer 'value',
+ krbsrvname 'value',
+ gsslib 'value'
+ --replication 'value'
+);
+-- Error, invalid list syntax
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo; bar');
+ERROR: parameter "extensions" must be a list of extension names
+-- OK but gets a warning
+ALTER SERVER testserver1 OPTIONS (ADD extensions 'foo, bar');
+WARNING: extension "foo" is not installed
+WARNING: extension "bar" is not installed
+ALTER SERVER testserver1 OPTIONS (DROP extensions);
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (DROP user, DROP password);
+-- Attempt to add a valid option that's not allowed in a user mapping
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslmode 'require');
+ERROR: invalid option "sslmode"
+-- But we can add valid ones fine
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslpassword 'dummy');
+-- Ensure valid options we haven't used in a user mapping yet are
+-- permitted to check validation.
+ALTER USER MAPPING FOR public SERVER testserver1
+ OPTIONS (ADD sslkey 'value', ADD sslcert 'value');
+ALTER FOREIGN TABLE ft1 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft2 OPTIONS (schema_name 'S 1', table_name 'T 1');
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+ALTER FOREIGN TABLE ft2 ALTER COLUMN c1 OPTIONS (column_name 'C 1');
+\det+
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------+-------+-----------+---------------------------------------+-------------
+ public | ft1 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft2 | loopback | (schema_name 'S 1', table_name 'T 1') |
+ public | ft4 | loopback | (schema_name 'S 1', table_name 'T 3') |
+ public | ft5 | loopback | (schema_name 'S 1', table_name 'T 4') |
+ public | ft6 | loopback2 | (schema_name 'S 1', table_name 'T 4') |
+ public | ft7 | loopback3 | (schema_name 'S 1', table_name 'T 4') |
+(6 rows)
+
+-- Test that alteration of server options causes reconnection
+-- Remote's errors might be non-English, so hide them to ensure stable results
+\set VERBOSITY terse
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET dbname 'no such database');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+DO $d$
+ BEGIN
+ EXECUTE $$ALTER SERVER loopback
+ OPTIONS (SET dbname '$$||current_database()||$$')$$;
+ END;
+$d$;
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+-- Test that alteration of user mapping options causes reconnection
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (ADD user 'no such user');
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should fail
+ERROR: could not connect to server "loopback"
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback
+ OPTIONS (DROP user);
+SELECT c3, c4 FROM ft1 ORDER BY c3, c1 LIMIT 1; -- should work again
+ c3 | c4
+-------+------------------------------
+ 00001 | Fri Jan 02 00:00:00 1970 PST
+(1 row)
+
+\set VERBOSITY default
+-- Now we should be able to run ANALYZE.
+-- To exercise multiple code paths, we use local stats on ft1
+-- and remote-estimate mode on ft2.
+ANALYZE ft1;
+ALTER FOREIGN TABLE ft2 OPTIONS (use_remote_estimate 'true');
+-- ===================================================================
+-- test error case for create publication on foreign table
+-- ===================================================================
+CREATE PUBLICATION testpub_ftbl FOR TABLE ft1; -- should fail
+ERROR: cannot add relation "ft1" to publication
+DETAIL: This operation is not supported for foreign tables.
+-- ===================================================================
+-- simple queries
+-- ===================================================================
+-- single table without alias
+EXPLAIN (COSTS OFF) SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------
+ Foreign Scan on ft1
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c3, c1 OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- single table with alias - also test that tableoid sort is not pushed to remote side
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ -> Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Sort Key: t1.c3, t1.c1, t1.tableoid
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, tableoid
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(8 rows)
+
+SELECT * FROM ft1 t1 ORDER BY t1.c3, t1.c1, t1.tableoid OFFSET 100 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 103 | 3 | 00103 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 105 | 5 | 00105 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 107 | 7 | 00107 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 109 | 9 | 00109 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF) SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: t1.*, c3, c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c3 ASC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(3 rows)
+
+SELECT t1 FROM ft1 t1 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ t1
+--------------------------------------------------------------------------------------------
+ (101,1,00101,"Fri Jan 02 00:00:00 1970 PST","Fri Jan 02 00:00:00 1970",1,"1 ",foo)
+ (102,2,00102,"Sat Jan 03 00:00:00 1970 PST","Sat Jan 03 00:00:00 1970",2,"2 ",foo)
+ (103,3,00103,"Sun Jan 04 00:00:00 1970 PST","Sun Jan 04 00:00:00 1970",3,"3 ",foo)
+ (104,4,00104,"Mon Jan 05 00:00:00 1970 PST","Mon Jan 05 00:00:00 1970",4,"4 ",foo)
+ (105,5,00105,"Tue Jan 06 00:00:00 1970 PST","Tue Jan 06 00:00:00 1970",5,"5 ",foo)
+ (106,6,00106,"Wed Jan 07 00:00:00 1970 PST","Wed Jan 07 00:00:00 1970",6,"6 ",foo)
+ (107,7,00107,"Thu Jan 08 00:00:00 1970 PST","Thu Jan 08 00:00:00 1970",7,"7 ",foo)
+ (108,8,00108,"Fri Jan 09 00:00:00 1970 PST","Fri Jan 09 00:00:00 1970",8,"8 ",foo)
+ (109,9,00109,"Sat Jan 10 00:00:00 1970 PST","Sat Jan 10 00:00:00 1970",9,"9 ",foo)
+ (110,0,00110,"Sun Jan 11 00:00:00 1970 PST","Sun Jan 11 00:00:00 1970",0,"0 ",foo)
+(10 rows)
+
+-- empty result
+SELECT * FROM ft1 WHERE false;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- with WHERE clause
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c7 >= '1')) AND (("C 1" = 101)) AND ((c6 = '1'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 = 101 AND t1.c6 = '1' AND t1.c7 >= '1';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- with FOR UPDATE/SHARE
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 101)) FOR UPDATE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 101 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, t1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 102)) FOR SHARE
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE c1 = 102 FOR SHARE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 102 | 2 | 00102 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+-- aggregate
+SELECT COUNT(*) FROM ft1 t1;
+ count
+-------
+ 1000
+(1 row)
+
+-- subquery
+SELECT * FROM ft1 t1 WHERE t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 <= 10) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- subquery+MAX
+SELECT * FROM ft1 t1 WHERE t1.c3 = (SELECT MAX(c3) FROM ft2 t2) ORDER BY c1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+(1 row)
+
+-- used in CTE
+WITH t1 AS (SELECT * FROM ft1 WHERE c1 <= 10) SELECT t2.c1, t2.c2, t2.c3, t2.c4 FROM t1, ft2 t2 WHERE t1.c1 = t2.c1 ORDER BY t1.c1;
+ c1 | c2 | c3 | c4
+----+----+-------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+(10 rows)
+
+-- fixed values
+SELECT 'fixed', NULL FROM ft1 t1 WHERE c1 = 1;
+ ?column? | ?column?
+----------+----------
+ fixed |
+(1 row)
+
+-- Test forcing the remote server to produce sorted data for a merge join.
+SET enable_hashjoin TO false;
+SET enable_nestloop TO false;
+-- inner join; expressions in the clauses appear in the equivalence class list
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2."C 1"
+ -> Merge Left Join
+ Output: t1.c1, t2."C 1"
+ Inner Unique: true
+ Merge Cond: (t1.c1 = t2."C 1")
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t2
+ Output: t2."C 1"
+(11 rows)
+
+SELECT t1.c1, t2."C 1" FROM ft2 t1 LEFT JOIN "S 1"."T 1" t2 ON (t1.c1 = t2."C 1") OFFSET 100 LIMIT 10;
+ c1 | C 1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- A join between local table and foreign join. ORDER BY clause is added to the
+-- foreign join so that the local table can be joined using merge join strategy.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Merge Right Join
+ Output: t1."C 1"
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r3."C 1" FROM ("S 1"."T 1" r2 INNER JOIN "S 1"."T 1" r3 ON (((r3."C 1" = r2."C 1")))) ORDER BY r2."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1 left join ft1 t2 join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- Test similar to above, except that the full join prevents any equivalence
+-- classes from being merged. This produces single relation equivalence classes
+-- included in join restrictions.
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Right Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t3.c1, t2.c1
+ Relations: (public.ft2 t3) LEFT JOIN (public.ft1 t2)
+ Remote SQL: SELECT r3."C 1", r2."C 1" FROM ("S 1"."T 1" r3 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 left join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+-- Test similar to above with all full outer joins
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1", t2.c1, t3.c1
+ -> Merge Full Join
+ Output: t1."C 1", t2.c1, t3.c1
+ Inner Unique: true
+ Merge Cond: (t3.c1 = t1."C 1")
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) FULL JOIN (public.ft2 t3)
+ Remote SQL: SELECT r2."C 1", r3."C 1" FROM ("S 1"."T 1" r2 FULL JOIN "S 1"."T 1" r3 ON (((r2."C 1" = r3."C 1")))) ORDER BY r3."C 1" ASC NULLS LAST
+ -> Index Only Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1"
+(12 rows)
+
+SELECT t1."C 1", t2.c1, t3.c1 FROM "S 1"."T 1" t1 full join ft1 t2 full join ft2 t3 on (t2.c1 = t3.c1) on (t3.c1 = t1."C 1") OFFSET 100 LIMIT 10;
+ C 1 | c1 | c1
+-----+-----+-----
+ 101 | 101 | 101
+ 102 | 102 | 102
+ 103 | 103 | 103
+ 104 | 104 | 104
+ 105 | 105 | 105
+ 106 | 106 | 106
+ 107 | 107 | 107
+ 108 | 108 | 108
+ 109 | 109 | 109
+ 110 | 110 | 110
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test executing assertion in estimate_path_cost_size() that makes sure that
+-- retrieved_rows for foreign rel re-used to cost pre-sorted foreign paths is
+-- a sensible value even when the rel has tuples=0
+CREATE TABLE loct_empty (c1 int NOT NULL, c2 text);
+CREATE FOREIGN TABLE ft_empty (c1 int NOT NULL, c2 text)
+ SERVER loopback OPTIONS (table_name 'loct_empty');
+INSERT INTO loct_empty
+ SELECT id, 'AAA' || to_char(id, 'FM000') FROM generate_series(1, 100) id;
+DELETE FROM loct_empty;
+ANALYZE ft_empty;
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft_empty ORDER BY c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Foreign Scan on public.ft_empty
+ Output: c1, c2
+ Remote SQL: SELECT c1, c2 FROM public.loct_empty ORDER BY c1 ASC NULLS LAST
+(3 rows)
+
+-- ===================================================================
+-- WHERE with remotely-executable conditions
+-- ===================================================================
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 1; -- Var, OpExpr(b), Const
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE t1.c1 = 100 AND t1.c2 = 0; -- BoolExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 100)) AND ((c2 = 0))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NULL; -- NullTest
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 IS NOT NULL; -- NullTest
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" IS NOT NULL))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE round(abs(c1), 0) = 1; -- FuncExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((round(abs("C 1"), 0) = 1::numeric))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = -c1; -- OpExpr(l)
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = (- "C 1")))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE (c1 IS NOT NULL) IS DISTINCT FROM (c1 IS NOT NULL); -- DistinctExpr
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((("C 1" IS NOT NULL) IS DISTINCT FROM ("C 1" IS NOT NULL)))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = ANY(ARRAY[c2, 1, c1 + 0]); -- ScalarArrayOpExpr
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ANY (ARRAY[c2, 1, ("C 1" + 0)])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c1 = (ARRAY[c1,c2,3])[1]; -- SubscriptingRef
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = ((ARRAY["C 1", c2, 3])[1])))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c6 = E'foo''s\\bar'; -- check special chars
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c6 = E'foo''s\\bar'))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 t1 WHERE c8 = 'foo'; -- can't be sent to remote
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- parameterized remote path for foreign table
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM "S 1"."T 1" a, ft2 b WHERE a."C 1" = 47 AND b.c1 = a.c2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Index Scan using t1_pkey on "S 1"."T 1" a
+ Output: a."C 1", a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Index Cond: (a."C 1" = 47)
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(8 rows)
+
+SELECT * FROM ft2 a, ft2 b WHERE a.c1 = 47 AND b.c1 = a.c2;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 47 | 7 | 00047 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo | 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+(1 row)
+
+-- check both safe and unsafe join conditions
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 a, ft2 b
+ WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8, b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ -> Foreign Scan on public.ft2 a
+ Output: a.c1, a.c2, a.c3, a.c4, a.c5, a.c6, a.c7, a.c8
+ Filter: (a.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c2 = 6))
+ -> Foreign Scan on public.ft2 b
+ Output: b.c1, b.c2, b.c3, b.c4, b.c5, b.c6, b.c7, b.c8
+ Filter: ((b.c7)::text = upper((a.c7)::text))
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(10 rows)
+
+SELECT * FROM ft2 a, ft2 b
+WHERE a.c2 = 6 AND b.c1 = a.c1 AND a.c8 = 'foo' AND b.c7 = upper(a.c7);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo
+(100 rows)
+
+-- bug before 9.3.5 due to sloppy handling of remote-estimate parameters
+SELECT * FROM ft1 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft2 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+SELECT * FROM ft2 WHERE c1 = ANY (ARRAY(SELECT c1 FROM ft1 WHERE c1 < 5));
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+(4 rows)
+
+-- we should not push order by clause with volatile expressions or unsafe
+-- collations
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, random();
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, (random())
+ Sort Key: ft2.c1, (random())
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, random()
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft2 ORDER BY ft2.c1, ft2.c3 collate "C";
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, ((c3)::text)
+ Sort Key: ft2.c1, ft2.c3 COLLATE "C"
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8, c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- user-defined operator/function
+CREATE FUNCTION postgres_fdw_abs(int) RETURNS int AS $$
+BEGIN
+RETURN abs($1);
+END
+$$ LANGUAGE plpgsql IMMUTABLE;
+CREATE OPERATOR === (
+ LEFTARG = int,
+ RIGHTARG = int,
+ PROCEDURE = int4eq,
+ COMMUTATOR = ===
+);
+-- built-in operators and functions can be shipped for remote execution
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ QUERY PLAN
+----------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- by default, user-defined ones cannot
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 = postgres_fdw_abs(t1.c2))
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- ORDER BY can be shipped, though
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- but let's put them in an extension ...
+ALTER EXTENSION postgres_fdw ADD FUNCTION postgres_fdw_abs(int);
+ALTER EXTENSION postgres_fdw ADD OPERATOR === (int, int);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- ... now they can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" = public.postgres_fdw_abs(c2)))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 = postgres_fdw_abs(t1.c2);
+ count
+-------
+ 9
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+ count
+-------
+ 9
+(1 row)
+
+-- and both ORDER BY and LIMIT can be shipped
+EXPLAIN (VERBOSE, COSTS OFF)
+ SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2)) ORDER BY c2 ASC NULLS LAST LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.c1 === t1.c2 order by t1.c2 limit 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- Test CASE pushdown
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE WHEN ("C 1" > 990) THEN "C 1" ELSE NULL::integer END) < 1000)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE WHEN c1 > 990 THEN c1 END < 1000 ORDER BY c1;
+ c1 | c2 | c3
+-----+----+-------
+ 991 | 1 | 00991
+ 992 | 2 | 00992
+ 993 | 3 | 00993
+ 994 | 4 | 00994
+ 995 | 5 | 00995
+ 996 | 6 | 00996
+ 997 | 7 | 00997
+ 998 | 8 | 00998
+ 999 | 9 | 00999
+(9 rows)
+
+-- Nested CASE
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" WHERE (((CASE (CASE WHEN (c2 > 0) THEN c2 ELSE NULL::integer END) WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END) > 600)) ORDER BY "C 1" ASC NULLS LAST
+(3 rows)
+
+SELECT c1,c2,c3 FROM ft2 WHERE CASE CASE WHEN c2 > 0 THEN c2 END WHEN 100 THEN 601 WHEN c2 THEN c2 ELSE 0 END > 600 ORDER BY c1;
+ c1 | c2 | c3
+----+----+----
+(0 rows)
+
+-- CASE arg WHEN
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE mod(c1, 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" > (CASE mod("C 1", 4) WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)))
+(3 rows)
+
+-- CASE cannot be pushed down because of unshippable arg clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c1 > (CASE random()::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (ft1.c1 > CASE (random())::integer WHEN 0 THEN 1 WHEN 2 THEN 50 ELSE 100 END)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- these are shippable
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c6 WHEN 'foo' THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c6 WHEN 'foo'::text THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((CASE c3 WHEN c6 THEN true ELSE (c3 < 'bar') END))
+(3 rows)
+
+-- but this is not because of collation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE CASE c3 COLLATE "C" WHEN c6 THEN true ELSE c3 < 'bar' END;
+ QUERY PLAN
+-------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: CASE (ft1.c3)::text WHEN ft1.c6 THEN true ELSE (ft1.c3 < 'bar'::text) END
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(4 rows)
+
+-- a regconfig constant referring to this text search configuration
+-- is initially unshippable
+CREATE TEXT SEARCH CONFIGURATION public.custom_search
+ (COPY = pg_catalog.english);
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Filter: (length(to_tsvector('custom_search'::regconfig, ft1.c3)) > 0)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642))
+(4 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- but if it's in a shippable extension, it can be shipped
+ALTER EXTENSION postgres_fdw ADD TEXT SEARCH CONFIGURATION public.custom_search;
+-- however, that doesn't flush the shippability cache, so do a quick reconnect
+\c -
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, to_tsvector('custom_search'::regconfig, c3)
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1" WHERE (("C 1" = 642)) AND ((length(to_tsvector('public.custom_search'::regconfig, c3)) > 0))
+(3 rows)
+
+SELECT c1, to_tsvector('custom_search'::regconfig, c3) FROM ft1
+WHERE c1 = 642 AND length(to_tsvector('custom_search'::regconfig, c3)) > 0;
+ c1 | to_tsvector
+-----+-------------
+ 642 | '00642':1
+(1 row)
+
+-- ===================================================================
+-- JOIN queries
+-- ===================================================================
+-- Analyze ft4 and ft5 so that we have better statistics. These tables do not
+-- have use_remote_estimate set.
+ANALYZE ft4;
+ANALYZE ft5;
+-- join two tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3, t1.c3
+ Relations: ((public.ft1 t1) INNER JOIN (public.ft2 t2)) INNER JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3, r1.c3 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) INNER JOIN "S 1"."T 3" r4 ON (((r1."C 1" = r4.c1)))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) JOIN ft4 t3 ON (t3.c1 = t1.c1) ORDER BY t1.c3, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 22 |
+ 24 | 24
+ 26 |
+ 28 |
+ 30 | 30
+ 32 |
+ 34 |
+ 36 | 36
+ 38 |
+ 40 |
+(10 rows)
+
+-- left outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + placement of clauses.
+-- clauses within the nullable side are not pulled up, but top level clause on
+-- non-nullable side is pushed into non-nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1) WHERE t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- clauses within the nullable side are not pulled up, but the top level clause
+-- on nullable side is not pushed down into nullable side
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t1.c2, ft5.c1, ft5.c2
+ Relations: (public.ft4 t1) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r1.c1, r1.c2, r4.c1, r4.c2 FROM ("S 1"."T 3" r1 LEFT JOIN "S 1"."T 4" r4 ON (((r1.c1 = r4.c1)) AND ((r4.c1 < 10)))) WHERE (((r4.c1 < 10) OR (r4.c1 IS NULL))) AND ((r1.c1 < 10))
+(4 rows)
+
+SELECT t1.c1, t1.c2, t2.c1, t2.c2 FROM ft4 t1 LEFT JOIN (SELECT * FROM ft5 WHERE c1 < 10) t2 ON (t1.c1 = t2.c1)
+ WHERE (t2.c1 < 10 OR t2.c1 IS NULL) AND t1.c1 < 10;
+ c1 | c2 | c1 | c2
+----+----+----+----
+ 2 | 3 | |
+ 4 | 5 | |
+ 6 | 7 | 6 | 7
+ 8 | 9 | |
+(4 rows)
+
+-- right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t2) LEFT JOIN (public.ft5 t1)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r1 ON (((r1.c1 = r2.c1)))) ORDER BY r2.c1 ASC NULLS LAST, r1.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 RIGHT JOIN ft4 t2 ON (t1.c1 = t2.c1) ORDER BY t2.c1, t1.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ | 22
+ 24 | 24
+ | 26
+ | 28
+ 30 | 30
+ | 32
+ | 34
+ 36 | 36
+ | 38
+ | 40
+(10 rows)
+
+-- right outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 45::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 45 LIMIT 10;
+ c1 | c1
+-----+----
+ 92 |
+ 94 |
+ 96 | 96
+ 98 |
+ 100 |
+ | 3
+ | 9
+ | 15
+ | 21
+ | 27
+(10 rows)
+
+-- full outer join with restrictions on the joining relations
+-- a. the joining relations are both base relations
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s4.c1, s5.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s5.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1;
+ c1 | c1
+----+----
+ 50 |
+ 52 |
+ 54 | 54
+ 56 |
+ 58 |
+ 60 | 60
+ | 51
+ | 57
+(8 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: 1
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT NULL FROM ((SELECT NULL FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4 FULL JOIN (SELECT NULL FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5 ON (TRUE)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT 1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t2 ON (TRUE) OFFSET 10 LIMIT 10;
+ ?column?
+----------
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- b. one of the joining relations is a base relation and the other is a join
+-- relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c1, t3.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 t2) LEFT JOIN (public.ft5 t3))
+ Remote SQL: SELECT s4.c1, s8.c1, s8.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT r5.c1, r6.c1 FROM ("S 1"."T 3" r5 LEFT JOIN "S 1"."T 4" r6 ON (((r5.c1 = r6.c1)))) WHERE ((r5.c1 >= 50)) AND ((r5.c1 <= 60))) s8(c1, c2) ON (((s4.c1 = s8.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s8.c1 ASC NULLS LAST, s8.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM ft4 t2 LEFT JOIN ft5 t3 ON (t2.c1 = t3.c1) WHERE (t2.c1 between 50 and 60)) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+(6 rows)
+
+-- c. test deparsing the remote query as nested subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft4_1.c1, ft5.c1
+ Relations: (public.ft4) FULL JOIN ((public.ft4 ft4_1) FULL JOIN (public.ft5))
+ Remote SQL: SELECT s4.c1, s10.c1, s10.c2 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT s8.c1, s9.c1 FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL)))) s10(c1, c2) ON (((s4.c1 = s10.c1)))) ORDER BY s4.c1 ASC NULLS LAST, s10.c1 ASC NULLS LAST, s10.c2 ASC NULLS LAST
+(4 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t1 FULL JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (t1.c1 = ss.a) ORDER BY t1.c1, ss.a, ss.b;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 52 | 52 |
+ 54 | 54 | 54
+ 56 | 56 |
+ 58 | 58 |
+ 60 | 60 | 60
+ | | 51
+ | | 57
+(8 rows)
+
+-- d. test deparsing rowmarked relations as subqueries
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Nested Loop
+ Output: "T 3".c1, ft4.c1, ft5.c1, "T 3".ctid, ft4.*, ft5.*
+ -> Foreign Scan
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Relations: (public.ft4) FULL JOIN (public.ft5)
+ Remote SQL: SELECT s8.c1, s8.c2, s9.c1, s9.c2 FROM ((SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s8(c1, c2) FULL JOIN (SELECT c1, ROW(c1, c2, c3) FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s9(c1, c2) ON (((s8.c1 = s9.c1)))) WHERE (((s8.c1 IS NULL) OR (s8.c1 IS NOT NULL))) ORDER BY s8.c1 ASC NULLS LAST, s9.c1 ASC NULLS LAST
+ -> Sort
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Full Join
+ Output: ft4.c1, ft4.*, ft5.c1, ft5.*
+ Hash Cond: (ft4.c1 = ft5.c1)
+ Filter: ((ft4.c1 IS NULL) OR (ft4.c1 IS NOT NULL))
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Hash
+ Output: ft5.c1, ft5.*
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))
+ -> Materialize
+ Output: "T 3".c1, "T 3".ctid
+ -> Seq Scan on "S 1"."T 3"
+ Output: "T 3".c1, "T 3".ctid
+ Filter: ("T 3".c1 = 50)
+(28 rows)
+
+SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNER JOIN (SELECT t2.c1, t3.c1 FROM (SELECT c1 FROM ft4 WHERE c1 between 50 and 60) t2 FULL JOIN (SELECT c1 FROM ft5 WHERE c1 between 50 and 60) t3 ON (t2.c1 = t3.c1) WHERE t2.c1 IS NULL OR t2.c1 IS NOT NULL) ss(a, b) ON (TRUE) ORDER BY t1.c1, ss.a, ss.b FOR UPDATE OF t1;
+ c1 | a | b
+----+----+----
+ 50 | 50 |
+ 50 | 52 |
+ 50 | 54 | 54
+ 50 | 56 |
+ 50 | 58 |
+ 50 | 60 | 60
+ 50 | | 51
+ 50 | | 57
+(8 rows)
+
+-- full outer join + inner join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t3.c1
+ Relations: ((public.ft4 t1) INNER JOIN (public.ft5 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1.c1, r2.c1, r4.c1 FROM (("S 1"."T 3" r1 INNER JOIN "S 1"."T 4" r2 ON (((r1.c1 = (r2.c1 + 1))) AND ((r1.c1 >= 50)) AND ((r1.c1 <= 60)))) FULL JOIN "S 1"."T 3" r4 ON (((r2.c1 = r4.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST, r4.c1 ASC NULLS LAST LIMIT 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10;
+ c1 | c1 | c1
+----+----+----
+ 52 | 51 |
+ 58 | 57 |
+ | | 2
+ | | 4
+ | | 6
+ | | 8
+ | | 10
+ | | 12
+ | | 14
+ | | 16
+(10 rows)
+
+-- full outer join three tables
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft4 t3) LEFT JOIN (public.ft2 t2)) LEFT JOIN (public.ft2 t1)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 3" r4 LEFT JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r4.c1)))) LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- right outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- full outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) FULL JOIN (public.ft2 t2)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+-- left outer join + full outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t1) LEFT JOIN (public.ft2 t2)) FULL JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r1 LEFT JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) FULL JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+SET enable_memoize TO off;
+-- right outer join + left outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: ((public.ft2 t2) LEFT JOIN (public.ft2 t1)) LEFT JOIN (public.ft4 t3)
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM (("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1")))) LEFT JOIN "S 1"."T 3" r4 ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 RIGHT JOIN ft2 t2 ON (t1.c1 = t2.c1) LEFT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 11 | 1 |
+ 12 | 2 | AAA012
+ 13 | 3 |
+ 14 | 4 | AAA014
+ 15 | 5 |
+ 16 | 6 | AAA016
+ 17 | 7 |
+ 18 | 8 | AAA018
+ 19 | 9 |
+ 20 | 0 | AAA020
+(10 rows)
+
+RESET enable_memoize;
+-- left outer join + right outer join
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t3.c3
+ Relations: (public.ft4 t3) LEFT JOIN ((public.ft2 t1) INNER JOIN (public.ft2 t2))
+ Remote SQL: SELECT r1."C 1", r2.c2, r4.c3 FROM ("S 1"."T 3" r4 LEFT JOIN ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) ON (((r2."C 1" = r4.c1)))) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2, t3.c3 FROM ft2 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) RIGHT JOIN ft4 t3 ON (t2.c1 = t3.c1) OFFSET 10 LIMIT 10;
+ c1 | c2 | c3
+----+----+--------
+ 22 | 2 | AAA022
+ 24 | 4 | AAA024
+ 26 | 6 | AAA026
+ 28 | 8 | AAA028
+ 30 | 0 | AAA030
+ 32 | 2 | AAA032
+ 34 | 4 | AAA034
+ 36 | 6 | AAA036
+ 38 | 8 | AAA038
+ 40 | 0 | AAA040
+(10 rows)
+
+-- full outer join + WHERE clause, only matched rows
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft4 t1) FULL JOIN (public.ft5 t2)
+ Remote SQL: SELECT r1.c1, r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 = r2.c1) OR (r1.c1 IS NULL)))
+(9 rows)
+
+SELECT t1.c1, t2.c1 FROM ft4 t1 FULL JOIN ft5 t2 ON (t1.c1 = t2.c1) WHERE (t1.c1 = t2.c1 OR t1.c1 IS NULL) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c1
+----+----
+ 66 | 66
+ 72 | 72
+ 78 | 78
+ 84 | 84
+ 90 | 90
+ 96 | 96
+ | 3
+ | 9
+ | 15
+ | 21
+(10 rows)
+
+-- full outer join + WHERE clause with shippable extensions set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")))) WHERE ((public.postgres_fdw_abs(r1."C 1") > 0)) LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+-- full outer join + WHERE clause with shippable extensions not set
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2, t1.c3 FROM ft1 t1 FULL JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE postgres_fdw_abs(t1.c1) > 0 OFFSET 10 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c2, t1.c3
+ -> Foreign Scan
+ Output: t1.c1, t2.c2, t1.c3
+ Filter: (postgres_fdw_abs(t1.c1) > 0)
+ Relations: (public.ft1 t1) FULL JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2.c2, r1.c3 FROM ("S 1"."T 1" r1 FULL JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1"))))
+(7 rows)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- join two tables with FOR UPDATE clause
+-- tests whole-row reference for row marks
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR UPDATE OF r1 FOR UPDATE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR UPDATE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join two tables with FOR SHARE clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE OF t1;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3, t1.*, t2.*
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint FOR SHARE OF r1 FOR SHARE OF r2
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10 FOR SHARE;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join in CTE
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t.c1_1, t.c2_1, t.c1_3
+ CTE t
+ -> Foreign Scan
+ Output: t1.c1, t1.c3, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r1.c3, r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+ -> Sort
+ Output: t.c1_1, t.c2_1, t.c1_3
+ Sort Key: t.c1_3, t.c1_1
+ -> CTE Scan on t
+ Output: t.c1_1, t.c2_1, t.c1_3
+(12 rows)
+
+WITH t (c1_1, c1_3, c2_1) AS MATERIALIZED (SELECT t1.c1, t1.c3, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) SELECT c1_1, c2_1 FROM t ORDER BY c1_3, c1_1 OFFSET 100 LIMIT 10;
+ c1_1 | c2_1
+------+------
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- ctid with whole-row reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.ctid, t1, t2, t1.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.ctid, t1.*, t2.*, t1.c1, t1.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r1."C 1", r1.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")))) ORDER BY r1.c3 ASC NULLS LAST, r1."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+-- SEMI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Semi Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c1)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c1) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 101
+ 102
+ 103
+ 104
+ 105
+ 106
+ 107
+ 108
+ 109
+ 110
+(10 rows)
+
+-- ANTI JOIN, not pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1
+ -> Merge Anti Join
+ Output: t1.c1
+ Merge Cond: (t1.c1 = t2.c2)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(11 rows)
+
+SELECT t1.c1 FROM ft1 t1 WHERE NOT EXISTS (SELECT 1 FROM ft2 t2 WHERE t1.c1 = t2.c2) ORDER BY t1.c1 OFFSET 100 LIMIT 10;
+ c1
+-----
+ 110
+ 111
+ 112
+ 113
+ 114
+ 115
+ 116
+ 117
+ 118
+ 119
+(10 rows)
+
+-- CROSS JOIN can be pushed down
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (TRUE)) ORDER BY r1."C 1" ASC NULLS LAST, r2."C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 100::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 CROSS JOIN ft2 t2 ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- different server, not pushed down. No result expected.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Merge Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft6 t2
+ Output: t2.c1, t2.c2, t2.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+ -> Materialize
+ Output: t1.c1, t1.c2, t1.c3
+ -> Foreign Scan on public.ft5 t1
+ Output: t1.c1, t1.c2, t1.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 4" ORDER BY c1 ASC NULLS LAST
+(13 rows)
+
+SELECT t1.c1, t2.c1 FROM ft5 t1 JOIN ft6 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+----
+(0 rows)
+
+-- unsafe join conditions (c8 has a UDT), not pushed down. Practically a CROSS
+-- JOIN since c8 in both tables has same value.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1
+ -> Sort
+ Output: t1.c1, t2.c1
+ Sort Key: t1.c1, t2.c1
+ -> Merge Left Join
+ Output: t1.c1, t2.c1
+ Merge Cond: (t1.c8 = t2.c8)
+ -> Sort
+ Output: t1.c1, t1.c8
+ Sort Key: t1.c8
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+ -> Sort
+ Output: t2.c1, t2.c8
+ Sort Key: t2.c8
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1, t2.c8
+ Remote SQL: SELECT "C 1", c8 FROM "S 1"."T 1"
+(20 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c8 = t2.c8) ORDER BY t1.c1, t2.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+----+-----
+ 1 | 101
+ 1 | 102
+ 1 | 103
+ 1 | 104
+ 1 | 105
+ 1 | 106
+ 1 | 107
+ 1 | 108
+ 1 | 109
+ 1 | 110
+(10 rows)
+
+-- unsafe conditions on one side (c8 has a UDT), not pushed down.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Hash Right Join
+ Output: t1.c1, t2.c1, t1.c3
+ Hash Cond: (t2.c1 = t1.c1)
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+ -> Hash
+ Output: t1.c1, t1.c3
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c3
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c3, c8 FROM "S 1"."T 1"
+(17 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 LEFT JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = 'foo' ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- join where unsafe to pushdown condition in WHERE clause has a column not
+-- in the SELECT clause. In this test unsafe clause needs to have column
+-- references from both joining sides so that the clause is not pushed down
+-- into one of the joining sides.
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, t2.c1, t1.c3
+ -> Sort
+ Output: t1.c1, t2.c1, t1.c3
+ Sort Key: t1.c3, t1.c1
+ -> Foreign Scan
+ Output: t1.c1, t2.c1, t1.c3
+ Filter: (t1.c8 = t2.c8)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1", r1.c3, r1.c8, r2.c8 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(10 rows)
+
+SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) WHERE t1.c8 = t2.c8 ORDER BY t1.c3, t1.c1 OFFSET 100 LIMIT 10;
+ c1 | c1
+-----+-----
+ 101 | 101
+ 102 | 102
+ 103 | 103
+ 104 | 104
+ 105 | 105
+ 106 | 106
+ 107 | 107
+ 108 | 108
+ 109 | 109
+ 110 | 110
+(10 rows)
+
+-- Aggregate after UNION, for testing setrefs
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ -> Sort
+ Output: t1.c1, (avg((t1.c1 + t2.c1)))
+ Sort Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, avg((t1.c1 + t2.c1))
+ Group Key: t1.c1
+ -> HashAggregate
+ Output: t1.c1, t2.c1
+ Group Key: t1.c1, t2.c1
+ -> Append
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+ -> Foreign Scan
+ Output: t1_1.c1, t2_1.c1
+ Relations: (public.ft1 t1_1) INNER JOIN (public.ft2 t2_1)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(20 rows)
+
+SELECT t1c1, avg(t1c1 + t2c1) FROM (SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1) UNION SELECT t1.c1, t2.c1 FROM ft1 t1 JOIN ft2 t2 ON (t1.c1 = t2.c1)) AS t (t1c1, t2c1) GROUP BY t1c1 ORDER BY t1c1 OFFSET 100 LIMIT 10;
+ t1c1 | avg
+------+----------------------
+ 101 | 202.0000000000000000
+ 102 | 204.0000000000000000
+ 103 | 206.0000000000000000
+ 104 | 208.0000000000000000
+ 105 | 210.0000000000000000
+ 106 | 212.0000000000000000
+ 107 | 214.0000000000000000
+ 108 | 216.0000000000000000
+ 109 | 218.0000000000000000
+ 110 | 220.0000000000000000
+(10 rows)
+
+-- join with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Limit
+ Output: t1."C 1"
+ -> Nested Loop
+ Output: t1."C 1"
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ -> Memoize
+ Cache Key: t1.c2
+ Cache Mode: binary
+ -> Subquery Scan on q
+ -> HashAggregate
+ Output: t2.c1, t3.c1
+ Group Key: t2.c1, t3.c1
+ -> Foreign Scan
+ Output: t2.c1, t3.c1
+ Relations: (public.ft1 t2) INNER JOIN (public.ft2 t3)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")) AND ((r1.c2 = $1::integer))))
+(17 rows)
+
+SELECT t1."C 1" FROM "S 1"."T 1" t1, LATERAL (SELECT DISTINCT t2.c1, t3.c1 FROM ft1 t2, ft2 t3 WHERE t2.c1 = t3.c1 AND t2.c2 = t1.c2) q ORDER BY t1."C 1" OFFSET 10 LIMIT 10;
+ C 1
+-----
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+ 1
+(10 rows)
+
+-- non-Var items in targetlist of the nullable rel of a join preventing
+-- push-down in some cases
+-- unable to push {ft1, ft2}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: (13), ft2.c1
+ Join Filter: (13 = ft2.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1" WHERE (("C 1" >= 10)) AND (("C 1" <= 15)) ORDER BY "C 1" ASC NULLS LAST
+ -> Materialize
+ Output: (13)
+ -> Foreign Scan on public.ft1
+ Output: 13
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 13))
+(11 rows)
+
+SELECT q.a, ft2.c1 FROM (SELECT 13 FROM ft1 WHERE c1 = 13) q(a) RIGHT JOIN ft2 ON (q.a = ft2.c1) WHERE ft2.c1 BETWEEN 10 AND 15;
+ a | c1
+----+----
+ | 10
+ | 11
+ | 12
+ 13 | 13
+ | 14
+ | 15
+(6 rows)
+
+-- ok to push {ft1, ft2} but not {ft1, ft2, ft4}
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: ft4.c1, (13), ft1.c1, ft2.c1
+ Join Filter: (ft4.c1 = ft1.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 10)) AND ((c1 <= 15))
+ -> Materialize
+ Output: ft1.c1, ft2.c1, (13)
+ -> Foreign Scan
+ Output: ft1.c1, ft2.c1, 13
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r5."C 1" FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = 12)) AND ((r4."C 1" = 12)))) ORDER BY r4."C 1" ASC NULLS LAST
+(12 rows)
+
+SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT JOIN ft2 ON (ft1.c1 = ft2.c1) WHERE ft1.c1 = 12) q(a, b, c) ON (ft4.c1 = q.b) WHERE ft4.c1 BETWEEN 10 AND 15;
+ c1 | a | b | c
+----+----+----+----
+ 10 | | |
+ 12 | 13 | 12 | 12
+ 14 | | |
+(3 rows)
+
+-- join with nullable side with some columns with null values
+UPDATE ft5 SET c3 = null where c1 % 9 = 0;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2
+ Relations: (public.ft5) INNER JOIN (public.ft4)
+ Remote SQL: SELECT CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1.c1, r1.c2, r1.c3) END, r1.c1, r1.c2, r1.c3, r2.c1, r2.c2 FROM ("S 1"."T 4" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c1 = r2.c1)) AND ((r2.c1 >= 10)) AND ((r2.c1 <= 30)))) ORDER BY r1.c1 ASC NULLS LAST
+(4 rows)
+
+SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1;
+ ft5 | c1 | c2 | c3 | c1 | c2
+----------------+----+----+--------+----+----
+ (12,13,AAA012) | 12 | 13 | AAA012 | 12 | 13
+ (18,19,) | 18 | 19 | | 18 | 19
+ (24,25,AAA024) | 24 | 25 | AAA024 | 24 | 25
+ (30,31,AAA030) | 30 | 31 | AAA030 | 30 | 31
+(4 rows)
+
+-- multi-way join involving multiple merge joins
+-- (this case used to have EPQ-related planning problems)
+CREATE TABLE local_tbl (c1 int NOT NULL, c2 int NOT NULL, c3 text, CONSTRAINT local_tbl_pkey PRIMARY KEY (c1));
+INSERT INTO local_tbl SELECT id, id % 10, to_char(id, 'FM0000') FROM generate_series(1, 1000) id;
+ANALYZE local_tbl;
+SET enable_nestloop TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid
+ Inner Unique: true
+ Merge Cond: (ft1.c2 = local_tbl.c1)
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Relations: (((public.ft1) INNER JOIN (public.ft2)) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r3.c1, r3.c2, r3.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r4.c1, r4.c2, r4.c3, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4.c1, r4.c2, r4.c3) END FROM ((("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1")) AND ((r2."C 1" < 100)) AND ((r1."C 1" < 100)))) INNER JOIN "S 1"."T 3" r3 ON (((r1.c2 = r3.c1)))) INNER JOIN "S 1"."T 4" r4 ON (((r1.c2 = r4.c1)))) ORDER BY r1.c2 ASC NULLS LAST FOR UPDATE OF r1 FOR UPDATE OF r2 FOR UPDATE OF r3 FOR UPDATE OF r4
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Merge Cond: (ft1.c2 = ft5.c1)
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Merge Cond: (ft1.c2 = ft4.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Sort Key: ft1.c2
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Merge Cond: (ft1.c1 = ft2.c1)
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) FOR UPDATE
+ -> Materialize
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ -> Foreign Scan on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Sort
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Sort Key: ft4.c1
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3, ft4.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3" FOR UPDATE
+ -> Sort
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Sort Key: ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c1, ft5.c2, ft5.c3, ft5.*
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4" FOR UPDATE
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+(47 rows)
+
+SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1
+ AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3 | c1 | c2 | c3
+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+-------+------------------------------+--------------------------+----+------------+-----+----+----+--------+----+----+--------+----+----+------
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST | Tue Jan 27 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST | Fri Feb 06 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST | Mon Feb 16 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST | Thu Feb 26 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST | Sun Mar 08 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST | Wed Mar 18 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST | Sat Mar 28 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST | Tue Apr 07 00:00:00 1970 | 6 | 6 | foo | 6 | 7 | AAA006 | 6 | 7 | AAA006 | 6 | 6 | 0006
+(10 rows)
+
+RESET enable_nestloop;
+RESET enable_hashjoin;
+-- test that add_paths_with_pathkeys_for_rel() arranges for the epq_path to
+-- return columns needed by the parent ForeignScan node
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.*, COALESCE(ft1.c3 || ft2.c3, 'foobar') FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100)) ss ON (local_tbl.c1 = ss.c1) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ -> Merge Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), local_tbl.ctid, ft1.*, ft2.*
+ Merge Cond: (local_tbl.c1 = ft1.c1)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text))
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c3 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = r4."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4."C 1" ASC NULLS LAST
+ -> Result
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c3
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, (COALESCE((ft1.c3 || ft2.c3), 'foobar'::text)), ft2.c3
+ Sort Key: ft1.c1
+ -> Hash Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, COALESCE((ft1.c3 || ft2.c3), 'foobar'::text), ft2.c3
+ Hash Cond: (ft1.c1 = ft2.c1)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Hash
+ Output: ft2.*, ft2.c1, ft2.c3
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c3
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(29 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD fdw_startup_cost '10000.0');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl LEFT JOIN (SELECT ft1.* FROM ft1 INNER JOIN ft2 ON (ft1.c1 = ft2.c1 AND ft1.c1 < 100 AND ft1.c1 = postgres_fdw_abs(ft2.c2))) ss ON (local_tbl.c3 = ss.c3) ORDER BY local_tbl.c1 FOR UPDATE OF local_tbl;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ LockRows
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ -> Nested Loop Left Join
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, local_tbl.ctid, ft1.*, ft2.*
+ Join Filter: (local_tbl.c3 = ft1.c3)
+ -> Index Scan using local_tbl_pkey on public.local_tbl
+ Output: local_tbl.c1, local_tbl.c2, local_tbl.c3, local_tbl.ctid
+ -> Materialize
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ -> Foreign Scan
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*
+ Filter: (ft1.c1 = postgres_fdw_abs(ft2.c2))
+ Relations: (public.ft1) INNER JOIN (public.ft2)
+ Remote SQL: SELECT r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4."C 1", r4.c2, r4.c3, r4.c4, r4.c5, r4.c6, r4.c7, r4.c8) END, CASE WHEN (r5.*)::text IS NOT NULL THEN ROW(r5."C 1", r5.c2, r5.c3, r5.c4, r5.c5, r5.c6, r5.c7, r5.c8) END, r5.c2 FROM ("S 1"."T 1" r4 INNER JOIN "S 1"."T 1" r5 ON (((r5."C 1" = r4."C 1")) AND ((r4."C 1" < 100)))) ORDER BY r4.c3 ASC NULLS LAST
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Sort Key: ft1.c3
+ -> Merge Join
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.*, ft2.c2
+ Merge Cond: ((ft1.c1 = (postgres_fdw_abs(ft2.c2))) AND (ft1.c1 = ft2.c1))
+ -> Sort
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Sort Key: ft1.c1
+ -> Foreign Scan on public.ft1
+ Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100))
+ -> Sort
+ Output: ft2.*, ft2.c1, ft2.c2, (postgres_fdw_abs(ft2.c2))
+ Sort Key: (postgres_fdw_abs(ft2.c2)), ft2.c1
+ -> Foreign Scan on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, postgres_fdw_abs(ft2.c2)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" ASC NULLS LAST
+(32 rows)
+
+ALTER SERVER loopback OPTIONS (DROP fdw_startup_cost);
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+DROP TABLE local_tbl;
+-- check join pushdown in situations where multiple userids are involved
+CREATE ROLE regress_view_owner SUPERUSER;
+CREATE USER MAPPING FOR regress_view_owner SERVER loopback;
+GRANT SELECT ON ft4 TO regress_view_owner;
+GRANT SELECT ON ft5 TO regress_view_owner;
+CREATE VIEW v4 AS SELECT * FROM ft4;
+CREATE VIEW v5 AS SELECT * FROM ft5;
+ALTER VIEW v5 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, different view owners
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, ft5.c2, ft5.c1
+ -> Sort
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Sort Key: ft4.c1, ft5.c1
+ -> Hash Left Join
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.c2, ft5.c1
+ -> Foreign Scan on public.ft5
+ Output: ft5.c2, ft5.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, ft5.c2, ft5.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5)
+ Remote SQL: SELECT r6.c1, r9.c2, r9.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r9 ON (((r6.c1 = r9.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r9.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN v5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can't be pushed down, view owner not current user
+ QUERY PLAN
+----------------------------------------------------------------------
+ Limit
+ Output: ft4.c1, t2.c2, t2.c1
+ -> Sort
+ Output: ft4.c1, t2.c2, t2.c1
+ Sort Key: ft4.c1, t2.c1
+ -> Hash Left Join
+ Output: ft4.c1, t2.c2, t2.c1
+ Hash Cond: (ft4.c1 = t2.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Hash
+ Output: t2.c2, t2.c1
+ -> Foreign Scan on public.ft5 t2
+ Output: t2.c2, t2.c1
+ Remote SQL: SELECT c1, c2 FROM "S 1"."T 4"
+(16 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO CURRENT_USER;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10; -- can be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ft4.c1, t2.c2, t2.c1
+ Relations: (public.ft4) LEFT JOIN (public.ft5 t2)
+ Remote SQL: SELECT r6.c1, r2.c2, r2.c1 FROM ("S 1"."T 3" r6 LEFT JOIN "S 1"."T 4" r2 ON (((r6.c1 = r2.c1)))) ORDER BY r6.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST LIMIT 10::bigint OFFSET 10::bigint
+(4 rows)
+
+SELECT t1.c1, t2.c2 FROM v4 t1 LEFT JOIN ft5 t2 ON (t1.c1 = t2.c1) ORDER BY t1.c1, t2.c1 OFFSET 10 LIMIT 10;
+ c1 | c2
+----+----
+ 22 |
+ 24 | 25
+ 26 |
+ 28 |
+ 30 | 31
+ 32 |
+ 34 |
+ 36 | 37
+ 38 |
+ 40 |
+(10 rows)
+
+ALTER VIEW v4 OWNER TO regress_view_owner;
+-- cleanup
+DROP OWNED BY regress_view_owner;
+DROP ROLE regress_view_owner;
+-- ===================================================================
+-- Aggregate and grouping queries
+-- ===================================================================
+-- Simple aggregates
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+------+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+ 100 | 49700 | 497.0000000000000000 | 2 | 992 | 0 | 49700
+ 100 | 49800 | 498.0000000000000000 | 3 | 993 | 0 | 49800
+ 100 | 49900 | 499.0000000000000000 | 4 | 994 | 0 | 49900
+ 100 | 50500 | 505.0000000000000000 | 0 | 1000 | 0 | 50500
+(5 rows)
+
+explain (verbose, costs off)
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c6)), (sum(c1)), (avg(c1)), (min(c2)), (max(c1)), (stddev(c2)), ((sum(c1)) * ((random() <= '1'::double precision))::integer), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c6), sum("C 1"), avg("C 1"), min(c2), max("C 1"), stddev(c2), c2 FROM "S 1"."T 1" WHERE ((c2 < 5)) GROUP BY 7 ORDER BY count(c6) ASC NULLS LAST, sum("C 1") ASC NULLS LAST LIMIT 1::bigint
+(4 rows)
+
+select count(c6), sum(c1), avg(c1), min(c2), max(c1), stddev(c2), sum(c1) * (random() <= 1)::int as sum2 from ft1 where c2 < 5 group by c2 order by 1, 2 limit 1;
+ count | sum | avg | min | max | stddev | sum2
+-------+-------+----------------------+-----+-----+--------+-------
+ 100 | 49600 | 496.0000000000000000 | 1 | 991 | 0 | 49600
+(1 row)
+
+-- Aggregate is not pushed down as aggregation contains random()
+explain (verbose, costs off)
+select sum(c1 * (random() <= 1)::int) as sum, avg(c1) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Aggregate
+ Output: sum((c1 * ((random() <= '1'::double precision))::integer)), avg(c1)
+ -> Foreign Scan on public.ft1
+ Output: c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(5 rows)
+
+-- Aggregate over join query
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(t1.c1)), (avg(t2.c1))
+ Relations: Aggregate on ((public.ft1 t1) INNER JOIN (public.ft1 t2))
+ Remote SQL: SELECT count(*), sum(r1."C 1"), avg(r2."C 1") FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2.c2 = 6)) AND ((r1.c2 = 6))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from ft1 t1 inner join ft1 t2 on (t1.c2 = t2.c2) where t1.c2 = 6;
+ count | sum | avg
+-------+---------+----------------------
+ 10000 | 5010000 | 501.0000000000000000
+(1 row)
+
+-- Not pushed down due to local conditions present in underneath input rel
+explain (verbose, costs off)
+select sum(t1.c1), count(t2.c1) from ft1 t1 inner join ft2 t2 on (t1.c1 = t2.c1) where ((t1.c1 * t2.c1)/(t1.c1 * t2.c1)) * random() <= 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(t1.c1), count(t2.c1)
+ -> Foreign Scan
+ Output: t1.c1, t2.c1
+ Filter: (((((t1.c1 * t2.c1) / (t1.c1 * t2.c1)))::double precision * random()) <= '1'::double precision)
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1."C 1", r2."C 1" FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = r1."C 1"))))
+(7 rows)
+
+-- GROUP BY clause having expressions
+explain (verbose, costs off)
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: ((c2 / 2)), ((sum(c2) * (c2 / 2)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (c2 / 2), (sum(c2) * (c2 / 2)) FROM "S 1"."T 1" GROUP BY 1 ORDER BY (c2 / 2) ASC NULLS LAST
+(4 rows)
+
+select c2/2, sum(c2) * (c2/2) from ft1 group by c2/2 order by c2/2;
+ ?column? | ?column?
+----------+----------
+ 0 | 0
+ 1 | 500
+ 2 | 1800
+ 3 | 3900
+ 4 | 6800
+(5 rows)
+
+-- Aggregates in subquery are pushed down.
+set enable_incremental_sort = off;
+explain (verbose, costs off)
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(ft1.c2), sum(ft1.c2)
+ -> Foreign Scan
+ Output: ft1.c2, (sum(ft1.c1)), (sqrt((ft1.c1)::double precision))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, sum("C 1"), sqrt("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 ORDER BY c2 ASC NULLS LAST, sum("C 1") ASC NULLS LAST
+(6 rows)
+
+select count(x.a), sum(x.a) from (select c2 a, sum(c1) b from ft1 group by c2, sqrt(c1) order by 1, 2) x;
+ count | sum
+-------+------
+ 1000 | 4500
+(1 row)
+
+reset enable_incremental_sort;
+-- Aggregate is still pushed down by taking unshippable expression out
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer)), ((sum(c1) * c2)), c2
+ Sort Key: ((ft1.c2 * ((random() <= '1'::double precision))::integer)), ((sum(ft1.c1) * ft1.c2))
+ -> Foreign Scan
+ Output: (c2 * ((random() <= '1'::double precision))::integer), ((sum(c1) * c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT (sum("C 1") * c2), c2 FROM "S 1"."T 1" GROUP BY 2
+(7 rows)
+
+select c2 * (random() <= 1)::int as sum1, sum(c1) * c2 as sum2 from ft1 group by c2 order by 1, 2;
+ sum1 | sum2
+------+--------
+ 0 | 0
+ 1 | 49600
+ 2 | 99400
+ 3 | 149400
+ 4 | 199600
+ 5 | 250000
+ 6 | 300600
+ 7 | 351400
+ 8 | 402400
+ 9 | 453600
+(10 rows)
+
+-- Aggregate with unshippable GROUP BY clause are not pushed
+explain (verbose, costs off)
+select c2 * (random() <= 1)::int as c2 from ft2 group by c2 * (random() <= 1)::int order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Sort Key: ((ft2.c2 * ((random() <= '1'::double precision))::integer))
+ -> HashAggregate
+ Output: ((c2 * ((random() <= '1'::double precision))::integer))
+ Group Key: (ft2.c2 * ((random() <= '1'::double precision))::integer)
+ -> Foreign Scan on public.ft2
+ Output: (c2 * ((random() <= '1'::double precision))::integer)
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(9 rows)
+
+-- GROUP BY clause in various forms, cardinal, alias and constant expression
+explain (verbose, costs off)
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Sort
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: (count(c2)), c2, 5, 7.0, 9
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(c2), c2, 5, 7.0, 9 FROM "S 1"."T 1" GROUP BY 2, 3, 5
+(7 rows)
+
+select count(c2) w, c2 x, 5 y, 7.0 z from ft1 group by 2, y, 9.0::int order by 2;
+ w | x | y | z
+-----+---+---+-----
+ 100 | 0 | 5 | 7.0
+ 100 | 1 | 5 | 7.0
+ 100 | 2 | 5 | 7.0
+ 100 | 3 | 5 | 7.0
+ 100 | 4 | 5 | 7.0
+ 100 | 5 | 5 | 7.0
+ 100 | 6 | 5 | 7.0
+ 100 | 7 | 5 | 7.0
+ 100 | 8 | 5 | 7.0
+ 100 | 9 | 5 | 7.0
+(10 rows)
+
+-- GROUP BY clause referring to same column multiple times
+-- Also, ORDER BY contains an aggregate function
+explain (verbose, costs off)
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, c2, (sum(c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, c2, sum("C 1") FROM "S 1"."T 1" WHERE ((c2 > 6)) GROUP BY 1, 2 ORDER BY sum("C 1") ASC NULLS LAST
+(4 rows)
+
+select c2, c2 from ft1 where c2 > 6 group by 1, 2 order by sum(c1);
+ c2 | c2
+----+----
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(3 rows)
+
+-- Testing HAVING clause shippability
+explain (verbose, costs off)
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c2, (sum(c1))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1 HAVING ((avg("C 1") < 500::numeric)) AND ((sum("C 1") < 49800)) ORDER BY c2 ASC NULLS LAST
+(4 rows)
+
+select c2, sum(c1) from ft2 group by c2 having avg(c1) < 500 and sum(c1) < 49800 order by c2;
+ c2 | sum
+----+-------
+ 1 | 49600
+ 2 | 49700
+(2 rows)
+
+-- Unshippable HAVING clause will be evaluated locally, and other qual in HAVING clause is pushed down
+explain (verbose, costs off)
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(*)
+ -> Foreign Scan
+ Output: ft1.c5, NULL::bigint, (sqrt((ft1.c2)::double precision))
+ Filter: (((((avg(ft1.c1)) / (avg(ft1.c1))))::double precision * random()) <= '1'::double precision)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c5, NULL::bigint, sqrt(c2), avg("C 1") FROM "S 1"."T 1" GROUP BY 1, 3 HAVING ((avg("C 1") < 500::numeric))
+(7 rows)
+
+select count(*) from (select c5, count(c1) from ft1 group by c5, sqrt(c2) having (avg(c1) / avg(c1)) * random() <= 1 and avg(c1) < 500) x;
+ count
+-------
+ 49
+(1 row)
+
+-- Aggregate in HAVING clause is not pushable, and thus aggregation is not pushed down
+explain (verbose, costs off)
+select sum(c1) from ft1 group by c2 having avg(c1 * (random() <= 1)::int) > 100 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1)), c2
+ Sort Key: (sum(ft1.c1))
+ -> HashAggregate
+ Output: sum(c1), c2
+ Group Key: ft1.c2
+ Filter: (avg((ft1.c1 * ((random() <= '1'::double precision))::integer)) > '100'::numeric)
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(10 rows)
+
+-- Remote aggregate in combination with a local Param (for the output
+-- of an initplan) can be trouble, per bug #15781
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ QUERY PLAN
+--------------------------------------------------
+ Foreign Scan
+ Output: $0, (sum(ft1.c1))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FROM "S 1"."T 1"
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+(6 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+explain (verbose, costs off)
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ QUERY PLAN
+---------------------------------------------------
+ GroupAggregate
+ Output: ($0), sum(ft1.c1)
+ Group Key: $0
+ InitPlan 1 (returns $0)
+ -> Seq Scan on pg_catalog.pg_enum
+ -> Foreign Scan on public.ft1
+ Output: $0, ft1.c1
+ Remote SQL: SELECT "C 1" FROM "S 1"."T 1"
+(8 rows)
+
+select exists(select 1 from pg_enum), sum(c1) from ft1 group by 1;
+ exists | sum
+--------+--------
+ t | 500500
+(1 row)
+
+-- Testing ORDER BY, DISTINCT, FILTER, Ordered-sets and VARIADIC within aggregates
+-- ORDER BY within aggregate, same column used to order
+explain (verbose, costs off)
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) GROUP BY 2 ORDER BY array_agg("C 1" ORDER BY "C 1" ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(c1 order by c1) from ft1 where c1 < 100 group by c2 order by 1;
+ array_agg
+--------------------------------
+ {1,11,21,31,41,51,61,71,81,91}
+ {2,12,22,32,42,52,62,72,82,92}
+ {3,13,23,33,43,53,63,73,83,93}
+ {4,14,24,34,44,54,64,74,84,94}
+ {5,15,25,35,45,55,65,75,85,95}
+ {6,16,26,36,46,56,66,76,86,96}
+ {7,17,27,37,47,57,67,77,87,97}
+ {8,18,28,38,48,58,68,78,88,98}
+ {9,19,29,39,49,59,69,79,89,99}
+ {10,20,30,40,50,60,70,80,90}
+(10 rows)
+
+-- ORDER BY within aggregate, different column used to order also using DESC
+explain (verbose, costs off)
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c5 ORDER BY c1 DESC))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg(c5 ORDER BY "C 1" DESC NULLS FIRST) FROM "S 1"."T 1" WHERE (("C 1" < 50)) AND ((c2 = 6))
+(4 rows)
+
+select array_agg(c5 order by c1 desc) from ft2 where c2 = 6 and c1 < 50;
+ array_agg
+------------------------------------------------------------------------------------------------------------------------------------------
+ {"Mon Feb 16 00:00:00 1970","Fri Feb 06 00:00:00 1970","Tue Jan 27 00:00:00 1970","Sat Jan 17 00:00:00 1970","Wed Jan 07 00:00:00 1970"}
+(1 row)
+
+-- DISTINCT within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5)), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5)) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+-- DISTINCT combined with ORDER BY within aggregate
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5))), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) ASC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {0,1,2,3,4}
+ {1,2,3,NULL}
+(2 rows)
+
+explain (verbose, costs off)
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(DISTINCT (t1.c1 % 5) ORDER BY (t1.c1 % 5) DESC NULLS LAST)), ((t2.c1 % 3))
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST), (r2.c1 % 3) FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) WHERE (((r1.c1 < 20) OR ((r1.c1 IS NULL) AND (r2.c1 < 5)))) GROUP BY 2 ORDER BY array_agg(DISTINCT (r1.c1 % 5) ORDER BY ((r1.c1 % 5)) DESC NULLS LAST) ASC NULLS LAST
+(4 rows)
+
+select array_agg(distinct (t1.c1)%5 order by (t1.c1)%5 desc nulls last) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) where t1.c1 < 20 or (t1.c1 is null and t2.c1 < 5) group by (t2.c1)%3 order by 1;
+ array_agg
+--------------
+ {3,2,1,NULL}
+ {4,3,2,1,0}
+(2 rows)
+
+-- FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum(c1) FILTER (WHERE ((c1 < 100) AND (c2 > 5)))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))), c2 FROM "S 1"."T 1" GROUP BY 2 ORDER BY sum("C 1") FILTER (WHERE (("C 1" < 100) AND (c2 > 5))) ASC NULLS LAST
+(4 rows)
+
+select sum(c1) filter (where c1 < 100 and c2 > 5) from ft1 group by c2 order by 1 nulls last;
+ sum
+-----
+ 510
+ 520
+ 530
+ 540
+
+
+
+
+
+
+(10 rows)
+
+-- DISTINCT, ORDER BY and FILTER within aggregate
+explain (verbose, costs off)
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (sum((c1 % 3))), (sum(DISTINCT (c1 % 3) ORDER BY (c1 % 3)) FILTER (WHERE ((c1 % 3) < 2))), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(("C 1" % 3)), sum(DISTINCT ("C 1" % 3) ORDER BY (("C 1" % 3)) ASC NULLS LAST) FILTER (WHERE (("C 1" % 3) < 2)), c2 FROM "S 1"."T 1" WHERE ((c2 = 6)) GROUP BY 3
+(4 rows)
+
+select sum(c1%3), sum(distinct c1%3 order by c1%3) filter (where c1%3 < 2), c2 from ft1 where c2 = 6 group by c2;
+ sum | sum | c2
+-----+-----+----
+ 99 | 1 | 6
+(1 row)
+
+-- Outer query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan
+ Output: (SubPlan 1)
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT count(*) FILTER (WHERE ((c2 = 6) AND ("C 1" < 10))) FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan on public.ft1 t1
+ Output: (count(*) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Remote SQL: SELECT NULL FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(*) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 1
+(1 row)
+
+-- Inner query is aggregation query
+explain (verbose, costs off)
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((SubPlan 1))
+ -> Sort
+ Output: ((SubPlan 1))
+ Sort Key: ((SubPlan 1))
+ -> Foreign Scan on public.ft2 t2
+ Output: (SubPlan 1)
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (((c2 % 6) = 0))
+ SubPlan 1
+ -> Foreign Scan
+ Output: (count(t1.c1) FILTER (WHERE ((t2.c2 = 6) AND (t2.c1 < 10))))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count("C 1") FILTER (WHERE (($1::integer = 6) AND ($2::integer < 10))) FROM "S 1"."T 1" WHERE (("C 1" = 6))
+(13 rows)
+
+select distinct (select count(t1.c1) filter (where t2.c2 = 6 and t2.c1 < 10) from ft1 t1 where t1.c1 = 6) from ft2 t2 where t2.c2 % 6 = 0 order by 1;
+ count
+-------
+ 0
+ 1
+(2 rows)
+
+-- Aggregate not pushed down as FILTER condition is not pushable
+explain (verbose, costs off)
+select sum(c1) filter (where (c1 / c1) * random() <= 1) from ft1 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: (sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision))), c2
+ Sort Key: (sum(ft1.c1) FILTER (WHERE ((((ft1.c1 / ft1.c1))::double precision * random()) <= '1'::double precision)))
+ -> HashAggregate
+ Output: sum(c1) FILTER (WHERE ((((c1 / c1))::double precision * random()) <= '1'::double precision)), c2
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c1, c2
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1"
+(9 rows)
+
+explain (verbose, costs off)
+select sum(c2) filter (where c2 in (select c2 from ft1 where c2 < 5)) from ft1;
+ QUERY PLAN
+-------------------------------------------------------------------
+ Aggregate
+ Output: sum(ft1.c2) FILTER (WHERE (hashed SubPlan 1))
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ SubPlan 1
+ -> Foreign Scan on public.ft1 ft1_1
+ Output: ft1_1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1" WHERE ((c2 < 5))
+(9 rows)
+
+-- Ordered-sets within aggregate
+explain (verbose, costs off)
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (rank('10'::character varying) WITHIN GROUP (ORDER BY c6)), (percentile_cont((((c2)::numeric / '10'::numeric))::double precision) WITHIN GROUP (ORDER BY ((c1)::double precision)))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, rank('10'::character varying) WITHIN GROUP (ORDER BY c6 ASC NULLS LAST), percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1 HAVING ((percentile_cont((c2 / 10::numeric)) WITHIN GROUP (ORDER BY ("C 1") ASC NULLS LAST) < 500::double precision))
+(7 rows)
+
+select c2, rank('10'::varchar) within group (order by c6), percentile_cont(c2/10::numeric) within group (order by c1) from ft1 where c2 < 10 group by c2 having percentile_cont(c2/10::numeric) within group (order by c1) < 500 order by c2;
+ c2 | rank | percentile_cont
+----+------+-----------------
+ 0 | 101 | 10
+ 1 | 101 | 100
+ 2 | 1 | 200
+ 3 | 1 | 300
+ 4 | 1 | 400
+(5 rows)
+
+-- Using multiple arguments within aggregates
+explain (verbose, costs off)
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: c1, (rank(c1, c2) WITHIN GROUP (ORDER BY c1, c2)), c2
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT "C 1", rank("C 1", c2) WITHIN GROUP (ORDER BY "C 1" ASC NULLS LAST, c2 ASC NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" = 6)) GROUP BY 1, 3
+(4 rows)
+
+select c1, rank(c1, c2) within group (order by c1, c2) from ft1 group by c1, c2 having c1 = 6 order by 1;
+ c1 | rank
+----+------
+ 6 | 1
+(1 row)
+
+-- User defined function for user defined aggregate, VARIADIC
+create function least_accum(anyelement, variadic anyarray)
+returns anyelement language sql as
+ 'select least($1, min($2[i])) from generate_subscripts($2,1) g(i)';
+create aggregate least_agg(variadic items anyarray) (
+ stype = anyelement, sfunc = least_accum
+);
+-- Disable hash aggregation for plan stability.
+set enable_hashagg to false;
+-- Not pushed down due to user defined aggregate
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Add function and aggregate into extension
+alter extension postgres_fdw add function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw add aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now aggregate will be pushed. Aggregate will display VARIADIC argument.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Sort Key: ft1.c2
+ -> Foreign Scan
+ Output: c2, (least_agg(VARIADIC ARRAY[c1]))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, public.least_agg(VARIADIC ARRAY["C 1"]) FROM "S 1"."T 1" WHERE ((c2 < 100)) GROUP BY 1
+(7 rows)
+
+select c2, least_agg(c1) from ft1 where c2 < 100 group by c2 order by c2;
+ c2 | least_agg
+----+-----------
+ 0 | 10
+ 1 | 1
+ 2 | 2
+ 3 | 3
+ 4 | 4
+ 5 | 5
+ 6 | 6
+ 7 | 7
+ 8 | 8
+ 9 | 9
+(10 rows)
+
+-- Remove function and aggregate from extension
+alter extension postgres_fdw drop function least_accum(anyelement, variadic anyarray);
+alter extension postgres_fdw drop aggregate least_agg(variadic items anyarray);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Not pushed down as we have dropped objects from extension.
+explain (verbose, costs off)
+select c2, least_agg(c1) from ft1 group by c2 order by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ GroupAggregate
+ Output: c2, least_agg(VARIADIC ARRAY[c1])
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" ORDER BY c2 ASC NULLS LAST
+(6 rows)
+
+-- Cleanup
+reset enable_hashagg;
+drop aggregate least_agg(variadic items anyarray);
+drop function least_accum(anyelement, variadic anyarray);
+-- Testing USING OPERATOR() in ORDER BY within aggregate.
+-- For this, we need user defined operators along with operator family and
+-- operator class. Create those and then add them in extension. Note that
+-- user defined objects are considered unshippable unless they are part of
+-- the extension.
+create operator public.<^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4eq
+);
+create operator public.=^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4lt
+);
+create operator public.>^ (
+ leftarg = int4,
+ rightarg = int4,
+ procedure = int4gt
+);
+create operator family my_op_family using btree;
+create function my_op_cmp(a int, b int) returns int as
+ $$begin return btint4cmp(a, b); end $$ language plpgsql;
+create operator class my_op_class for type int using btree family my_op_family as
+ operator 1 public.<^,
+ operator 3 public.=^,
+ operator 5 public.>^,
+ function 1 my_op_cmp(int, int);
+-- This will not be pushed as user defined sort operator is not part of the
+-- extension yet.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- This should not be pushed either.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Sort
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+-- Update local stats on ft2
+ANALYZE ft2;
+-- Add into extension
+alter extension postgres_fdw add operator class my_op_class using btree;
+alter extension postgres_fdw add function my_op_cmp(a int, b int);
+alter extension postgres_fdw add operator family my_op_family using btree;
+alter extension postgres_fdw add operator public.<^(int, int);
+alter extension postgres_fdw add operator public.=^(int, int);
+alter extension postgres_fdw add operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- Now this will be pushed as sort operator is part of the extension.
+alter server loopback options (add fdw_tuple_cost '0.5');
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (array_agg(c1 ORDER BY c1 USING <^ NULLS LAST)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT array_agg("C 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST), c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6)) GROUP BY 2
+(4 rows)
+
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ array_agg
+--------------------------------
+ {6,16,26,36,46,56,66,76,86,96}
+(1 row)
+
+alter server loopback options (drop fdw_tuple_cost);
+-- This should be pushed too.
+explain (verbose, costs off)
+select * from ft2 order by c1 using operator(public.<^);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY "C 1" USING OPERATOR(public.<^) NULLS LAST
+(3 rows)
+
+-- Remove from extension
+alter extension postgres_fdw drop operator class my_op_class using btree;
+alter extension postgres_fdw drop function my_op_cmp(a int, b int);
+alter extension postgres_fdw drop operator family my_op_family using btree;
+alter extension postgres_fdw drop operator public.<^(int, int);
+alter extension postgres_fdw drop operator public.=^(int, int);
+alter extension postgres_fdw drop operator public.>^(int, int);
+alter server loopback options (set extensions 'postgres_fdw');
+-- This will not be pushed as sort operator is now removed from the extension.
+explain (verbose, costs off)
+select array_agg(c1 order by c1 using operator(public.<^)) from ft2 where c2 = 6 and c1 < 100 group by c2;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ GroupAggregate
+ Output: array_agg(c1 ORDER BY c1 USING <^ NULLS LAST), c2
+ Group Key: ft2.c2
+ -> Sort
+ Output: c2, c1
+ Sort Key: ft2.c1 USING <^
+ -> Foreign Scan on public.ft2
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND ((c2 = 6))
+(9 rows)
+
+-- Cleanup
+drop operator class my_op_class using btree;
+drop function my_op_cmp(a int, b int);
+drop operator family my_op_family using btree;
+drop operator public.>^(int, int);
+drop operator public.=^(int, int);
+drop operator public.<^(int, int);
+-- Input relation to aggregate push down hook is not safe to pushdown and thus
+-- the aggregate cannot be pushed down to foreign server.
+explain (verbose, costs off)
+select count(t1.c3) from ft2 t1 left join ft2 t2 on (t1.c1 = random() * t2.c2);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------
+ Aggregate
+ Output: count(t1.c3)
+ -> Nested Loop Left Join
+ Output: t1.c3
+ Join Filter: ((t1.c1)::double precision = (random() * (t2.c2)::double precision))
+ -> Foreign Scan on public.ft2 t1
+ Output: t1.c3, t1.c1
+ Remote SQL: SELECT "C 1", c3 FROM "S 1"."T 1"
+ -> Materialize
+ Output: t2.c2
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+(13 rows)
+
+-- Subquery in FROM clause having aggregate
+explain (verbose, costs off)
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Sort
+ Output: (count(*)), x.b
+ Sort Key: (count(*)), x.b
+ -> HashAggregate
+ Output: count(*), x.b
+ Group Key: x.b
+ -> Hash Join
+ Output: x.b
+ Inner Unique: true
+ Hash Cond: (ft1.c2 = x.a)
+ -> Foreign Scan on public.ft1
+ Output: ft1.c2
+ Remote SQL: SELECT c2 FROM "S 1"."T 1"
+ -> Hash
+ Output: x.b, x.a
+ -> Subquery Scan on x
+ Output: x.b, x.a
+ -> Foreign Scan
+ Output: ft1_1.c2, (sum(ft1_1.c1))
+ Relations: Aggregate on (public.ft1 ft1_1)
+ Remote SQL: SELECT c2, sum("C 1") FROM "S 1"."T 1" GROUP BY 1
+(21 rows)
+
+select count(*), x.b from ft1, (select c2 a, sum(c1) b from ft1 group by c2) x where ft1.c2 = x.a group by x.b order by 1, 2;
+ count | b
+-------+-------
+ 100 | 49600
+ 100 | 49700
+ 100 | 49800
+ 100 | 49900
+ 100 | 50000
+ 100 | 50100
+ 100 | 50200
+ 100 | 50300
+ 100 | 50400
+ 100 | 50500
+(10 rows)
+
+-- FULL join with IS NULL check in HAVING
+explain (verbose, costs off)
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (avg(t1.c1)), (sum(t2.c1)), t2.c1
+ Relations: Aggregate on ((public.ft4 t1) FULL JOIN (public.ft5 t2))
+ Remote SQL: SELECT avg(r1.c1), sum(r2.c1), r2.c1 FROM ("S 1"."T 3" r1 FULL JOIN "S 1"."T 4" r2 ON (((r1.c1 = r2.c1)))) GROUP BY 3 HAVING ((((avg(r1.c1) IS NULL) AND (sum(r2.c1) < 10)) OR (sum(r2.c1) IS NULL))) ORDER BY avg(r1.c1) ASC NULLS LAST, sum(r2.c1) ASC NULLS LAST
+(4 rows)
+
+select avg(t1.c1), sum(t2.c1) from ft4 t1 full join ft5 t2 on (t1.c1 = t2.c1) group by t2.c1 having (avg(t1.c1) is null and sum(t2.c1) < 10) or sum(t2.c1) is null order by 1 nulls last, 2;
+ avg | sum
+---------------------+-----
+ 51.0000000000000000 |
+ | 3
+ | 9
+(3 rows)
+
+-- Aggregate over FULL join needing to deparse the joining relations as
+-- subqueries.
+explain (verbose, costs off)
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*)), (sum(ft4.c1)), (avg(ft5.c1))
+ Relations: Aggregate on ((public.ft4) FULL JOIN (public.ft5))
+ Remote SQL: SELECT count(*), sum(s4.c1), avg(s5.c1) FROM ((SELECT c1 FROM "S 1"."T 3" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s4(c1) FULL JOIN (SELECT c1 FROM "S 1"."T 4" WHERE ((c1 >= 50)) AND ((c1 <= 60))) s5(c1) ON (((s4.c1 = s5.c1))))
+(4 rows)
+
+select count(*), sum(t1.c1), avg(t2.c1) from (select c1 from ft4 where c1 between 50 and 60) t1 full join (select c1 from ft5 where c1 between 50 and 60) t2 on (t1.c1 = t2.c1);
+ count | sum | avg
+-------+-----+---------------------
+ 8 | 330 | 55.5000000000000000
+(1 row)
+
+-- ORDER BY expression is part of the target list but not pushed down to
+-- foreign server.
+explain (verbose, costs off)
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Sort
+ Output: (((sum(c2)) * ((random() <= '1'::double precision))::integer))
+ Sort Key: (((sum(ft1.c2)) * ((random() <= '1'::double precision))::integer))
+ -> Foreign Scan
+ Output: ((sum(c2)) * ((random() <= '1'::double precision))::integer)
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT sum(c2) FROM "S 1"."T 1"
+(7 rows)
+
+select sum(c2) * (random() <= 1)::int as sum from ft1 order by 1;
+ sum
+------
+ 4500
+(1 row)
+
+-- LATERAL join, with parameterization
+set enable_hashagg to false;
+explain (verbose, costs off)
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c2, qry.sum
+ Sort Key: t1.c2
+ -> Nested Loop
+ Output: t1.c2, qry.sum
+ -> Index Scan using t1_pkey on "S 1"."T 1" t1
+ Output: t1."C 1", t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Index Cond: (t1."C 1" < 100)
+ Filter: (t1.c2 < 3)
+ -> Subquery Scan on qry
+ Output: qry.sum, t2.c1
+ Filter: ((t1.c2 * 2) = qry.sum)
+ -> Foreign Scan
+ Output: (sum((t2.c1 + t1."C 1"))), t2.c1
+ Relations: Aggregate on (public.ft2 t2)
+ Remote SQL: SELECT sum(("C 1" + $1::integer)), "C 1" FROM "S 1"."T 1" GROUP BY 2
+(16 rows)
+
+select c2, sum from "S 1"."T 1" t1, lateral (select sum(t2.c1 + t1."C 1") sum from ft2 t2 group by t2.c1) qry where t1.c2 * 2 = qry.sum and t1.c2 < 3 and t1."C 1" < 100 order by 1;
+ c2 | sum
+----+-----
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+reset enable_hashagg;
+-- bug #15613: bad plan for foreign table scan with lateral reference
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: ref_0.c2, ref_0."C 1", (ref_0.c2), ref_1.c3, ref_0."C 1"
+ -> Nested Loop
+ Output: ref_0.c2, ref_0."C 1", ref_1.c3, (ref_0.c2)
+ -> Index Scan using t1_pkey on "S 1"."T 1" ref_0
+ Output: ref_0."C 1", ref_0.c2, ref_0.c3, ref_0.c4, ref_0.c5, ref_0.c6, ref_0.c7, ref_0.c8
+ Index Cond: (ref_0."C 1" < 10)
+ -> Foreign Scan on public.ft1 ref_1
+ Output: ref_1.c3, ref_0.c2
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+ -> Materialize
+ Output: ref_3.c3
+ -> Foreign Scan on public.ft2 ref_3
+ Output: ref_3.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE ((c3 = '00001'))
+(15 rows)
+
+SELECT ref_0.c2, subq_1.*
+FROM
+ "S 1"."T 1" AS ref_0,
+ LATERAL (
+ SELECT ref_0."C 1" c1, subq_0.*
+ FROM (SELECT ref_0.c2, ref_1.c3
+ FROM ft1 AS ref_1) AS subq_0
+ RIGHT JOIN ft2 AS ref_3 ON (subq_0.c3 = ref_3.c3)
+ ) AS subq_1
+WHERE ref_0."C 1" < 10 AND subq_1.c3 = '00001'
+ORDER BY ref_0."C 1";
+ c2 | c1 | c2 | c3
+----+----+----+-------
+ 1 | 1 | 1 | 00001
+ 2 | 2 | 2 | 00001
+ 3 | 3 | 3 | 00001
+ 4 | 4 | 4 | 00001
+ 5 | 5 | 5 | 00001
+ 6 | 6 | 6 | 00001
+ 7 | 7 | 7 | 00001
+ 8 | 8 | 8 | 00001
+ 9 | 9 | 9 | 00001
+(9 rows)
+
+-- Check with placeHolderVars
+explain (verbose, costs off)
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------
+ Aggregate
+ Output: sum(q.a), count(q.b)
+ -> Nested Loop Left Join
+ Output: q.a, q.b
+ Inner Unique: true
+ Join Filter: ((ft4.c1)::numeric <= q.b)
+ -> Foreign Scan on public.ft4
+ Output: ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1 FROM "S 1"."T 3"
+ -> Materialize
+ Output: q.a, q.b
+ -> Subquery Scan on q
+ Output: q.a, q.b
+ -> Foreign Scan
+ Output: 13, (avg(ft1.c1)), NULL::bigint
+ Relations: Aggregate on ((public.ft2) LEFT JOIN (public.ft1))
+ Remote SQL: SELECT 13, avg(r1."C 1"), NULL::bigint FROM ("S 1"."T 1" r2 LEFT JOIN "S 1"."T 1" r1 ON (((r1."C 1" = r2."C 1"))))
+(17 rows)
+
+select sum(q.a), count(q.b) from ft4 left join (select 13, avg(ft1.c1), sum(ft2.c1) from ft1 right join ft2 on (ft1.c1 = ft2.c1)) q(a, b, c) on (ft4.c1 <= q.b);
+ sum | count
+-----+-------
+ 650 | 50
+(1 row)
+
+-- Not supported cases
+-- Grouping sets
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by rollup(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1))
+ Sort Key: ft1.c2
+ -> MixedAggregate
+ Output: c2, sum(c1)
+ Hash Key: ft1.c2
+ Group Key: ()
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, sum(c1) from ft1 where c2 < 3 group by cube(c2) order by 1 nulls last;
+ c2 | sum
+----+--------
+ 0 | 50500
+ 1 | 49600
+ 2 | 49700
+ | 149800
+(4 rows)
+
+explain (verbose, costs off)
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ QUERY PLAN
+----------------------------------------------------------------------------------
+ Sort
+ Output: c2, c6, (sum(c1))
+ Sort Key: ft1.c2, ft1.c6
+ -> HashAggregate
+ Output: c2, c6, sum(c1)
+ Hash Key: ft1.c2
+ Hash Key: ft1.c6
+ -> Foreign Scan on public.ft1
+ Output: c2, c6, c1
+ Remote SQL: SELECT "C 1", c2, c6 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(10 rows)
+
+select c2, c6, sum(c1) from ft1 where c2 < 3 group by grouping sets(c2, c6) order by 1 nulls last, 2 nulls last;
+ c2 | c6 | sum
+----+----+-------
+ 0 | | 50500
+ 1 | | 49600
+ 2 | | 49700
+ | 0 | 50500
+ | 1 | 49600
+ | 2 | 49700
+(6 rows)
+
+explain (verbose, costs off)
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ QUERY PLAN
+------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c1)), (GROUPING(c2))
+ Sort Key: ft1.c2
+ -> HashAggregate
+ Output: c2, sum(c1), GROUPING(c2)
+ Group Key: ft1.c2
+ -> Foreign Scan on public.ft1
+ Output: c2, c1
+ Remote SQL: SELECT "C 1", c2 FROM "S 1"."T 1" WHERE ((c2 < 3))
+(9 rows)
+
+select c2, sum(c1), grouping(c2) from ft1 where c2 < 3 group by c2 order by 1 nulls last;
+ c2 | sum | grouping
+----+-------+----------
+ 0 | 50500 | 0
+ 1 | 49600 | 0
+ 2 | 49700 | 0
+(3 rows)
+
+-- DISTINCT itself is not pushed down, whereas underneath aggregate is pushed
+explain (verbose, costs off)
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Unique
+ Output: ((sum(c1) / 1000)), c2
+ -> Sort
+ Output: ((sum(c1) / 1000)), c2
+ Sort Key: ((sum(ft2.c1) / 1000))
+ -> Foreign Scan
+ Output: ((sum(c1) / 1000)), c2
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT (sum("C 1") / 1000), c2 FROM "S 1"."T 1" WHERE ((c2 < 6)) GROUP BY 2
+(9 rows)
+
+select distinct sum(c1)/1000 s from ft2 where c2 < 6 group by c2 order by 1;
+ s
+----
+ 49
+ 50
+(2 rows)
+
+-- WindowAgg
+explain (verbose, costs off)
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (sum(c2)), (count(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft2.c2
+ -> WindowAgg
+ Output: c2, (sum(c2)), count(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Sort Key: ((ft2.c2 % 2))
+ -> Foreign Scan
+ Output: c2, ((c2 % 2)), (sum(c2))
+ Relations: Aggregate on (public.ft2)
+ Remote SQL: SELECT c2, (c2 % 2), sum(c2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, sum(c2), count(c2) over (partition by c2%2) from ft2 where c2 < 10 group by c2 order by 1;
+ c2 | sum | count
+----+-----+-------
+ 0 | 0 | 5
+ 1 | 100 | 5
+ 2 | 200 | 5
+ 3 | 300 | 5
+ 4 | 400 | 5
+ 5 | 500 | 5
+ 6 | 600 | 5
+ 7 | 700 | 5
+ 8 | 800 | 5
+ 9 | 900 | 5
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2 DESC
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 desc) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {8,6,4,2,0}
+ 1 | {9,7,5,3,1}
+ 2 | {8,6,4,2}
+ 3 | {9,7,5,3}
+ 4 | {8,6,4}
+ 5 | {9,7,5}
+ 6 | {8,6}
+ 7 | {9,7}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+explain (verbose, costs off)
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Sort
+ Output: c2, (array_agg(c2) OVER (?)), ((c2 % 2))
+ Sort Key: ft1.c2
+ -> WindowAgg
+ Output: c2, array_agg(c2) OVER (?), ((c2 % 2))
+ -> Sort
+ Output: c2, ((c2 % 2))
+ Sort Key: ((ft1.c2 % 2)), ft1.c2
+ -> Foreign Scan
+ Output: c2, ((c2 % 2))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT c2, (c2 % 2) FROM "S 1"."T 1" WHERE ((c2 < 10)) GROUP BY 1
+(12 rows)
+
+select c2, array_agg(c2) over (partition by c2%2 order by c2 range between current row and unbounded following) from ft1 where c2 < 10 group by c2 order by 1;
+ c2 | array_agg
+----+-------------
+ 0 | {0,2,4,6,8}
+ 1 | {1,3,5,7,9}
+ 2 | {2,4,6,8}
+ 3 | {3,5,7,9}
+ 4 | {4,6,8}
+ 5 | {5,7,9}
+ 6 | {6,8}
+ 7 | {7,9}
+ 8 | {8}
+ 9 | {9}
+(10 rows)
+
+-- ===================================================================
+-- parameterized queries
+-- ===================================================================
+-- simple join
+PREPARE st1(int, int) AS SELECT t1.c3, t2.c3 FROM ft1 t1, ft2 t2 WHERE t1.c1 = $1 AND t2.c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st1(1, 2);
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.c3, t2.c3
+ Relations: (public.ft1 t1) INNER JOIN (public.ft2 t2)
+ Remote SQL: SELECT r1.c3, r2.c3 FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r2."C 1" = 2)) AND ((r1."C 1" = 1))))
+(4 rows)
+
+EXECUTE st1(1, 1);
+ c3 | c3
+-------+-------
+ 00001 | 00001
+(1 row)
+
+EXECUTE st1(101, 101);
+ c3 | c3
+-------+-------
+ 00101 | 00101
+(1 row)
+
+-- subquery using stable function (can't be sent to remote)
+PREPARE st2(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c4) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st2(10, 20);
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t2.c3 = t1.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Filter: (date(t2.c4) = '01-17-1970'::date)
+ Remote SQL: SELECT c3, c4 FROM "S 1"."T 1" WHERE (("C 1" > 10))
+(15 rows)
+
+EXECUTE st2(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st2(101, 121);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+-- subquery using immutable function (can be sent to remote)
+PREPARE st3(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 < $2 AND t1.c3 IN (SELECT c3 FROM ft2 t2 WHERE c1 > $1 AND date(c5) = '1970-01-17'::date) ORDER BY c1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st3(10, 20);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Sort
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Sort Key: t1.c1
+ -> Nested Loop Semi Join
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Join Filter: (t2.c3 = t1.c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: t1.c1, t1.c2, t1.c3, t1.c4, t1.c5, t1.c6, t1.c7, t1.c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 20))
+ -> Materialize
+ Output: t2.c3
+ -> Foreign Scan on public.ft2 t2
+ Output: t2.c3
+ Remote SQL: SELECT c3 FROM "S 1"."T 1" WHERE (("C 1" > 10)) AND ((date(c5) = '1970-01-17'::date))
+(14 rows)
+
+EXECUTE st3(10, 20);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST | Sat Jan 17 00:00:00 1970 | 6 | 6 | foo
+(1 row)
+
+EXECUTE st3(20, 30);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+----+----+----+----+----+----
+(0 rows)
+
+-- custom plan should be chosen initially
+PREPARE st4(int) AS SELECT * FROM ft1 t1 WHERE t1.c1 = $1;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(3 rows)
+
+-- once we try it enough times, should switch to generic plan
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st4(1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(3 rows)
+
+-- value of $1 should not be sent to remote
+PREPARE st5(user_enum,int) AS SELECT * FROM ft1 t1 WHERE c8 = $1 and c1 = $2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+---------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = 'foo'::user_enum)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = 1))
+(4 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st5('foo', 1);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.c8 = $1)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = $1::integer))
+(4 rows)
+
+EXECUTE st5('foo', 1);
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- altering FDW options requires replanning
+PREPARE st6 AS SELECT * FROM ft1 t1 WHERE t1.c1 = t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" = c2))
+(3 rows)
+
+PREPARE st7 AS INSERT INTO ft1 (c1,c2,c3) VALUES (1001,101,'foo');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 1" RENAME TO "T 0";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 0');
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st6;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 0" WHERE (("C 1" = c2))
+(3 rows)
+
+EXECUTE st6;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST | Mon Jan 05 00:00:00 1970 | 4 | 4 | foo
+ 5 | 5 | 00005 | Tue Jan 06 00:00:00 1970 PST | Tue Jan 06 00:00:00 1970 | 5 | 5 | foo
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST | Wed Jan 07 00:00:00 1970 | 6 | 6 | foo
+ 7 | 7 | 00007 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 9 | 9 | 00009 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | 9 | foo
+(9 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st7;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft1
+ Remote SQL: INSERT INTO "S 1"."T 0"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: NULL::integer, 1001, 101, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft1 '::character(10), NULL::user_enum
+(5 rows)
+
+ALTER TABLE "S 1"."T 0" RENAME TO "T 1";
+ALTER FOREIGN TABLE ft1 OPTIONS (SET table_name 'T 1');
+PREPARE st8 AS SELECT count(c3) FROM ft1 t1 WHERE t1.c1 === t1.c2;
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(c3))
+ Relations: Aggregate on (public.ft1 t1)
+ Remote SQL: SELECT count(c3) FROM "S 1"."T 1" WHERE (("C 1" OPERATOR(public.===) c2))
+(4 rows)
+
+ALTER SERVER loopback OPTIONS (DROP extensions);
+EXPLAIN (VERBOSE, COSTS OFF) EXECUTE st8;
+ QUERY PLAN
+-----------------------------------------------------------
+ Aggregate
+ Output: count(c3)
+ -> Foreign Scan on public.ft1 t1
+ Output: c3
+ Filter: (t1.c1 === t1.c2)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1"
+(6 rows)
+
+EXECUTE st8;
+ count
+-------
+ 9
+(1 row)
+
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- cleanup
+DEALLOCATE st1;
+DEALLOCATE st2;
+DEALLOCATE st3;
+DEALLOCATE st4;
+DEALLOCATE st5;
+DEALLOCATE st6;
+DEALLOCATE st7;
+DEALLOCATE st8;
+-- System columns, except ctid and oid, should not be sent to remote
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'pg_class'::regclass LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Limit
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Filter: (t1.tableoid = '1259'::oid)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(6 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.tableoid = 'ft1'::regclass LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: (tableoid)::regclass, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ft1 t1 LIMIT 1;
+ tableoid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ ft1 | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((ctid = '(0,2)'))
+(3 rows)
+
+SELECT * FROM ft1 t1 WHERE t1.ctid = '(0,2)';
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1 t1
+ Output: ctid, c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" LIMIT 1::bigint
+(3 rows)
+
+SELECT ctid, * FROM ft1 t1 LIMIT 1;
+ ctid | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+-------+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ (0,1) | 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- ===================================================================
+-- used in PL/pgSQL function
+-- ===================================================================
+CREATE OR REPLACE FUNCTION f_test(p_c1 int) RETURNS int AS $$
+DECLARE
+ v_c1 int;
+BEGIN
+ SELECT c1 INTO v_c1 FROM ft1 WHERE c1 = p_c1 LIMIT 1;
+ PERFORM c1 FROM ft1 WHERE c1 = p_c1 AND p_c1 = v_c1 LIMIT 1;
+ RETURN v_c1;
+END;
+$$ LANGUAGE plpgsql;
+SELECT f_test(100);
+ f_test
+--------
+ 100
+(1 row)
+
+DROP FUNCTION f_test(int);
+-- ===================================================================
+-- REINDEX
+-- ===================================================================
+-- remote table is not created here
+CREATE FOREIGN TABLE reindex_foreign (c1 int, c2 int)
+ SERVER loopback2 OPTIONS (table_name 'reindex_local');
+REINDEX TABLE reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+REINDEX TABLE CONCURRENTLY reindex_foreign; -- error
+ERROR: "reindex_foreign" is not a table or materialized view
+DROP FOREIGN TABLE reindex_foreign;
+-- partitions and foreign tables
+CREATE TABLE reind_fdw_parent (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE reind_fdw_0_10 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (0) TO (10);
+CREATE FOREIGN TABLE reind_fdw_10_20 PARTITION OF reind_fdw_parent
+ FOR VALUES FROM (10) TO (20)
+ SERVER loopback OPTIONS (table_name 'reind_local_10_20');
+REINDEX TABLE reind_fdw_parent; -- ok
+REINDEX TABLE CONCURRENTLY reind_fdw_parent; -- ok
+DROP TABLE reind_fdw_parent;
+-- ===================================================================
+-- conversion error
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE int;
+SELECT * FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8) WHERE x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx.x8 FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "x8" of foreign table "ftx"
+SELECT ftx.x1, ft2.c2, ftx FROM ft1 ftx(x1,x2,x3,x4,x5,x6,x7,x8), ft2
+ WHERE ftx.x1 = ft2.c1 AND ftx.x1 = 1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: whole-row reference to foreign table "ftx"
+SELECT sum(c2), array_agg(c8) FROM ft1 GROUP BY c8; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: processing expression at position 2 in select list
+ANALYZE ft1; -- ERROR
+ERROR: invalid input syntax for type integer: "foo"
+CONTEXT: column "c8" of foreign table "ft1"
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- local type can be different from remote type in some cases,
+-- in particular if similarly-named operators do equivalent things
+-- ===================================================================
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE text;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 = 'foo')) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE c8 = 'foo' LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (('foo' = c8)) LIMIT 1::bigint
+(3 rows)
+
+SELECT * FROM ft1 WHERE 'foo' = c8 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+-- we declared c8 to be text locally, but it's still the same type on
+-- the remote which will balk if we try to do anything incompatible
+-- with that remote type
+SELECT * FROM ft1 WHERE c8 LIKE 'foo' LIMIT 1; -- ERROR
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+SELECT * FROM ft1 WHERE c8::text LIKE 'foo' LIMIT 1; -- ERROR; cast not pushed down
+ERROR: operator does not exist: public.user_enum ~~ unknown
+HINT: No operator matches the given name and argument types. You might need to add explicit type casts.
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE ((c8 ~~ 'foo')) LIMIT 1::bigint
+ALTER FOREIGN TABLE ft1 ALTER COLUMN c8 TYPE user_enum;
+-- ===================================================================
+-- subtransaction
+-- + local/remote error doesn't break cursor
+-- ===================================================================
+BEGIN;
+DECLARE c CURSOR FOR SELECT * FROM ft1 ORDER BY c1;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+SAVEPOINT s;
+ERROR OUT; -- ERROR
+ERROR: syntax error at or near "ERROR"
+LINE 1: ERROR OUT;
+ ^
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 2 | 2 | 00002 | Sat Jan 03 00:00:00 1970 PST | Sat Jan 03 00:00:00 1970 | 2 | 2 | foo
+(1 row)
+
+SAVEPOINT s;
+SELECT * FROM ft1 WHERE 1 / (c1 - 1) > 0; -- ERROR
+ERROR: division by zero
+CONTEXT: remote SQL command: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (((1 / ("C 1" - 1)) > 0))
+ROLLBACK TO s;
+FETCH c;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 3 | 3 | 00003 | Sun Jan 04 00:00:00 1970 PST | Sun Jan 04 00:00:00 1970 | 3 | 3 | foo
+(1 row)
+
+SELECT * FROM ft1 ORDER BY c1 LIMIT 1;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+----+----+-------+------------------------------+--------------------------+----+------------+-----
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST | Fri Jan 02 00:00:00 1970 | 1 | 1 | foo
+(1 row)
+
+COMMIT;
+-- ===================================================================
+-- test handling of collations
+-- ===================================================================
+create table loct3 (f1 text collate "C" unique, f2 text, f3 varchar(10) unique);
+create foreign table ft3 (f1 text collate "C", f2 text, f3 varchar(10))
+ server loopback options (table_name 'loct3', use_remote_estimate 'true');
+-- can be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "C" = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f1 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f2 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 where f3 = 'foo';
+ QUERY PLAN
+------------------------------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = 'foo'))
+(3 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 and l.f1 = 'foo';
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3 WHERE ((f3 = $1::character varying(10)))
+(8 rows)
+
+-- can't be sent to remote
+explain (verbose, costs off) select * from ft3 where f1 COLLATE "POSIX" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f1)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f1 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f1 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 COLLATE "C" = 'foo';
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: ((ft3.f2)::text = 'foo'::text)
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 where f2 = 'foo' COLLATE "C";
+ QUERY PLAN
+---------------------------------------------------
+ Foreign Scan on public.ft3
+ Output: f1, f2, f3
+ Filter: (ft3.f2 = 'foo'::text COLLATE "C")
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+(4 rows)
+
+explain (verbose, costs off) select * from ft3 f, loct3 l
+ where f.f3 = l.f3 COLLATE "POSIX" and l.f1 = 'foo';
+ QUERY PLAN
+-------------------------------------------------------------
+ Hash Join
+ Output: f.f1, f.f2, f.f3, l.f1, l.f2, l.f3
+ Inner Unique: true
+ Hash Cond: ((f.f3)::text = (l.f3)::text)
+ -> Foreign Scan on public.ft3 f
+ Output: f.f1, f.f2, f.f3
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct3
+ -> Hash
+ Output: l.f1, l.f2, l.f3
+ -> Index Scan using loct3_f1_key on public.loct3 l
+ Output: l.f1, l.f2, l.f3
+ Index Cond: (l.f1 = 'foo'::text)
+(12 rows)
+
+-- ===================================================================
+-- test writable foreign table stuff
+-- ===================================================================
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Subquery Scan on "*SELECT*"
+ Output: "*SELECT*"."?column?", "*SELECT*"."?column?_1", NULL::integer, "*SELECT*"."?column?_2", NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+ -> Foreign Scan on public.ft2 ft2_1
+ Output: (ft2_1.c1 + 1000), (ft2_1.c2 + 100), (ft2_1.c3 || ft2_1.c3)
+ Remote SQL: SELECT "C 1", c2, c3 FROM "S 1"."T 1" LIMIT 20::bigint
+(8 rows)
+
+INSERT INTO ft2 (c1,c2,c3) SELECT c1+1000,c2+100, c3 || c3 FROM ft2 LIMIT 20;
+INSERT INTO ft2 (c1,c2,c3)
+ VALUES (1101,201,'aaa'), (1102,202,'bbb'), (1103,203,'ccc') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----+----+----+----+------------+----
+ 1101 | 201 | aaa | | | | ft2 |
+ 1102 | 202 | bbb | | | | ft2 |
+ 1103 | 203 | ccc | | | | ft2 |
+(3 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1104,204,'ddd'), (1105,205,'eee');
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 300), c3 = (c3 || '_update3') WHERE ((("C 1" % 10) = 3))
+(3 rows)
+
+UPDATE ft2 SET c2 = c2 + 300, c3 = c3 || '_update3' WHERE c1 % 10 = 3;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = (c2 + 400), c3 = (c3 || '_update7') WHERE ((("C 1" % 10) = 7)) RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+(4 rows)
+
+UPDATE ft2 SET c2 = c2 + 400, c3 = c3 || '_update7' WHERE c1 % 10 = 7 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+----+------------+-----
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST | Thu Jan 08 00:00:00 1970 | 7 | 7 | foo
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST | Sun Jan 18 00:00:00 1970 | 7 | 7 | foo
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST | Wed Jan 28 00:00:00 1970 | 7 | 7 | foo
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST | Sat Feb 07 00:00:00 1970 | 7 | 7 | foo
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST | Tue Feb 17 00:00:00 1970 | 7 | 7 | foo
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST | Fri Feb 27 00:00:00 1970 | 7 | 7 | foo
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST | Mon Mar 09 00:00:00 1970 | 7 | 7 | foo
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST | Thu Mar 19 00:00:00 1970 | 7 | 7 | foo
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST | Sun Mar 29 00:00:00 1970 | 7 | 7 | foo
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST | Wed Apr 08 00:00:00 1970 | 7 | 7 | foo
+ 1007 | 507 | 0000700007_update7 | | | | ft2 |
+ 1017 | 507 | 0001700017_update7 | | | | ft2 |
+(102 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9; -- can be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c2 = (r1.c2 + 500), c3 = (r1.c3 || '_update9'), c7 = 'ft2 '::character(10) FROM "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 9))
+(3 rows)
+
+UPDATE ft2 SET c2 = ft2.c2 + 500, c3 = ft2.c3 || '_update9', c7 = DEFAULT
+ FROM ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 9;
+EXPLAIN (verbose, costs off)
+ DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: c1, c4
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ((("C 1" % 10) = 5)) RETURNING "C 1", c4
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 % 10 = 5 RETURNING c1, c4;
+ c1 | c4
+------+------------------------------
+ 5 | Tue Jan 06 00:00:00 1970 PST
+ 15 | Fri Jan 16 00:00:00 1970 PST
+ 25 | Mon Jan 26 00:00:00 1970 PST
+ 35 | Thu Feb 05 00:00:00 1970 PST
+ 45 | Sun Feb 15 00:00:00 1970 PST
+ 55 | Wed Feb 25 00:00:00 1970 PST
+ 65 | Sat Mar 07 00:00:00 1970 PST
+ 75 | Tue Mar 17 00:00:00 1970 PST
+ 85 | Fri Mar 27 00:00:00 1970 PST
+ 95 | Mon Apr 06 00:00:00 1970 PST
+ 105 | Tue Jan 06 00:00:00 1970 PST
+ 115 | Fri Jan 16 00:00:00 1970 PST
+ 125 | Mon Jan 26 00:00:00 1970 PST
+ 135 | Thu Feb 05 00:00:00 1970 PST
+ 145 | Sun Feb 15 00:00:00 1970 PST
+ 155 | Wed Feb 25 00:00:00 1970 PST
+ 165 | Sat Mar 07 00:00:00 1970 PST
+ 175 | Tue Mar 17 00:00:00 1970 PST
+ 185 | Fri Mar 27 00:00:00 1970 PST
+ 195 | Mon Apr 06 00:00:00 1970 PST
+ 205 | Tue Jan 06 00:00:00 1970 PST
+ 215 | Fri Jan 16 00:00:00 1970 PST
+ 225 | Mon Jan 26 00:00:00 1970 PST
+ 235 | Thu Feb 05 00:00:00 1970 PST
+ 245 | Sun Feb 15 00:00:00 1970 PST
+ 255 | Wed Feb 25 00:00:00 1970 PST
+ 265 | Sat Mar 07 00:00:00 1970 PST
+ 275 | Tue Mar 17 00:00:00 1970 PST
+ 285 | Fri Mar 27 00:00:00 1970 PST
+ 295 | Mon Apr 06 00:00:00 1970 PST
+ 305 | Tue Jan 06 00:00:00 1970 PST
+ 315 | Fri Jan 16 00:00:00 1970 PST
+ 325 | Mon Jan 26 00:00:00 1970 PST
+ 335 | Thu Feb 05 00:00:00 1970 PST
+ 345 | Sun Feb 15 00:00:00 1970 PST
+ 355 | Wed Feb 25 00:00:00 1970 PST
+ 365 | Sat Mar 07 00:00:00 1970 PST
+ 375 | Tue Mar 17 00:00:00 1970 PST
+ 385 | Fri Mar 27 00:00:00 1970 PST
+ 395 | Mon Apr 06 00:00:00 1970 PST
+ 405 | Tue Jan 06 00:00:00 1970 PST
+ 415 | Fri Jan 16 00:00:00 1970 PST
+ 425 | Mon Jan 26 00:00:00 1970 PST
+ 435 | Thu Feb 05 00:00:00 1970 PST
+ 445 | Sun Feb 15 00:00:00 1970 PST
+ 455 | Wed Feb 25 00:00:00 1970 PST
+ 465 | Sat Mar 07 00:00:00 1970 PST
+ 475 | Tue Mar 17 00:00:00 1970 PST
+ 485 | Fri Mar 27 00:00:00 1970 PST
+ 495 | Mon Apr 06 00:00:00 1970 PST
+ 505 | Tue Jan 06 00:00:00 1970 PST
+ 515 | Fri Jan 16 00:00:00 1970 PST
+ 525 | Mon Jan 26 00:00:00 1970 PST
+ 535 | Thu Feb 05 00:00:00 1970 PST
+ 545 | Sun Feb 15 00:00:00 1970 PST
+ 555 | Wed Feb 25 00:00:00 1970 PST
+ 565 | Sat Mar 07 00:00:00 1970 PST
+ 575 | Tue Mar 17 00:00:00 1970 PST
+ 585 | Fri Mar 27 00:00:00 1970 PST
+ 595 | Mon Apr 06 00:00:00 1970 PST
+ 605 | Tue Jan 06 00:00:00 1970 PST
+ 615 | Fri Jan 16 00:00:00 1970 PST
+ 625 | Mon Jan 26 00:00:00 1970 PST
+ 635 | Thu Feb 05 00:00:00 1970 PST
+ 645 | Sun Feb 15 00:00:00 1970 PST
+ 655 | Wed Feb 25 00:00:00 1970 PST
+ 665 | Sat Mar 07 00:00:00 1970 PST
+ 675 | Tue Mar 17 00:00:00 1970 PST
+ 685 | Fri Mar 27 00:00:00 1970 PST
+ 695 | Mon Apr 06 00:00:00 1970 PST
+ 705 | Tue Jan 06 00:00:00 1970 PST
+ 715 | Fri Jan 16 00:00:00 1970 PST
+ 725 | Mon Jan 26 00:00:00 1970 PST
+ 735 | Thu Feb 05 00:00:00 1970 PST
+ 745 | Sun Feb 15 00:00:00 1970 PST
+ 755 | Wed Feb 25 00:00:00 1970 PST
+ 765 | Sat Mar 07 00:00:00 1970 PST
+ 775 | Tue Mar 17 00:00:00 1970 PST
+ 785 | Fri Mar 27 00:00:00 1970 PST
+ 795 | Mon Apr 06 00:00:00 1970 PST
+ 805 | Tue Jan 06 00:00:00 1970 PST
+ 815 | Fri Jan 16 00:00:00 1970 PST
+ 825 | Mon Jan 26 00:00:00 1970 PST
+ 835 | Thu Feb 05 00:00:00 1970 PST
+ 845 | Sun Feb 15 00:00:00 1970 PST
+ 855 | Wed Feb 25 00:00:00 1970 PST
+ 865 | Sat Mar 07 00:00:00 1970 PST
+ 875 | Tue Mar 17 00:00:00 1970 PST
+ 885 | Fri Mar 27 00:00:00 1970 PST
+ 895 | Mon Apr 06 00:00:00 1970 PST
+ 905 | Tue Jan 06 00:00:00 1970 PST
+ 915 | Fri Jan 16 00:00:00 1970 PST
+ 925 | Mon Jan 26 00:00:00 1970 PST
+ 935 | Thu Feb 05 00:00:00 1970 PST
+ 945 | Sun Feb 15 00:00:00 1970 PST
+ 955 | Wed Feb 25 00:00:00 1970 PST
+ 965 | Sat Mar 07 00:00:00 1970 PST
+ 975 | Tue Mar 17 00:00:00 1970 PST
+ 985 | Fri Mar 27 00:00:00 1970 PST
+ 995 | Mon Apr 06 00:00:00 1970 PST
+ 1005 |
+ 1015 |
+ 1105 |
+(103 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING "S 1"."T 1" r2 WHERE ((r1.c2 = r2."C 1")) AND (((r2."C 1" % 10) = 2))
+(3 rows)
+
+DELETE FROM ft2 USING ft1 WHERE ft1.c1 = ft2.c2 AND ft1.c1 % 10 = 2;
+SELECT c1,c2,c3,c4 FROM ft2 ORDER BY c1;
+ c1 | c2 | c3 | c4
+------+-----+--------------------+------------------------------
+ 1 | 1 | 00001 | Fri Jan 02 00:00:00 1970 PST
+ 3 | 303 | 00003_update3 | Sun Jan 04 00:00:00 1970 PST
+ 4 | 4 | 00004 | Mon Jan 05 00:00:00 1970 PST
+ 6 | 6 | 00006 | Wed Jan 07 00:00:00 1970 PST
+ 7 | 407 | 00007_update7 | Thu Jan 08 00:00:00 1970 PST
+ 8 | 8 | 00008 | Fri Jan 09 00:00:00 1970 PST
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST
+ 10 | 0 | 00010 | Sun Jan 11 00:00:00 1970 PST
+ 11 | 1 | 00011 | Mon Jan 12 00:00:00 1970 PST
+ 13 | 303 | 00013_update3 | Wed Jan 14 00:00:00 1970 PST
+ 14 | 4 | 00014 | Thu Jan 15 00:00:00 1970 PST
+ 16 | 6 | 00016 | Sat Jan 17 00:00:00 1970 PST
+ 17 | 407 | 00017_update7 | Sun Jan 18 00:00:00 1970 PST
+ 18 | 8 | 00018 | Mon Jan 19 00:00:00 1970 PST
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST
+ 20 | 0 | 00020 | Wed Jan 21 00:00:00 1970 PST
+ 21 | 1 | 00021 | Thu Jan 22 00:00:00 1970 PST
+ 23 | 303 | 00023_update3 | Sat Jan 24 00:00:00 1970 PST
+ 24 | 4 | 00024 | Sun Jan 25 00:00:00 1970 PST
+ 26 | 6 | 00026 | Tue Jan 27 00:00:00 1970 PST
+ 27 | 407 | 00027_update7 | Wed Jan 28 00:00:00 1970 PST
+ 28 | 8 | 00028 | Thu Jan 29 00:00:00 1970 PST
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST
+ 30 | 0 | 00030 | Sat Jan 31 00:00:00 1970 PST
+ 31 | 1 | 00031 | Sun Feb 01 00:00:00 1970 PST
+ 33 | 303 | 00033_update3 | Tue Feb 03 00:00:00 1970 PST
+ 34 | 4 | 00034 | Wed Feb 04 00:00:00 1970 PST
+ 36 | 6 | 00036 | Fri Feb 06 00:00:00 1970 PST
+ 37 | 407 | 00037_update7 | Sat Feb 07 00:00:00 1970 PST
+ 38 | 8 | 00038 | Sun Feb 08 00:00:00 1970 PST
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST
+ 40 | 0 | 00040 | Tue Feb 10 00:00:00 1970 PST
+ 41 | 1 | 00041 | Wed Feb 11 00:00:00 1970 PST
+ 43 | 303 | 00043_update3 | Fri Feb 13 00:00:00 1970 PST
+ 44 | 4 | 00044 | Sat Feb 14 00:00:00 1970 PST
+ 46 | 6 | 00046 | Mon Feb 16 00:00:00 1970 PST
+ 47 | 407 | 00047_update7 | Tue Feb 17 00:00:00 1970 PST
+ 48 | 8 | 00048 | Wed Feb 18 00:00:00 1970 PST
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST
+ 50 | 0 | 00050 | Fri Feb 20 00:00:00 1970 PST
+ 51 | 1 | 00051 | Sat Feb 21 00:00:00 1970 PST
+ 53 | 303 | 00053_update3 | Mon Feb 23 00:00:00 1970 PST
+ 54 | 4 | 00054 | Tue Feb 24 00:00:00 1970 PST
+ 56 | 6 | 00056 | Thu Feb 26 00:00:00 1970 PST
+ 57 | 407 | 00057_update7 | Fri Feb 27 00:00:00 1970 PST
+ 58 | 8 | 00058 | Sat Feb 28 00:00:00 1970 PST
+ 59 | 509 | 00059_update9 | Sun Mar 01 00:00:00 1970 PST
+ 60 | 0 | 00060 | Mon Mar 02 00:00:00 1970 PST
+ 61 | 1 | 00061 | Tue Mar 03 00:00:00 1970 PST
+ 63 | 303 | 00063_update3 | Thu Mar 05 00:00:00 1970 PST
+ 64 | 4 | 00064 | Fri Mar 06 00:00:00 1970 PST
+ 66 | 6 | 00066 | Sun Mar 08 00:00:00 1970 PST
+ 67 | 407 | 00067_update7 | Mon Mar 09 00:00:00 1970 PST
+ 68 | 8 | 00068 | Tue Mar 10 00:00:00 1970 PST
+ 69 | 509 | 00069_update9 | Wed Mar 11 00:00:00 1970 PST
+ 70 | 0 | 00070 | Thu Mar 12 00:00:00 1970 PST
+ 71 | 1 | 00071 | Fri Mar 13 00:00:00 1970 PST
+ 73 | 303 | 00073_update3 | Sun Mar 15 00:00:00 1970 PST
+ 74 | 4 | 00074 | Mon Mar 16 00:00:00 1970 PST
+ 76 | 6 | 00076 | Wed Mar 18 00:00:00 1970 PST
+ 77 | 407 | 00077_update7 | Thu Mar 19 00:00:00 1970 PST
+ 78 | 8 | 00078 | Fri Mar 20 00:00:00 1970 PST
+ 79 | 509 | 00079_update9 | Sat Mar 21 00:00:00 1970 PST
+ 80 | 0 | 00080 | Sun Mar 22 00:00:00 1970 PST
+ 81 | 1 | 00081 | Mon Mar 23 00:00:00 1970 PST
+ 83 | 303 | 00083_update3 | Wed Mar 25 00:00:00 1970 PST
+ 84 | 4 | 00084 | Thu Mar 26 00:00:00 1970 PST
+ 86 | 6 | 00086 | Sat Mar 28 00:00:00 1970 PST
+ 87 | 407 | 00087_update7 | Sun Mar 29 00:00:00 1970 PST
+ 88 | 8 | 00088 | Mon Mar 30 00:00:00 1970 PST
+ 89 | 509 | 00089_update9 | Tue Mar 31 00:00:00 1970 PST
+ 90 | 0 | 00090 | Wed Apr 01 00:00:00 1970 PST
+ 91 | 1 | 00091 | Thu Apr 02 00:00:00 1970 PST
+ 93 | 303 | 00093_update3 | Sat Apr 04 00:00:00 1970 PST
+ 94 | 4 | 00094 | Sun Apr 05 00:00:00 1970 PST
+ 96 | 6 | 00096 | Tue Apr 07 00:00:00 1970 PST
+ 97 | 407 | 00097_update7 | Wed Apr 08 00:00:00 1970 PST
+ 98 | 8 | 00098 | Thu Apr 09 00:00:00 1970 PST
+ 99 | 509 | 00099_update9 | Fri Apr 10 00:00:00 1970 PST
+ 100 | 0 | 00100 | Thu Jan 01 00:00:00 1970 PST
+ 101 | 1 | 00101 | Fri Jan 02 00:00:00 1970 PST
+ 103 | 303 | 00103_update3 | Sun Jan 04 00:00:00 1970 PST
+ 104 | 4 | 00104 | Mon Jan 05 00:00:00 1970 PST
+ 106 | 6 | 00106 | Wed Jan 07 00:00:00 1970 PST
+ 107 | 407 | 00107_update7 | Thu Jan 08 00:00:00 1970 PST
+ 108 | 8 | 00108 | Fri Jan 09 00:00:00 1970 PST
+ 109 | 509 | 00109_update9 | Sat Jan 10 00:00:00 1970 PST
+ 110 | 0 | 00110 | Sun Jan 11 00:00:00 1970 PST
+ 111 | 1 | 00111 | Mon Jan 12 00:00:00 1970 PST
+ 113 | 303 | 00113_update3 | Wed Jan 14 00:00:00 1970 PST
+ 114 | 4 | 00114 | Thu Jan 15 00:00:00 1970 PST
+ 116 | 6 | 00116 | Sat Jan 17 00:00:00 1970 PST
+ 117 | 407 | 00117_update7 | Sun Jan 18 00:00:00 1970 PST
+ 118 | 8 | 00118 | Mon Jan 19 00:00:00 1970 PST
+ 119 | 509 | 00119_update9 | Tue Jan 20 00:00:00 1970 PST
+ 120 | 0 | 00120 | Wed Jan 21 00:00:00 1970 PST
+ 121 | 1 | 00121 | Thu Jan 22 00:00:00 1970 PST
+ 123 | 303 | 00123_update3 | Sat Jan 24 00:00:00 1970 PST
+ 124 | 4 | 00124 | Sun Jan 25 00:00:00 1970 PST
+ 126 | 6 | 00126 | Tue Jan 27 00:00:00 1970 PST
+ 127 | 407 | 00127_update7 | Wed Jan 28 00:00:00 1970 PST
+ 128 | 8 | 00128 | Thu Jan 29 00:00:00 1970 PST
+ 129 | 509 | 00129_update9 | Fri Jan 30 00:00:00 1970 PST
+ 130 | 0 | 00130 | Sat Jan 31 00:00:00 1970 PST
+ 131 | 1 | 00131 | Sun Feb 01 00:00:00 1970 PST
+ 133 | 303 | 00133_update3 | Tue Feb 03 00:00:00 1970 PST
+ 134 | 4 | 00134 | Wed Feb 04 00:00:00 1970 PST
+ 136 | 6 | 00136 | Fri Feb 06 00:00:00 1970 PST
+ 137 | 407 | 00137_update7 | Sat Feb 07 00:00:00 1970 PST
+ 138 | 8 | 00138 | Sun Feb 08 00:00:00 1970 PST
+ 139 | 509 | 00139_update9 | Mon Feb 09 00:00:00 1970 PST
+ 140 | 0 | 00140 | Tue Feb 10 00:00:00 1970 PST
+ 141 | 1 | 00141 | Wed Feb 11 00:00:00 1970 PST
+ 143 | 303 | 00143_update3 | Fri Feb 13 00:00:00 1970 PST
+ 144 | 4 | 00144 | Sat Feb 14 00:00:00 1970 PST
+ 146 | 6 | 00146 | Mon Feb 16 00:00:00 1970 PST
+ 147 | 407 | 00147_update7 | Tue Feb 17 00:00:00 1970 PST
+ 148 | 8 | 00148 | Wed Feb 18 00:00:00 1970 PST
+ 149 | 509 | 00149_update9 | Thu Feb 19 00:00:00 1970 PST
+ 150 | 0 | 00150 | Fri Feb 20 00:00:00 1970 PST
+ 151 | 1 | 00151 | Sat Feb 21 00:00:00 1970 PST
+ 153 | 303 | 00153_update3 | Mon Feb 23 00:00:00 1970 PST
+ 154 | 4 | 00154 | Tue Feb 24 00:00:00 1970 PST
+ 156 | 6 | 00156 | Thu Feb 26 00:00:00 1970 PST
+ 157 | 407 | 00157_update7 | Fri Feb 27 00:00:00 1970 PST
+ 158 | 8 | 00158 | Sat Feb 28 00:00:00 1970 PST
+ 159 | 509 | 00159_update9 | Sun Mar 01 00:00:00 1970 PST
+ 160 | 0 | 00160 | Mon Mar 02 00:00:00 1970 PST
+ 161 | 1 | 00161 | Tue Mar 03 00:00:00 1970 PST
+ 163 | 303 | 00163_update3 | Thu Mar 05 00:00:00 1970 PST
+ 164 | 4 | 00164 | Fri Mar 06 00:00:00 1970 PST
+ 166 | 6 | 00166 | Sun Mar 08 00:00:00 1970 PST
+ 167 | 407 | 00167_update7 | Mon Mar 09 00:00:00 1970 PST
+ 168 | 8 | 00168 | Tue Mar 10 00:00:00 1970 PST
+ 169 | 509 | 00169_update9 | Wed Mar 11 00:00:00 1970 PST
+ 170 | 0 | 00170 | Thu Mar 12 00:00:00 1970 PST
+ 171 | 1 | 00171 | Fri Mar 13 00:00:00 1970 PST
+ 173 | 303 | 00173_update3 | Sun Mar 15 00:00:00 1970 PST
+ 174 | 4 | 00174 | Mon Mar 16 00:00:00 1970 PST
+ 176 | 6 | 00176 | Wed Mar 18 00:00:00 1970 PST
+ 177 | 407 | 00177_update7 | Thu Mar 19 00:00:00 1970 PST
+ 178 | 8 | 00178 | Fri Mar 20 00:00:00 1970 PST
+ 179 | 509 | 00179_update9 | Sat Mar 21 00:00:00 1970 PST
+ 180 | 0 | 00180 | Sun Mar 22 00:00:00 1970 PST
+ 181 | 1 | 00181 | Mon Mar 23 00:00:00 1970 PST
+ 183 | 303 | 00183_update3 | Wed Mar 25 00:00:00 1970 PST
+ 184 | 4 | 00184 | Thu Mar 26 00:00:00 1970 PST
+ 186 | 6 | 00186 | Sat Mar 28 00:00:00 1970 PST
+ 187 | 407 | 00187_update7 | Sun Mar 29 00:00:00 1970 PST
+ 188 | 8 | 00188 | Mon Mar 30 00:00:00 1970 PST
+ 189 | 509 | 00189_update9 | Tue Mar 31 00:00:00 1970 PST
+ 190 | 0 | 00190 | Wed Apr 01 00:00:00 1970 PST
+ 191 | 1 | 00191 | Thu Apr 02 00:00:00 1970 PST
+ 193 | 303 | 00193_update3 | Sat Apr 04 00:00:00 1970 PST
+ 194 | 4 | 00194 | Sun Apr 05 00:00:00 1970 PST
+ 196 | 6 | 00196 | Tue Apr 07 00:00:00 1970 PST
+ 197 | 407 | 00197_update7 | Wed Apr 08 00:00:00 1970 PST
+ 198 | 8 | 00198 | Thu Apr 09 00:00:00 1970 PST
+ 199 | 509 | 00199_update9 | Fri Apr 10 00:00:00 1970 PST
+ 200 | 0 | 00200 | Thu Jan 01 00:00:00 1970 PST
+ 201 | 1 | 00201 | Fri Jan 02 00:00:00 1970 PST
+ 203 | 303 | 00203_update3 | Sun Jan 04 00:00:00 1970 PST
+ 204 | 4 | 00204 | Mon Jan 05 00:00:00 1970 PST
+ 206 | 6 | 00206 | Wed Jan 07 00:00:00 1970 PST
+ 207 | 407 | 00207_update7 | Thu Jan 08 00:00:00 1970 PST
+ 208 | 8 | 00208 | Fri Jan 09 00:00:00 1970 PST
+ 209 | 509 | 00209_update9 | Sat Jan 10 00:00:00 1970 PST
+ 210 | 0 | 00210 | Sun Jan 11 00:00:00 1970 PST
+ 211 | 1 | 00211 | Mon Jan 12 00:00:00 1970 PST
+ 213 | 303 | 00213_update3 | Wed Jan 14 00:00:00 1970 PST
+ 214 | 4 | 00214 | Thu Jan 15 00:00:00 1970 PST
+ 216 | 6 | 00216 | Sat Jan 17 00:00:00 1970 PST
+ 217 | 407 | 00217_update7 | Sun Jan 18 00:00:00 1970 PST
+ 218 | 8 | 00218 | Mon Jan 19 00:00:00 1970 PST
+ 219 | 509 | 00219_update9 | Tue Jan 20 00:00:00 1970 PST
+ 220 | 0 | 00220 | Wed Jan 21 00:00:00 1970 PST
+ 221 | 1 | 00221 | Thu Jan 22 00:00:00 1970 PST
+ 223 | 303 | 00223_update3 | Sat Jan 24 00:00:00 1970 PST
+ 224 | 4 | 00224 | Sun Jan 25 00:00:00 1970 PST
+ 226 | 6 | 00226 | Tue Jan 27 00:00:00 1970 PST
+ 227 | 407 | 00227_update7 | Wed Jan 28 00:00:00 1970 PST
+ 228 | 8 | 00228 | Thu Jan 29 00:00:00 1970 PST
+ 229 | 509 | 00229_update9 | Fri Jan 30 00:00:00 1970 PST
+ 230 | 0 | 00230 | Sat Jan 31 00:00:00 1970 PST
+ 231 | 1 | 00231 | Sun Feb 01 00:00:00 1970 PST
+ 233 | 303 | 00233_update3 | Tue Feb 03 00:00:00 1970 PST
+ 234 | 4 | 00234 | Wed Feb 04 00:00:00 1970 PST
+ 236 | 6 | 00236 | Fri Feb 06 00:00:00 1970 PST
+ 237 | 407 | 00237_update7 | Sat Feb 07 00:00:00 1970 PST
+ 238 | 8 | 00238 | Sun Feb 08 00:00:00 1970 PST
+ 239 | 509 | 00239_update9 | Mon Feb 09 00:00:00 1970 PST
+ 240 | 0 | 00240 | Tue Feb 10 00:00:00 1970 PST
+ 241 | 1 | 00241 | Wed Feb 11 00:00:00 1970 PST
+ 243 | 303 | 00243_update3 | Fri Feb 13 00:00:00 1970 PST
+ 244 | 4 | 00244 | Sat Feb 14 00:00:00 1970 PST
+ 246 | 6 | 00246 | Mon Feb 16 00:00:00 1970 PST
+ 247 | 407 | 00247_update7 | Tue Feb 17 00:00:00 1970 PST
+ 248 | 8 | 00248 | Wed Feb 18 00:00:00 1970 PST
+ 249 | 509 | 00249_update9 | Thu Feb 19 00:00:00 1970 PST
+ 250 | 0 | 00250 | Fri Feb 20 00:00:00 1970 PST
+ 251 | 1 | 00251 | Sat Feb 21 00:00:00 1970 PST
+ 253 | 303 | 00253_update3 | Mon Feb 23 00:00:00 1970 PST
+ 254 | 4 | 00254 | Tue Feb 24 00:00:00 1970 PST
+ 256 | 6 | 00256 | Thu Feb 26 00:00:00 1970 PST
+ 257 | 407 | 00257_update7 | Fri Feb 27 00:00:00 1970 PST
+ 258 | 8 | 00258 | Sat Feb 28 00:00:00 1970 PST
+ 259 | 509 | 00259_update9 | Sun Mar 01 00:00:00 1970 PST
+ 260 | 0 | 00260 | Mon Mar 02 00:00:00 1970 PST
+ 261 | 1 | 00261 | Tue Mar 03 00:00:00 1970 PST
+ 263 | 303 | 00263_update3 | Thu Mar 05 00:00:00 1970 PST
+ 264 | 4 | 00264 | Fri Mar 06 00:00:00 1970 PST
+ 266 | 6 | 00266 | Sun Mar 08 00:00:00 1970 PST
+ 267 | 407 | 00267_update7 | Mon Mar 09 00:00:00 1970 PST
+ 268 | 8 | 00268 | Tue Mar 10 00:00:00 1970 PST
+ 269 | 509 | 00269_update9 | Wed Mar 11 00:00:00 1970 PST
+ 270 | 0 | 00270 | Thu Mar 12 00:00:00 1970 PST
+ 271 | 1 | 00271 | Fri Mar 13 00:00:00 1970 PST
+ 273 | 303 | 00273_update3 | Sun Mar 15 00:00:00 1970 PST
+ 274 | 4 | 00274 | Mon Mar 16 00:00:00 1970 PST
+ 276 | 6 | 00276 | Wed Mar 18 00:00:00 1970 PST
+ 277 | 407 | 00277_update7 | Thu Mar 19 00:00:00 1970 PST
+ 278 | 8 | 00278 | Fri Mar 20 00:00:00 1970 PST
+ 279 | 509 | 00279_update9 | Sat Mar 21 00:00:00 1970 PST
+ 280 | 0 | 00280 | Sun Mar 22 00:00:00 1970 PST
+ 281 | 1 | 00281 | Mon Mar 23 00:00:00 1970 PST
+ 283 | 303 | 00283_update3 | Wed Mar 25 00:00:00 1970 PST
+ 284 | 4 | 00284 | Thu Mar 26 00:00:00 1970 PST
+ 286 | 6 | 00286 | Sat Mar 28 00:00:00 1970 PST
+ 287 | 407 | 00287_update7 | Sun Mar 29 00:00:00 1970 PST
+ 288 | 8 | 00288 | Mon Mar 30 00:00:00 1970 PST
+ 289 | 509 | 00289_update9 | Tue Mar 31 00:00:00 1970 PST
+ 290 | 0 | 00290 | Wed Apr 01 00:00:00 1970 PST
+ 291 | 1 | 00291 | Thu Apr 02 00:00:00 1970 PST
+ 293 | 303 | 00293_update3 | Sat Apr 04 00:00:00 1970 PST
+ 294 | 4 | 00294 | Sun Apr 05 00:00:00 1970 PST
+ 296 | 6 | 00296 | Tue Apr 07 00:00:00 1970 PST
+ 297 | 407 | 00297_update7 | Wed Apr 08 00:00:00 1970 PST
+ 298 | 8 | 00298 | Thu Apr 09 00:00:00 1970 PST
+ 299 | 509 | 00299_update9 | Fri Apr 10 00:00:00 1970 PST
+ 300 | 0 | 00300 | Thu Jan 01 00:00:00 1970 PST
+ 301 | 1 | 00301 | Fri Jan 02 00:00:00 1970 PST
+ 303 | 303 | 00303_update3 | Sun Jan 04 00:00:00 1970 PST
+ 304 | 4 | 00304 | Mon Jan 05 00:00:00 1970 PST
+ 306 | 6 | 00306 | Wed Jan 07 00:00:00 1970 PST
+ 307 | 407 | 00307_update7 | Thu Jan 08 00:00:00 1970 PST
+ 308 | 8 | 00308 | Fri Jan 09 00:00:00 1970 PST
+ 309 | 509 | 00309_update9 | Sat Jan 10 00:00:00 1970 PST
+ 310 | 0 | 00310 | Sun Jan 11 00:00:00 1970 PST
+ 311 | 1 | 00311 | Mon Jan 12 00:00:00 1970 PST
+ 313 | 303 | 00313_update3 | Wed Jan 14 00:00:00 1970 PST
+ 314 | 4 | 00314 | Thu Jan 15 00:00:00 1970 PST
+ 316 | 6 | 00316 | Sat Jan 17 00:00:00 1970 PST
+ 317 | 407 | 00317_update7 | Sun Jan 18 00:00:00 1970 PST
+ 318 | 8 | 00318 | Mon Jan 19 00:00:00 1970 PST
+ 319 | 509 | 00319_update9 | Tue Jan 20 00:00:00 1970 PST
+ 320 | 0 | 00320 | Wed Jan 21 00:00:00 1970 PST
+ 321 | 1 | 00321 | Thu Jan 22 00:00:00 1970 PST
+ 323 | 303 | 00323_update3 | Sat Jan 24 00:00:00 1970 PST
+ 324 | 4 | 00324 | Sun Jan 25 00:00:00 1970 PST
+ 326 | 6 | 00326 | Tue Jan 27 00:00:00 1970 PST
+ 327 | 407 | 00327_update7 | Wed Jan 28 00:00:00 1970 PST
+ 328 | 8 | 00328 | Thu Jan 29 00:00:00 1970 PST
+ 329 | 509 | 00329_update9 | Fri Jan 30 00:00:00 1970 PST
+ 330 | 0 | 00330 | Sat Jan 31 00:00:00 1970 PST
+ 331 | 1 | 00331 | Sun Feb 01 00:00:00 1970 PST
+ 333 | 303 | 00333_update3 | Tue Feb 03 00:00:00 1970 PST
+ 334 | 4 | 00334 | Wed Feb 04 00:00:00 1970 PST
+ 336 | 6 | 00336 | Fri Feb 06 00:00:00 1970 PST
+ 337 | 407 | 00337_update7 | Sat Feb 07 00:00:00 1970 PST
+ 338 | 8 | 00338 | Sun Feb 08 00:00:00 1970 PST
+ 339 | 509 | 00339_update9 | Mon Feb 09 00:00:00 1970 PST
+ 340 | 0 | 00340 | Tue Feb 10 00:00:00 1970 PST
+ 341 | 1 | 00341 | Wed Feb 11 00:00:00 1970 PST
+ 343 | 303 | 00343_update3 | Fri Feb 13 00:00:00 1970 PST
+ 344 | 4 | 00344 | Sat Feb 14 00:00:00 1970 PST
+ 346 | 6 | 00346 | Mon Feb 16 00:00:00 1970 PST
+ 347 | 407 | 00347_update7 | Tue Feb 17 00:00:00 1970 PST
+ 348 | 8 | 00348 | Wed Feb 18 00:00:00 1970 PST
+ 349 | 509 | 00349_update9 | Thu Feb 19 00:00:00 1970 PST
+ 350 | 0 | 00350 | Fri Feb 20 00:00:00 1970 PST
+ 351 | 1 | 00351 | Sat Feb 21 00:00:00 1970 PST
+ 353 | 303 | 00353_update3 | Mon Feb 23 00:00:00 1970 PST
+ 354 | 4 | 00354 | Tue Feb 24 00:00:00 1970 PST
+ 356 | 6 | 00356 | Thu Feb 26 00:00:00 1970 PST
+ 357 | 407 | 00357_update7 | Fri Feb 27 00:00:00 1970 PST
+ 358 | 8 | 00358 | Sat Feb 28 00:00:00 1970 PST
+ 359 | 509 | 00359_update9 | Sun Mar 01 00:00:00 1970 PST
+ 360 | 0 | 00360 | Mon Mar 02 00:00:00 1970 PST
+ 361 | 1 | 00361 | Tue Mar 03 00:00:00 1970 PST
+ 363 | 303 | 00363_update3 | Thu Mar 05 00:00:00 1970 PST
+ 364 | 4 | 00364 | Fri Mar 06 00:00:00 1970 PST
+ 366 | 6 | 00366 | Sun Mar 08 00:00:00 1970 PST
+ 367 | 407 | 00367_update7 | Mon Mar 09 00:00:00 1970 PST
+ 368 | 8 | 00368 | Tue Mar 10 00:00:00 1970 PST
+ 369 | 509 | 00369_update9 | Wed Mar 11 00:00:00 1970 PST
+ 370 | 0 | 00370 | Thu Mar 12 00:00:00 1970 PST
+ 371 | 1 | 00371 | Fri Mar 13 00:00:00 1970 PST
+ 373 | 303 | 00373_update3 | Sun Mar 15 00:00:00 1970 PST
+ 374 | 4 | 00374 | Mon Mar 16 00:00:00 1970 PST
+ 376 | 6 | 00376 | Wed Mar 18 00:00:00 1970 PST
+ 377 | 407 | 00377_update7 | Thu Mar 19 00:00:00 1970 PST
+ 378 | 8 | 00378 | Fri Mar 20 00:00:00 1970 PST
+ 379 | 509 | 00379_update9 | Sat Mar 21 00:00:00 1970 PST
+ 380 | 0 | 00380 | Sun Mar 22 00:00:00 1970 PST
+ 381 | 1 | 00381 | Mon Mar 23 00:00:00 1970 PST
+ 383 | 303 | 00383_update3 | Wed Mar 25 00:00:00 1970 PST
+ 384 | 4 | 00384 | Thu Mar 26 00:00:00 1970 PST
+ 386 | 6 | 00386 | Sat Mar 28 00:00:00 1970 PST
+ 387 | 407 | 00387_update7 | Sun Mar 29 00:00:00 1970 PST
+ 388 | 8 | 00388 | Mon Mar 30 00:00:00 1970 PST
+ 389 | 509 | 00389_update9 | Tue Mar 31 00:00:00 1970 PST
+ 390 | 0 | 00390 | Wed Apr 01 00:00:00 1970 PST
+ 391 | 1 | 00391 | Thu Apr 02 00:00:00 1970 PST
+ 393 | 303 | 00393_update3 | Sat Apr 04 00:00:00 1970 PST
+ 394 | 4 | 00394 | Sun Apr 05 00:00:00 1970 PST
+ 396 | 6 | 00396 | Tue Apr 07 00:00:00 1970 PST
+ 397 | 407 | 00397_update7 | Wed Apr 08 00:00:00 1970 PST
+ 398 | 8 | 00398 | Thu Apr 09 00:00:00 1970 PST
+ 399 | 509 | 00399_update9 | Fri Apr 10 00:00:00 1970 PST
+ 400 | 0 | 00400 | Thu Jan 01 00:00:00 1970 PST
+ 401 | 1 | 00401 | Fri Jan 02 00:00:00 1970 PST
+ 403 | 303 | 00403_update3 | Sun Jan 04 00:00:00 1970 PST
+ 404 | 4 | 00404 | Mon Jan 05 00:00:00 1970 PST
+ 406 | 6 | 00406 | Wed Jan 07 00:00:00 1970 PST
+ 407 | 407 | 00407_update7 | Thu Jan 08 00:00:00 1970 PST
+ 408 | 8 | 00408 | Fri Jan 09 00:00:00 1970 PST
+ 409 | 509 | 00409_update9 | Sat Jan 10 00:00:00 1970 PST
+ 410 | 0 | 00410 | Sun Jan 11 00:00:00 1970 PST
+ 411 | 1 | 00411 | Mon Jan 12 00:00:00 1970 PST
+ 413 | 303 | 00413_update3 | Wed Jan 14 00:00:00 1970 PST
+ 414 | 4 | 00414 | Thu Jan 15 00:00:00 1970 PST
+ 416 | 6 | 00416 | Sat Jan 17 00:00:00 1970 PST
+ 417 | 407 | 00417_update7 | Sun Jan 18 00:00:00 1970 PST
+ 418 | 8 | 00418 | Mon Jan 19 00:00:00 1970 PST
+ 419 | 509 | 00419_update9 | Tue Jan 20 00:00:00 1970 PST
+ 420 | 0 | 00420 | Wed Jan 21 00:00:00 1970 PST
+ 421 | 1 | 00421 | Thu Jan 22 00:00:00 1970 PST
+ 423 | 303 | 00423_update3 | Sat Jan 24 00:00:00 1970 PST
+ 424 | 4 | 00424 | Sun Jan 25 00:00:00 1970 PST
+ 426 | 6 | 00426 | Tue Jan 27 00:00:00 1970 PST
+ 427 | 407 | 00427_update7 | Wed Jan 28 00:00:00 1970 PST
+ 428 | 8 | 00428 | Thu Jan 29 00:00:00 1970 PST
+ 429 | 509 | 00429_update9 | Fri Jan 30 00:00:00 1970 PST
+ 430 | 0 | 00430 | Sat Jan 31 00:00:00 1970 PST
+ 431 | 1 | 00431 | Sun Feb 01 00:00:00 1970 PST
+ 433 | 303 | 00433_update3 | Tue Feb 03 00:00:00 1970 PST
+ 434 | 4 | 00434 | Wed Feb 04 00:00:00 1970 PST
+ 436 | 6 | 00436 | Fri Feb 06 00:00:00 1970 PST
+ 437 | 407 | 00437_update7 | Sat Feb 07 00:00:00 1970 PST
+ 438 | 8 | 00438 | Sun Feb 08 00:00:00 1970 PST
+ 439 | 509 | 00439_update9 | Mon Feb 09 00:00:00 1970 PST
+ 440 | 0 | 00440 | Tue Feb 10 00:00:00 1970 PST
+ 441 | 1 | 00441 | Wed Feb 11 00:00:00 1970 PST
+ 443 | 303 | 00443_update3 | Fri Feb 13 00:00:00 1970 PST
+ 444 | 4 | 00444 | Sat Feb 14 00:00:00 1970 PST
+ 446 | 6 | 00446 | Mon Feb 16 00:00:00 1970 PST
+ 447 | 407 | 00447_update7 | Tue Feb 17 00:00:00 1970 PST
+ 448 | 8 | 00448 | Wed Feb 18 00:00:00 1970 PST
+ 449 | 509 | 00449_update9 | Thu Feb 19 00:00:00 1970 PST
+ 450 | 0 | 00450 | Fri Feb 20 00:00:00 1970 PST
+ 451 | 1 | 00451 | Sat Feb 21 00:00:00 1970 PST
+ 453 | 303 | 00453_update3 | Mon Feb 23 00:00:00 1970 PST
+ 454 | 4 | 00454 | Tue Feb 24 00:00:00 1970 PST
+ 456 | 6 | 00456 | Thu Feb 26 00:00:00 1970 PST
+ 457 | 407 | 00457_update7 | Fri Feb 27 00:00:00 1970 PST
+ 458 | 8 | 00458 | Sat Feb 28 00:00:00 1970 PST
+ 459 | 509 | 00459_update9 | Sun Mar 01 00:00:00 1970 PST
+ 460 | 0 | 00460 | Mon Mar 02 00:00:00 1970 PST
+ 461 | 1 | 00461 | Tue Mar 03 00:00:00 1970 PST
+ 463 | 303 | 00463_update3 | Thu Mar 05 00:00:00 1970 PST
+ 464 | 4 | 00464 | Fri Mar 06 00:00:00 1970 PST
+ 466 | 6 | 00466 | Sun Mar 08 00:00:00 1970 PST
+ 467 | 407 | 00467_update7 | Mon Mar 09 00:00:00 1970 PST
+ 468 | 8 | 00468 | Tue Mar 10 00:00:00 1970 PST
+ 469 | 509 | 00469_update9 | Wed Mar 11 00:00:00 1970 PST
+ 470 | 0 | 00470 | Thu Mar 12 00:00:00 1970 PST
+ 471 | 1 | 00471 | Fri Mar 13 00:00:00 1970 PST
+ 473 | 303 | 00473_update3 | Sun Mar 15 00:00:00 1970 PST
+ 474 | 4 | 00474 | Mon Mar 16 00:00:00 1970 PST
+ 476 | 6 | 00476 | Wed Mar 18 00:00:00 1970 PST
+ 477 | 407 | 00477_update7 | Thu Mar 19 00:00:00 1970 PST
+ 478 | 8 | 00478 | Fri Mar 20 00:00:00 1970 PST
+ 479 | 509 | 00479_update9 | Sat Mar 21 00:00:00 1970 PST
+ 480 | 0 | 00480 | Sun Mar 22 00:00:00 1970 PST
+ 481 | 1 | 00481 | Mon Mar 23 00:00:00 1970 PST
+ 483 | 303 | 00483_update3 | Wed Mar 25 00:00:00 1970 PST
+ 484 | 4 | 00484 | Thu Mar 26 00:00:00 1970 PST
+ 486 | 6 | 00486 | Sat Mar 28 00:00:00 1970 PST
+ 487 | 407 | 00487_update7 | Sun Mar 29 00:00:00 1970 PST
+ 488 | 8 | 00488 | Mon Mar 30 00:00:00 1970 PST
+ 489 | 509 | 00489_update9 | Tue Mar 31 00:00:00 1970 PST
+ 490 | 0 | 00490 | Wed Apr 01 00:00:00 1970 PST
+ 491 | 1 | 00491 | Thu Apr 02 00:00:00 1970 PST
+ 493 | 303 | 00493_update3 | Sat Apr 04 00:00:00 1970 PST
+ 494 | 4 | 00494 | Sun Apr 05 00:00:00 1970 PST
+ 496 | 6 | 00496 | Tue Apr 07 00:00:00 1970 PST
+ 497 | 407 | 00497_update7 | Wed Apr 08 00:00:00 1970 PST
+ 498 | 8 | 00498 | Thu Apr 09 00:00:00 1970 PST
+ 499 | 509 | 00499_update9 | Fri Apr 10 00:00:00 1970 PST
+ 500 | 0 | 00500 | Thu Jan 01 00:00:00 1970 PST
+ 501 | 1 | 00501 | Fri Jan 02 00:00:00 1970 PST
+ 503 | 303 | 00503_update3 | Sun Jan 04 00:00:00 1970 PST
+ 504 | 4 | 00504 | Mon Jan 05 00:00:00 1970 PST
+ 506 | 6 | 00506 | Wed Jan 07 00:00:00 1970 PST
+ 507 | 407 | 00507_update7 | Thu Jan 08 00:00:00 1970 PST
+ 508 | 8 | 00508 | Fri Jan 09 00:00:00 1970 PST
+ 509 | 509 | 00509_update9 | Sat Jan 10 00:00:00 1970 PST
+ 510 | 0 | 00510 | Sun Jan 11 00:00:00 1970 PST
+ 511 | 1 | 00511 | Mon Jan 12 00:00:00 1970 PST
+ 513 | 303 | 00513_update3 | Wed Jan 14 00:00:00 1970 PST
+ 514 | 4 | 00514 | Thu Jan 15 00:00:00 1970 PST
+ 516 | 6 | 00516 | Sat Jan 17 00:00:00 1970 PST
+ 517 | 407 | 00517_update7 | Sun Jan 18 00:00:00 1970 PST
+ 518 | 8 | 00518 | Mon Jan 19 00:00:00 1970 PST
+ 519 | 509 | 00519_update9 | Tue Jan 20 00:00:00 1970 PST
+ 520 | 0 | 00520 | Wed Jan 21 00:00:00 1970 PST
+ 521 | 1 | 00521 | Thu Jan 22 00:00:00 1970 PST
+ 523 | 303 | 00523_update3 | Sat Jan 24 00:00:00 1970 PST
+ 524 | 4 | 00524 | Sun Jan 25 00:00:00 1970 PST
+ 526 | 6 | 00526 | Tue Jan 27 00:00:00 1970 PST
+ 527 | 407 | 00527_update7 | Wed Jan 28 00:00:00 1970 PST
+ 528 | 8 | 00528 | Thu Jan 29 00:00:00 1970 PST
+ 529 | 509 | 00529_update9 | Fri Jan 30 00:00:00 1970 PST
+ 530 | 0 | 00530 | Sat Jan 31 00:00:00 1970 PST
+ 531 | 1 | 00531 | Sun Feb 01 00:00:00 1970 PST
+ 533 | 303 | 00533_update3 | Tue Feb 03 00:00:00 1970 PST
+ 534 | 4 | 00534 | Wed Feb 04 00:00:00 1970 PST
+ 536 | 6 | 00536 | Fri Feb 06 00:00:00 1970 PST
+ 537 | 407 | 00537_update7 | Sat Feb 07 00:00:00 1970 PST
+ 538 | 8 | 00538 | Sun Feb 08 00:00:00 1970 PST
+ 539 | 509 | 00539_update9 | Mon Feb 09 00:00:00 1970 PST
+ 540 | 0 | 00540 | Tue Feb 10 00:00:00 1970 PST
+ 541 | 1 | 00541 | Wed Feb 11 00:00:00 1970 PST
+ 543 | 303 | 00543_update3 | Fri Feb 13 00:00:00 1970 PST
+ 544 | 4 | 00544 | Sat Feb 14 00:00:00 1970 PST
+ 546 | 6 | 00546 | Mon Feb 16 00:00:00 1970 PST
+ 547 | 407 | 00547_update7 | Tue Feb 17 00:00:00 1970 PST
+ 548 | 8 | 00548 | Wed Feb 18 00:00:00 1970 PST
+ 549 | 509 | 00549_update9 | Thu Feb 19 00:00:00 1970 PST
+ 550 | 0 | 00550 | Fri Feb 20 00:00:00 1970 PST
+ 551 | 1 | 00551 | Sat Feb 21 00:00:00 1970 PST
+ 553 | 303 | 00553_update3 | Mon Feb 23 00:00:00 1970 PST
+ 554 | 4 | 00554 | Tue Feb 24 00:00:00 1970 PST
+ 556 | 6 | 00556 | Thu Feb 26 00:00:00 1970 PST
+ 557 | 407 | 00557_update7 | Fri Feb 27 00:00:00 1970 PST
+ 558 | 8 | 00558 | Sat Feb 28 00:00:00 1970 PST
+ 559 | 509 | 00559_update9 | Sun Mar 01 00:00:00 1970 PST
+ 560 | 0 | 00560 | Mon Mar 02 00:00:00 1970 PST
+ 561 | 1 | 00561 | Tue Mar 03 00:00:00 1970 PST
+ 563 | 303 | 00563_update3 | Thu Mar 05 00:00:00 1970 PST
+ 564 | 4 | 00564 | Fri Mar 06 00:00:00 1970 PST
+ 566 | 6 | 00566 | Sun Mar 08 00:00:00 1970 PST
+ 567 | 407 | 00567_update7 | Mon Mar 09 00:00:00 1970 PST
+ 568 | 8 | 00568 | Tue Mar 10 00:00:00 1970 PST
+ 569 | 509 | 00569_update9 | Wed Mar 11 00:00:00 1970 PST
+ 570 | 0 | 00570 | Thu Mar 12 00:00:00 1970 PST
+ 571 | 1 | 00571 | Fri Mar 13 00:00:00 1970 PST
+ 573 | 303 | 00573_update3 | Sun Mar 15 00:00:00 1970 PST
+ 574 | 4 | 00574 | Mon Mar 16 00:00:00 1970 PST
+ 576 | 6 | 00576 | Wed Mar 18 00:00:00 1970 PST
+ 577 | 407 | 00577_update7 | Thu Mar 19 00:00:00 1970 PST
+ 578 | 8 | 00578 | Fri Mar 20 00:00:00 1970 PST
+ 579 | 509 | 00579_update9 | Sat Mar 21 00:00:00 1970 PST
+ 580 | 0 | 00580 | Sun Mar 22 00:00:00 1970 PST
+ 581 | 1 | 00581 | Mon Mar 23 00:00:00 1970 PST
+ 583 | 303 | 00583_update3 | Wed Mar 25 00:00:00 1970 PST
+ 584 | 4 | 00584 | Thu Mar 26 00:00:00 1970 PST
+ 586 | 6 | 00586 | Sat Mar 28 00:00:00 1970 PST
+ 587 | 407 | 00587_update7 | Sun Mar 29 00:00:00 1970 PST
+ 588 | 8 | 00588 | Mon Mar 30 00:00:00 1970 PST
+ 589 | 509 | 00589_update9 | Tue Mar 31 00:00:00 1970 PST
+ 590 | 0 | 00590 | Wed Apr 01 00:00:00 1970 PST
+ 591 | 1 | 00591 | Thu Apr 02 00:00:00 1970 PST
+ 593 | 303 | 00593_update3 | Sat Apr 04 00:00:00 1970 PST
+ 594 | 4 | 00594 | Sun Apr 05 00:00:00 1970 PST
+ 596 | 6 | 00596 | Tue Apr 07 00:00:00 1970 PST
+ 597 | 407 | 00597_update7 | Wed Apr 08 00:00:00 1970 PST
+ 598 | 8 | 00598 | Thu Apr 09 00:00:00 1970 PST
+ 599 | 509 | 00599_update9 | Fri Apr 10 00:00:00 1970 PST
+ 600 | 0 | 00600 | Thu Jan 01 00:00:00 1970 PST
+ 601 | 1 | 00601 | Fri Jan 02 00:00:00 1970 PST
+ 603 | 303 | 00603_update3 | Sun Jan 04 00:00:00 1970 PST
+ 604 | 4 | 00604 | Mon Jan 05 00:00:00 1970 PST
+ 606 | 6 | 00606 | Wed Jan 07 00:00:00 1970 PST
+ 607 | 407 | 00607_update7 | Thu Jan 08 00:00:00 1970 PST
+ 608 | 8 | 00608 | Fri Jan 09 00:00:00 1970 PST
+ 609 | 509 | 00609_update9 | Sat Jan 10 00:00:00 1970 PST
+ 610 | 0 | 00610 | Sun Jan 11 00:00:00 1970 PST
+ 611 | 1 | 00611 | Mon Jan 12 00:00:00 1970 PST
+ 613 | 303 | 00613_update3 | Wed Jan 14 00:00:00 1970 PST
+ 614 | 4 | 00614 | Thu Jan 15 00:00:00 1970 PST
+ 616 | 6 | 00616 | Sat Jan 17 00:00:00 1970 PST
+ 617 | 407 | 00617_update7 | Sun Jan 18 00:00:00 1970 PST
+ 618 | 8 | 00618 | Mon Jan 19 00:00:00 1970 PST
+ 619 | 509 | 00619_update9 | Tue Jan 20 00:00:00 1970 PST
+ 620 | 0 | 00620 | Wed Jan 21 00:00:00 1970 PST
+ 621 | 1 | 00621 | Thu Jan 22 00:00:00 1970 PST
+ 623 | 303 | 00623_update3 | Sat Jan 24 00:00:00 1970 PST
+ 624 | 4 | 00624 | Sun Jan 25 00:00:00 1970 PST
+ 626 | 6 | 00626 | Tue Jan 27 00:00:00 1970 PST
+ 627 | 407 | 00627_update7 | Wed Jan 28 00:00:00 1970 PST
+ 628 | 8 | 00628 | Thu Jan 29 00:00:00 1970 PST
+ 629 | 509 | 00629_update9 | Fri Jan 30 00:00:00 1970 PST
+ 630 | 0 | 00630 | Sat Jan 31 00:00:00 1970 PST
+ 631 | 1 | 00631 | Sun Feb 01 00:00:00 1970 PST
+ 633 | 303 | 00633_update3 | Tue Feb 03 00:00:00 1970 PST
+ 634 | 4 | 00634 | Wed Feb 04 00:00:00 1970 PST
+ 636 | 6 | 00636 | Fri Feb 06 00:00:00 1970 PST
+ 637 | 407 | 00637_update7 | Sat Feb 07 00:00:00 1970 PST
+ 638 | 8 | 00638 | Sun Feb 08 00:00:00 1970 PST
+ 639 | 509 | 00639_update9 | Mon Feb 09 00:00:00 1970 PST
+ 640 | 0 | 00640 | Tue Feb 10 00:00:00 1970 PST
+ 641 | 1 | 00641 | Wed Feb 11 00:00:00 1970 PST
+ 643 | 303 | 00643_update3 | Fri Feb 13 00:00:00 1970 PST
+ 644 | 4 | 00644 | Sat Feb 14 00:00:00 1970 PST
+ 646 | 6 | 00646 | Mon Feb 16 00:00:00 1970 PST
+ 647 | 407 | 00647_update7 | Tue Feb 17 00:00:00 1970 PST
+ 648 | 8 | 00648 | Wed Feb 18 00:00:00 1970 PST
+ 649 | 509 | 00649_update9 | Thu Feb 19 00:00:00 1970 PST
+ 650 | 0 | 00650 | Fri Feb 20 00:00:00 1970 PST
+ 651 | 1 | 00651 | Sat Feb 21 00:00:00 1970 PST
+ 653 | 303 | 00653_update3 | Mon Feb 23 00:00:00 1970 PST
+ 654 | 4 | 00654 | Tue Feb 24 00:00:00 1970 PST
+ 656 | 6 | 00656 | Thu Feb 26 00:00:00 1970 PST
+ 657 | 407 | 00657_update7 | Fri Feb 27 00:00:00 1970 PST
+ 658 | 8 | 00658 | Sat Feb 28 00:00:00 1970 PST
+ 659 | 509 | 00659_update9 | Sun Mar 01 00:00:00 1970 PST
+ 660 | 0 | 00660 | Mon Mar 02 00:00:00 1970 PST
+ 661 | 1 | 00661 | Tue Mar 03 00:00:00 1970 PST
+ 663 | 303 | 00663_update3 | Thu Mar 05 00:00:00 1970 PST
+ 664 | 4 | 00664 | Fri Mar 06 00:00:00 1970 PST
+ 666 | 6 | 00666 | Sun Mar 08 00:00:00 1970 PST
+ 667 | 407 | 00667_update7 | Mon Mar 09 00:00:00 1970 PST
+ 668 | 8 | 00668 | Tue Mar 10 00:00:00 1970 PST
+ 669 | 509 | 00669_update9 | Wed Mar 11 00:00:00 1970 PST
+ 670 | 0 | 00670 | Thu Mar 12 00:00:00 1970 PST
+ 671 | 1 | 00671 | Fri Mar 13 00:00:00 1970 PST
+ 673 | 303 | 00673_update3 | Sun Mar 15 00:00:00 1970 PST
+ 674 | 4 | 00674 | Mon Mar 16 00:00:00 1970 PST
+ 676 | 6 | 00676 | Wed Mar 18 00:00:00 1970 PST
+ 677 | 407 | 00677_update7 | Thu Mar 19 00:00:00 1970 PST
+ 678 | 8 | 00678 | Fri Mar 20 00:00:00 1970 PST
+ 679 | 509 | 00679_update9 | Sat Mar 21 00:00:00 1970 PST
+ 680 | 0 | 00680 | Sun Mar 22 00:00:00 1970 PST
+ 681 | 1 | 00681 | Mon Mar 23 00:00:00 1970 PST
+ 683 | 303 | 00683_update3 | Wed Mar 25 00:00:00 1970 PST
+ 684 | 4 | 00684 | Thu Mar 26 00:00:00 1970 PST
+ 686 | 6 | 00686 | Sat Mar 28 00:00:00 1970 PST
+ 687 | 407 | 00687_update7 | Sun Mar 29 00:00:00 1970 PST
+ 688 | 8 | 00688 | Mon Mar 30 00:00:00 1970 PST
+ 689 | 509 | 00689_update9 | Tue Mar 31 00:00:00 1970 PST
+ 690 | 0 | 00690 | Wed Apr 01 00:00:00 1970 PST
+ 691 | 1 | 00691 | Thu Apr 02 00:00:00 1970 PST
+ 693 | 303 | 00693_update3 | Sat Apr 04 00:00:00 1970 PST
+ 694 | 4 | 00694 | Sun Apr 05 00:00:00 1970 PST
+ 696 | 6 | 00696 | Tue Apr 07 00:00:00 1970 PST
+ 697 | 407 | 00697_update7 | Wed Apr 08 00:00:00 1970 PST
+ 698 | 8 | 00698 | Thu Apr 09 00:00:00 1970 PST
+ 699 | 509 | 00699_update9 | Fri Apr 10 00:00:00 1970 PST
+ 700 | 0 | 00700 | Thu Jan 01 00:00:00 1970 PST
+ 701 | 1 | 00701 | Fri Jan 02 00:00:00 1970 PST
+ 703 | 303 | 00703_update3 | Sun Jan 04 00:00:00 1970 PST
+ 704 | 4 | 00704 | Mon Jan 05 00:00:00 1970 PST
+ 706 | 6 | 00706 | Wed Jan 07 00:00:00 1970 PST
+ 707 | 407 | 00707_update7 | Thu Jan 08 00:00:00 1970 PST
+ 708 | 8 | 00708 | Fri Jan 09 00:00:00 1970 PST
+ 709 | 509 | 00709_update9 | Sat Jan 10 00:00:00 1970 PST
+ 710 | 0 | 00710 | Sun Jan 11 00:00:00 1970 PST
+ 711 | 1 | 00711 | Mon Jan 12 00:00:00 1970 PST
+ 713 | 303 | 00713_update3 | Wed Jan 14 00:00:00 1970 PST
+ 714 | 4 | 00714 | Thu Jan 15 00:00:00 1970 PST
+ 716 | 6 | 00716 | Sat Jan 17 00:00:00 1970 PST
+ 717 | 407 | 00717_update7 | Sun Jan 18 00:00:00 1970 PST
+ 718 | 8 | 00718 | Mon Jan 19 00:00:00 1970 PST
+ 719 | 509 | 00719_update9 | Tue Jan 20 00:00:00 1970 PST
+ 720 | 0 | 00720 | Wed Jan 21 00:00:00 1970 PST
+ 721 | 1 | 00721 | Thu Jan 22 00:00:00 1970 PST
+ 723 | 303 | 00723_update3 | Sat Jan 24 00:00:00 1970 PST
+ 724 | 4 | 00724 | Sun Jan 25 00:00:00 1970 PST
+ 726 | 6 | 00726 | Tue Jan 27 00:00:00 1970 PST
+ 727 | 407 | 00727_update7 | Wed Jan 28 00:00:00 1970 PST
+ 728 | 8 | 00728 | Thu Jan 29 00:00:00 1970 PST
+ 729 | 509 | 00729_update9 | Fri Jan 30 00:00:00 1970 PST
+ 730 | 0 | 00730 | Sat Jan 31 00:00:00 1970 PST
+ 731 | 1 | 00731 | Sun Feb 01 00:00:00 1970 PST
+ 733 | 303 | 00733_update3 | Tue Feb 03 00:00:00 1970 PST
+ 734 | 4 | 00734 | Wed Feb 04 00:00:00 1970 PST
+ 736 | 6 | 00736 | Fri Feb 06 00:00:00 1970 PST
+ 737 | 407 | 00737_update7 | Sat Feb 07 00:00:00 1970 PST
+ 738 | 8 | 00738 | Sun Feb 08 00:00:00 1970 PST
+ 739 | 509 | 00739_update9 | Mon Feb 09 00:00:00 1970 PST
+ 740 | 0 | 00740 | Tue Feb 10 00:00:00 1970 PST
+ 741 | 1 | 00741 | Wed Feb 11 00:00:00 1970 PST
+ 743 | 303 | 00743_update3 | Fri Feb 13 00:00:00 1970 PST
+ 744 | 4 | 00744 | Sat Feb 14 00:00:00 1970 PST
+ 746 | 6 | 00746 | Mon Feb 16 00:00:00 1970 PST
+ 747 | 407 | 00747_update7 | Tue Feb 17 00:00:00 1970 PST
+ 748 | 8 | 00748 | Wed Feb 18 00:00:00 1970 PST
+ 749 | 509 | 00749_update9 | Thu Feb 19 00:00:00 1970 PST
+ 750 | 0 | 00750 | Fri Feb 20 00:00:00 1970 PST
+ 751 | 1 | 00751 | Sat Feb 21 00:00:00 1970 PST
+ 753 | 303 | 00753_update3 | Mon Feb 23 00:00:00 1970 PST
+ 754 | 4 | 00754 | Tue Feb 24 00:00:00 1970 PST
+ 756 | 6 | 00756 | Thu Feb 26 00:00:00 1970 PST
+ 757 | 407 | 00757_update7 | Fri Feb 27 00:00:00 1970 PST
+ 758 | 8 | 00758 | Sat Feb 28 00:00:00 1970 PST
+ 759 | 509 | 00759_update9 | Sun Mar 01 00:00:00 1970 PST
+ 760 | 0 | 00760 | Mon Mar 02 00:00:00 1970 PST
+ 761 | 1 | 00761 | Tue Mar 03 00:00:00 1970 PST
+ 763 | 303 | 00763_update3 | Thu Mar 05 00:00:00 1970 PST
+ 764 | 4 | 00764 | Fri Mar 06 00:00:00 1970 PST
+ 766 | 6 | 00766 | Sun Mar 08 00:00:00 1970 PST
+ 767 | 407 | 00767_update7 | Mon Mar 09 00:00:00 1970 PST
+ 768 | 8 | 00768 | Tue Mar 10 00:00:00 1970 PST
+ 769 | 509 | 00769_update9 | Wed Mar 11 00:00:00 1970 PST
+ 770 | 0 | 00770 | Thu Mar 12 00:00:00 1970 PST
+ 771 | 1 | 00771 | Fri Mar 13 00:00:00 1970 PST
+ 773 | 303 | 00773_update3 | Sun Mar 15 00:00:00 1970 PST
+ 774 | 4 | 00774 | Mon Mar 16 00:00:00 1970 PST
+ 776 | 6 | 00776 | Wed Mar 18 00:00:00 1970 PST
+ 777 | 407 | 00777_update7 | Thu Mar 19 00:00:00 1970 PST
+ 778 | 8 | 00778 | Fri Mar 20 00:00:00 1970 PST
+ 779 | 509 | 00779_update9 | Sat Mar 21 00:00:00 1970 PST
+ 780 | 0 | 00780 | Sun Mar 22 00:00:00 1970 PST
+ 781 | 1 | 00781 | Mon Mar 23 00:00:00 1970 PST
+ 783 | 303 | 00783_update3 | Wed Mar 25 00:00:00 1970 PST
+ 784 | 4 | 00784 | Thu Mar 26 00:00:00 1970 PST
+ 786 | 6 | 00786 | Sat Mar 28 00:00:00 1970 PST
+ 787 | 407 | 00787_update7 | Sun Mar 29 00:00:00 1970 PST
+ 788 | 8 | 00788 | Mon Mar 30 00:00:00 1970 PST
+ 789 | 509 | 00789_update9 | Tue Mar 31 00:00:00 1970 PST
+ 790 | 0 | 00790 | Wed Apr 01 00:00:00 1970 PST
+ 791 | 1 | 00791 | Thu Apr 02 00:00:00 1970 PST
+ 793 | 303 | 00793_update3 | Sat Apr 04 00:00:00 1970 PST
+ 794 | 4 | 00794 | Sun Apr 05 00:00:00 1970 PST
+ 796 | 6 | 00796 | Tue Apr 07 00:00:00 1970 PST
+ 797 | 407 | 00797_update7 | Wed Apr 08 00:00:00 1970 PST
+ 798 | 8 | 00798 | Thu Apr 09 00:00:00 1970 PST
+ 799 | 509 | 00799_update9 | Fri Apr 10 00:00:00 1970 PST
+ 800 | 0 | 00800 | Thu Jan 01 00:00:00 1970 PST
+ 801 | 1 | 00801 | Fri Jan 02 00:00:00 1970 PST
+ 803 | 303 | 00803_update3 | Sun Jan 04 00:00:00 1970 PST
+ 804 | 4 | 00804 | Mon Jan 05 00:00:00 1970 PST
+ 806 | 6 | 00806 | Wed Jan 07 00:00:00 1970 PST
+ 807 | 407 | 00807_update7 | Thu Jan 08 00:00:00 1970 PST
+ 808 | 8 | 00808 | Fri Jan 09 00:00:00 1970 PST
+ 809 | 509 | 00809_update9 | Sat Jan 10 00:00:00 1970 PST
+ 810 | 0 | 00810 | Sun Jan 11 00:00:00 1970 PST
+ 811 | 1 | 00811 | Mon Jan 12 00:00:00 1970 PST
+ 813 | 303 | 00813_update3 | Wed Jan 14 00:00:00 1970 PST
+ 814 | 4 | 00814 | Thu Jan 15 00:00:00 1970 PST
+ 816 | 6 | 00816 | Sat Jan 17 00:00:00 1970 PST
+ 817 | 407 | 00817_update7 | Sun Jan 18 00:00:00 1970 PST
+ 818 | 8 | 00818 | Mon Jan 19 00:00:00 1970 PST
+ 819 | 509 | 00819_update9 | Tue Jan 20 00:00:00 1970 PST
+ 820 | 0 | 00820 | Wed Jan 21 00:00:00 1970 PST
+ 821 | 1 | 00821 | Thu Jan 22 00:00:00 1970 PST
+ 823 | 303 | 00823_update3 | Sat Jan 24 00:00:00 1970 PST
+ 824 | 4 | 00824 | Sun Jan 25 00:00:00 1970 PST
+ 826 | 6 | 00826 | Tue Jan 27 00:00:00 1970 PST
+ 827 | 407 | 00827_update7 | Wed Jan 28 00:00:00 1970 PST
+ 828 | 8 | 00828 | Thu Jan 29 00:00:00 1970 PST
+ 829 | 509 | 00829_update9 | Fri Jan 30 00:00:00 1970 PST
+ 830 | 0 | 00830 | Sat Jan 31 00:00:00 1970 PST
+ 831 | 1 | 00831 | Sun Feb 01 00:00:00 1970 PST
+ 833 | 303 | 00833_update3 | Tue Feb 03 00:00:00 1970 PST
+ 834 | 4 | 00834 | Wed Feb 04 00:00:00 1970 PST
+ 836 | 6 | 00836 | Fri Feb 06 00:00:00 1970 PST
+ 837 | 407 | 00837_update7 | Sat Feb 07 00:00:00 1970 PST
+ 838 | 8 | 00838 | Sun Feb 08 00:00:00 1970 PST
+ 839 | 509 | 00839_update9 | Mon Feb 09 00:00:00 1970 PST
+ 840 | 0 | 00840 | Tue Feb 10 00:00:00 1970 PST
+ 841 | 1 | 00841 | Wed Feb 11 00:00:00 1970 PST
+ 843 | 303 | 00843_update3 | Fri Feb 13 00:00:00 1970 PST
+ 844 | 4 | 00844 | Sat Feb 14 00:00:00 1970 PST
+ 846 | 6 | 00846 | Mon Feb 16 00:00:00 1970 PST
+ 847 | 407 | 00847_update7 | Tue Feb 17 00:00:00 1970 PST
+ 848 | 8 | 00848 | Wed Feb 18 00:00:00 1970 PST
+ 849 | 509 | 00849_update9 | Thu Feb 19 00:00:00 1970 PST
+ 850 | 0 | 00850 | Fri Feb 20 00:00:00 1970 PST
+ 851 | 1 | 00851 | Sat Feb 21 00:00:00 1970 PST
+ 853 | 303 | 00853_update3 | Mon Feb 23 00:00:00 1970 PST
+ 854 | 4 | 00854 | Tue Feb 24 00:00:00 1970 PST
+ 856 | 6 | 00856 | Thu Feb 26 00:00:00 1970 PST
+ 857 | 407 | 00857_update7 | Fri Feb 27 00:00:00 1970 PST
+ 858 | 8 | 00858 | Sat Feb 28 00:00:00 1970 PST
+ 859 | 509 | 00859_update9 | Sun Mar 01 00:00:00 1970 PST
+ 860 | 0 | 00860 | Mon Mar 02 00:00:00 1970 PST
+ 861 | 1 | 00861 | Tue Mar 03 00:00:00 1970 PST
+ 863 | 303 | 00863_update3 | Thu Mar 05 00:00:00 1970 PST
+ 864 | 4 | 00864 | Fri Mar 06 00:00:00 1970 PST
+ 866 | 6 | 00866 | Sun Mar 08 00:00:00 1970 PST
+ 867 | 407 | 00867_update7 | Mon Mar 09 00:00:00 1970 PST
+ 868 | 8 | 00868 | Tue Mar 10 00:00:00 1970 PST
+ 869 | 509 | 00869_update9 | Wed Mar 11 00:00:00 1970 PST
+ 870 | 0 | 00870 | Thu Mar 12 00:00:00 1970 PST
+ 871 | 1 | 00871 | Fri Mar 13 00:00:00 1970 PST
+ 873 | 303 | 00873_update3 | Sun Mar 15 00:00:00 1970 PST
+ 874 | 4 | 00874 | Mon Mar 16 00:00:00 1970 PST
+ 876 | 6 | 00876 | Wed Mar 18 00:00:00 1970 PST
+ 877 | 407 | 00877_update7 | Thu Mar 19 00:00:00 1970 PST
+ 878 | 8 | 00878 | Fri Mar 20 00:00:00 1970 PST
+ 879 | 509 | 00879_update9 | Sat Mar 21 00:00:00 1970 PST
+ 880 | 0 | 00880 | Sun Mar 22 00:00:00 1970 PST
+ 881 | 1 | 00881 | Mon Mar 23 00:00:00 1970 PST
+ 883 | 303 | 00883_update3 | Wed Mar 25 00:00:00 1970 PST
+ 884 | 4 | 00884 | Thu Mar 26 00:00:00 1970 PST
+ 886 | 6 | 00886 | Sat Mar 28 00:00:00 1970 PST
+ 887 | 407 | 00887_update7 | Sun Mar 29 00:00:00 1970 PST
+ 888 | 8 | 00888 | Mon Mar 30 00:00:00 1970 PST
+ 889 | 509 | 00889_update9 | Tue Mar 31 00:00:00 1970 PST
+ 890 | 0 | 00890 | Wed Apr 01 00:00:00 1970 PST
+ 891 | 1 | 00891 | Thu Apr 02 00:00:00 1970 PST
+ 893 | 303 | 00893_update3 | Sat Apr 04 00:00:00 1970 PST
+ 894 | 4 | 00894 | Sun Apr 05 00:00:00 1970 PST
+ 896 | 6 | 00896 | Tue Apr 07 00:00:00 1970 PST
+ 897 | 407 | 00897_update7 | Wed Apr 08 00:00:00 1970 PST
+ 898 | 8 | 00898 | Thu Apr 09 00:00:00 1970 PST
+ 899 | 509 | 00899_update9 | Fri Apr 10 00:00:00 1970 PST
+ 900 | 0 | 00900 | Thu Jan 01 00:00:00 1970 PST
+ 901 | 1 | 00901 | Fri Jan 02 00:00:00 1970 PST
+ 903 | 303 | 00903_update3 | Sun Jan 04 00:00:00 1970 PST
+ 904 | 4 | 00904 | Mon Jan 05 00:00:00 1970 PST
+ 906 | 6 | 00906 | Wed Jan 07 00:00:00 1970 PST
+ 907 | 407 | 00907_update7 | Thu Jan 08 00:00:00 1970 PST
+ 908 | 8 | 00908 | Fri Jan 09 00:00:00 1970 PST
+ 909 | 509 | 00909_update9 | Sat Jan 10 00:00:00 1970 PST
+ 910 | 0 | 00910 | Sun Jan 11 00:00:00 1970 PST
+ 911 | 1 | 00911 | Mon Jan 12 00:00:00 1970 PST
+ 913 | 303 | 00913_update3 | Wed Jan 14 00:00:00 1970 PST
+ 914 | 4 | 00914 | Thu Jan 15 00:00:00 1970 PST
+ 916 | 6 | 00916 | Sat Jan 17 00:00:00 1970 PST
+ 917 | 407 | 00917_update7 | Sun Jan 18 00:00:00 1970 PST
+ 918 | 8 | 00918 | Mon Jan 19 00:00:00 1970 PST
+ 919 | 509 | 00919_update9 | Tue Jan 20 00:00:00 1970 PST
+ 920 | 0 | 00920 | Wed Jan 21 00:00:00 1970 PST
+ 921 | 1 | 00921 | Thu Jan 22 00:00:00 1970 PST
+ 923 | 303 | 00923_update3 | Sat Jan 24 00:00:00 1970 PST
+ 924 | 4 | 00924 | Sun Jan 25 00:00:00 1970 PST
+ 926 | 6 | 00926 | Tue Jan 27 00:00:00 1970 PST
+ 927 | 407 | 00927_update7 | Wed Jan 28 00:00:00 1970 PST
+ 928 | 8 | 00928 | Thu Jan 29 00:00:00 1970 PST
+ 929 | 509 | 00929_update9 | Fri Jan 30 00:00:00 1970 PST
+ 930 | 0 | 00930 | Sat Jan 31 00:00:00 1970 PST
+ 931 | 1 | 00931 | Sun Feb 01 00:00:00 1970 PST
+ 933 | 303 | 00933_update3 | Tue Feb 03 00:00:00 1970 PST
+ 934 | 4 | 00934 | Wed Feb 04 00:00:00 1970 PST
+ 936 | 6 | 00936 | Fri Feb 06 00:00:00 1970 PST
+ 937 | 407 | 00937_update7 | Sat Feb 07 00:00:00 1970 PST
+ 938 | 8 | 00938 | Sun Feb 08 00:00:00 1970 PST
+ 939 | 509 | 00939_update9 | Mon Feb 09 00:00:00 1970 PST
+ 940 | 0 | 00940 | Tue Feb 10 00:00:00 1970 PST
+ 941 | 1 | 00941 | Wed Feb 11 00:00:00 1970 PST
+ 943 | 303 | 00943_update3 | Fri Feb 13 00:00:00 1970 PST
+ 944 | 4 | 00944 | Sat Feb 14 00:00:00 1970 PST
+ 946 | 6 | 00946 | Mon Feb 16 00:00:00 1970 PST
+ 947 | 407 | 00947_update7 | Tue Feb 17 00:00:00 1970 PST
+ 948 | 8 | 00948 | Wed Feb 18 00:00:00 1970 PST
+ 949 | 509 | 00949_update9 | Thu Feb 19 00:00:00 1970 PST
+ 950 | 0 | 00950 | Fri Feb 20 00:00:00 1970 PST
+ 951 | 1 | 00951 | Sat Feb 21 00:00:00 1970 PST
+ 953 | 303 | 00953_update3 | Mon Feb 23 00:00:00 1970 PST
+ 954 | 4 | 00954 | Tue Feb 24 00:00:00 1970 PST
+ 956 | 6 | 00956 | Thu Feb 26 00:00:00 1970 PST
+ 957 | 407 | 00957_update7 | Fri Feb 27 00:00:00 1970 PST
+ 958 | 8 | 00958 | Sat Feb 28 00:00:00 1970 PST
+ 959 | 509 | 00959_update9 | Sun Mar 01 00:00:00 1970 PST
+ 960 | 0 | 00960 | Mon Mar 02 00:00:00 1970 PST
+ 961 | 1 | 00961 | Tue Mar 03 00:00:00 1970 PST
+ 963 | 303 | 00963_update3 | Thu Mar 05 00:00:00 1970 PST
+ 964 | 4 | 00964 | Fri Mar 06 00:00:00 1970 PST
+ 966 | 6 | 00966 | Sun Mar 08 00:00:00 1970 PST
+ 967 | 407 | 00967_update7 | Mon Mar 09 00:00:00 1970 PST
+ 968 | 8 | 00968 | Tue Mar 10 00:00:00 1970 PST
+ 969 | 509 | 00969_update9 | Wed Mar 11 00:00:00 1970 PST
+ 970 | 0 | 00970 | Thu Mar 12 00:00:00 1970 PST
+ 971 | 1 | 00971 | Fri Mar 13 00:00:00 1970 PST
+ 973 | 303 | 00973_update3 | Sun Mar 15 00:00:00 1970 PST
+ 974 | 4 | 00974 | Mon Mar 16 00:00:00 1970 PST
+ 976 | 6 | 00976 | Wed Mar 18 00:00:00 1970 PST
+ 977 | 407 | 00977_update7 | Thu Mar 19 00:00:00 1970 PST
+ 978 | 8 | 00978 | Fri Mar 20 00:00:00 1970 PST
+ 979 | 509 | 00979_update9 | Sat Mar 21 00:00:00 1970 PST
+ 980 | 0 | 00980 | Sun Mar 22 00:00:00 1970 PST
+ 981 | 1 | 00981 | Mon Mar 23 00:00:00 1970 PST
+ 983 | 303 | 00983_update3 | Wed Mar 25 00:00:00 1970 PST
+ 984 | 4 | 00984 | Thu Mar 26 00:00:00 1970 PST
+ 986 | 6 | 00986 | Sat Mar 28 00:00:00 1970 PST
+ 987 | 407 | 00987_update7 | Sun Mar 29 00:00:00 1970 PST
+ 988 | 8 | 00988 | Mon Mar 30 00:00:00 1970 PST
+ 989 | 509 | 00989_update9 | Tue Mar 31 00:00:00 1970 PST
+ 990 | 0 | 00990 | Wed Apr 01 00:00:00 1970 PST
+ 991 | 1 | 00991 | Thu Apr 02 00:00:00 1970 PST
+ 993 | 303 | 00993_update3 | Sat Apr 04 00:00:00 1970 PST
+ 994 | 4 | 00994 | Sun Apr 05 00:00:00 1970 PST
+ 996 | 6 | 00996 | Tue Apr 07 00:00:00 1970 PST
+ 997 | 407 | 00997_update7 | Wed Apr 08 00:00:00 1970 PST
+ 998 | 8 | 00998 | Thu Apr 09 00:00:00 1970 PST
+ 999 | 509 | 00999_update9 | Fri Apr 10 00:00:00 1970 PST
+ 1000 | 0 | 01000 | Thu Jan 01 00:00:00 1970 PST
+ 1001 | 101 | 0000100001 |
+ 1003 | 403 | 0000300003_update3 |
+ 1004 | 104 | 0000400004 |
+ 1006 | 106 | 0000600006 |
+ 1007 | 507 | 0000700007_update7 |
+ 1008 | 108 | 0000800008 |
+ 1009 | 609 | 0000900009_update9 |
+ 1010 | 100 | 0001000010 |
+ 1011 | 101 | 0001100011 |
+ 1013 | 403 | 0001300013_update3 |
+ 1014 | 104 | 0001400014 |
+ 1016 | 106 | 0001600016 |
+ 1017 | 507 | 0001700017_update7 |
+ 1018 | 108 | 0001800018 |
+ 1019 | 609 | 0001900019_update9 |
+ 1020 | 100 | 0002000020 |
+ 1101 | 201 | aaa |
+ 1103 | 503 | ccc_update3 |
+ 1104 | 204 | ddd |
+(819 rows)
+
+EXPLAIN (verbose, costs off)
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.ft2
+ Output: (ft2.tableoid)::regclass
+ Remote SQL: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+ Batch Size: 1
+ -> Result
+ Output: 1200, 999, NULL::integer, 'foo'::text, NULL::timestamp with time zone, NULL::timestamp without time zone, NULL::character varying, 'ft2 '::character(10), NULL::user_enum
+(6 rows)
+
+INSERT INTO ft2 (c1,c2,c3) VALUES (1200,999,'foo') RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Update on public.ft2
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = 'bar'::text WHERE (("C 1" = 1200))
+(4 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass; -- can be pushed down
+ QUERY PLAN
+--------------------------------------------------------------------
+ Delete on public.ft2
+ Output: (tableoid)::regclass
+ -> Foreign Delete on public.ft2
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE (("C 1" = 1200))
+(4 rows)
+
+DELETE FROM ft2 WHERE c1 = 1200 RETURNING tableoid::regclass;
+ tableoid
+----------
+ ft2
+(1 row)
+
+-- Test UPDATE/DELETE with RETURNING on a three-table join
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id - 1200, to_char(id, 'FM00000') FROM generate_series(1201, 1300) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.*, ft4.c1, ft4.c2, ft4.c3
+ -> Foreign Update
+ Remote SQL: UPDATE "S 1"."T 1" r1 SET c3 = 'foo'::text FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (TRUE)) WHERE ((r2.c1 = r3.c1)) AND ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) RETURNING r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3
+(4 rows)
+
+UPDATE ft2 SET c3 = 'foo'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c2 = ft4.c1
+ RETURNING ft2, ft2.*, ft4, ft4.*;
+ ft2 | c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | ft4 | c1 | c2 | c3
+--------------------------------+------+----+-----+----+----+----+------------+----+----------------+----+----+--------
+ (1206,6,foo,,,,"ft2 ",) | 1206 | 6 | foo | | | | ft2 | | (6,7,AAA006) | 6 | 7 | AAA006
+ (1212,12,foo,,,,"ft2 ",) | 1212 | 12 | foo | | | | ft2 | | (12,13,AAA012) | 12 | 13 | AAA012
+ (1218,18,foo,,,,"ft2 ",) | 1218 | 18 | foo | | | | ft2 | | (18,19,AAA018) | 18 | 19 | AAA018
+ (1224,24,foo,,,,"ft2 ",) | 1224 | 24 | foo | | | | ft2 | | (24,25,AAA024) | 24 | 25 | AAA024
+ (1230,30,foo,,,,"ft2 ",) | 1230 | 30 | foo | | | | ft2 | | (30,31,AAA030) | 30 | 31 | AAA030
+ (1236,36,foo,,,,"ft2 ",) | 1236 | 36 | foo | | | | ft2 | | (36,37,AAA036) | 36 | 37 | AAA036
+ (1242,42,foo,,,,"ft2 ",) | 1242 | 42 | foo | | | | ft2 | | (42,43,AAA042) | 42 | 43 | AAA042
+ (1248,48,foo,,,,"ft2 ",) | 1248 | 48 | foo | | | | ft2 | | (48,49,AAA048) | 48 | 49 | AAA048
+ (1254,54,foo,,,,"ft2 ",) | 1254 | 54 | foo | | | | ft2 | | (54,55,AAA054) | 54 | 55 | AAA054
+ (1260,60,foo,,,,"ft2 ",) | 1260 | 60 | foo | | | | ft2 | | (60,61,AAA060) | 60 | 61 | AAA060
+ (1266,66,foo,,,,"ft2 ",) | 1266 | 66 | foo | | | | ft2 | | (66,67,AAA066) | 66 | 67 | AAA066
+ (1272,72,foo,,,,"ft2 ",) | 1272 | 72 | foo | | | | ft2 | | (72,73,AAA072) | 72 | 73 | AAA072
+ (1278,78,foo,,,,"ft2 ",) | 1278 | 78 | foo | | | | ft2 | | (78,79,AAA078) | 78 | 79 | AAA078
+ (1284,84,foo,,,,"ft2 ",) | 1284 | 84 | foo | | | | ft2 | | (84,85,AAA084) | 84 | 85 | AAA084
+ (1290,90,foo,,,,"ft2 ",) | 1290 | 90 | foo | | | | ft2 | | (90,91,AAA090) | 90 | 91 | AAA090
+ (1296,96,foo,,,,"ft2 ",) | 1296 | 96 | foo | | | | ft2 | | (96,97,AAA096) | 96 | 97 | AAA096
+(16 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: 100
+ -> Foreign Delete
+ Remote SQL: DELETE FROM "S 1"."T 1" r1 USING ("S 1"."T 3" r2 LEFT JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1)))) WHERE ((r1.c2 = r2.c1)) AND ((r1."C 1" > 1200)) AND (((r1."C 1" % 10) = 0))
+(4 rows)
+
+DELETE FROM ft2
+ USING ft4 LEFT JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 1200 AND ft2.c1 % 10 = 0 AND ft2.c2 = ft4.c1
+ RETURNING 100;
+ ?column?
+----------
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+ 100
+(10 rows)
+
+DELETE FROM ft2 WHERE ft2.c1 > 1200;
+-- Test UPDATE with a MULTIEXPR sub-select
+-- (maybe someday this'll be remotely executable, but not today)
+EXPLAIN (verbose, costs off)
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 target
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2, c7 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.ft2 target
+ Output: $1, $2, (SubPlan 1 (returns $1,$2)), target.ctid, target.*
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1100)) FOR UPDATE
+ SubPlan 1 (returns $1,$2)
+ -> Foreign Scan on public.ft2 src
+ Output: (src.c2 * 10), src.c7
+ Remote SQL: SELECT c2, c7 FROM "S 1"."T 1" WHERE (($1::integer = "C 1"))
+(9 rows)
+
+UPDATE ft2 AS target SET (c2, c7) = (
+ SELECT c2 * 10, c7
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+UPDATE ft2 AS target SET (c2) = (
+ SELECT c2 / 10
+ FROM ft2 AS src
+ WHERE target.c1 = src.c1
+) WHERE c1 > 1100;
+-- Test UPDATE involving a join that can be pushed down,
+-- but a SET clause that can't be
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2 d
+ Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2 WHERE ctid = $1
+ -> Foreign Scan
+ Output: CASE WHEN (random() >= '0'::double precision) THEN d.c2 ELSE 0 END, d.ctid, d.*, t.*
+ Relations: (public.ft2 d) INNER JOIN (public.ft2 t)
+ Remote SQL: SELECT r1.c2, r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r1."C 1" > 1000)))) FOR UPDATE OF r1
+ -> Hash Join
+ Output: d.c2, d.ctid, d.*, t.*
+ Hash Cond: (d.c1 = t.c1)
+ -> Foreign Scan on public.ft2 d
+ Output: d.c2, d.ctid, d.*, d.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1000)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE
+ -> Hash
+ Output: t.*, t.c1
+ -> Foreign Scan on public.ft2 t
+ Output: t.*, t.c1
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1"
+(17 rows)
+
+UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END
+ FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000;
+-- Test UPDATE/DELETE with WHERE or JOIN/ON conditions containing
+-- user-defined operators/functions
+ALTER SERVER loopback OPTIONS (DROP extensions);
+INSERT INTO ft2 (c1,c2,c3)
+ SELECT id, id % 10, to_char(id, 'FM00000') FROM generate_series(2001, 2010) id;
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Foreign Scan on public.ft2
+ Output: 'bar'::text, ctid, ft2.*
+ Filter: (postgres_fdw_abs(ft2.c1) > 2000)
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" FOR UPDATE
+(7 rows)
+
+UPDATE ft2 SET c3 = 'bar' WHERE postgres_fdw_abs(c1) > 2000 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+----+-----+----+----+----+------------+----
+ 2001 | 1 | bar | | | | ft2 |
+ 2002 | 2 | bar | | | | ft2 |
+ 2003 | 3 | bar | | | | ft2 |
+ 2004 | 4 | bar | | | | ft2 |
+ 2005 | 5 | bar | | | | ft2 |
+ 2006 | 6 | bar | | | | ft2 |
+ 2007 | 7 | bar | | | | ft2 |
+ 2008 | 8 | bar | | | | ft2 |
+ 2009 | 9 | bar | | | | ft2 |
+ 2010 | 0 | bar | | | | ft2 |
+(10 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Update on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: UPDATE "S 1"."T 1" SET c3 = $2 WHERE ctid = $1 RETURNING "C 1", c2, c3, c4, c5, c6, c7, c8
+ -> Nested Loop
+ Output: 'baz'::text, ft2.ctid, ft2.*, ft4.*, ft5.*, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3
+ Join Filter: (ft2.c2 === ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.*, ft2.c2
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Relations: (public.ft4) INNER JOIN (public.ft5)
+ Remote SQL: SELECT CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, r2.c1, r2.c2, r2.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r3.c1, r3.c2, r3.c3 FROM ("S 1"."T 3" r2 INNER JOIN "S 1"."T 4" r3 ON (((r2.c1 = r3.c1))))
+ -> Hash Join
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3, ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Hash Cond: (ft4.c1 = ft5.c1)
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1, ft4.c2, ft4.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Hash
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1, ft5.c2, ft5.c3
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(24 rows)
+
+UPDATE ft2 SET c3 = 'baz'
+ FROM ft4 INNER JOIN ft5 ON (ft4.c1 = ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 === ft4.c1
+ RETURNING ft2.*, ft4.*, ft5.*;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8 | c1 | c2 | c3 | c1 | c2 | c3
+------+----+-----+----+----+----+------------+----+----+----+--------+----+----+--------
+ 2006 | 6 | baz | | | | ft2 | | 6 | 7 | AAA006 | 6 | 7 | AAA006
+(1 row)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3; -- can't be pushed down
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Delete on public.ft2
+ Output: ft2.c1, ft2.c2, ft2.c3
+ Remote SQL: DELETE FROM "S 1"."T 1" WHERE ctid = $1 RETURNING "C 1", c2, c3
+ -> Foreign Scan
+ Output: ft2.ctid, ft4.*, ft5.*
+ Filter: (ft4.c1 === ft5.c1)
+ Relations: ((public.ft2) INNER JOIN (public.ft4)) INNER JOIN (public.ft5)
+ Remote SQL: SELECT r1.ctid, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2.c1, r2.c2, r2.c3) END, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r2.c1, r3.c1 FROM (("S 1"."T 1" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c2 = r2.c1)) AND ((r1."C 1" > 2000)))) INNER JOIN "S 1"."T 4" r3 ON (TRUE)) FOR UPDATE OF r1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft5.*, ft4.c1, ft5.c1
+ -> Nested Loop
+ Output: ft2.ctid, ft4.*, ft4.c1
+ Join Filter: (ft2.c2 = ft4.c1)
+ -> Foreign Scan on public.ft2
+ Output: ft2.ctid, ft2.c2
+ Remote SQL: SELECT c2, ctid FROM "S 1"."T 1" WHERE (("C 1" > 2000)) FOR UPDATE
+ -> Foreign Scan on public.ft4
+ Output: ft4.*, ft4.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 3"
+ -> Foreign Scan on public.ft5
+ Output: ft5.*, ft5.c1
+ Remote SQL: SELECT c1, c2, c3 FROM "S 1"."T 4"
+(22 rows)
+
+DELETE FROM ft2
+ USING ft4 INNER JOIN ft5 ON (ft4.c1 === ft5.c1)
+ WHERE ft2.c1 > 2000 AND ft2.c2 = ft4.c1
+ RETURNING ft2.c1, ft2.c2, ft2.c3;
+ c1 | c2 | c3
+------+----+-----
+ 2006 | 6 | baz
+(1 row)
+
+DELETE FROM ft2 WHERE ft2.c1 > 2000;
+ALTER SERVER loopback OPTIONS (ADD extensions 'postgres_fdw');
+-- Test that trigger on remote table works as expected
+CREATE OR REPLACE FUNCTION "S 1".F_BRTRIG() RETURNS trigger AS $$
+BEGIN
+ NEW.c3 = NEW.c3 || '_trig_update';
+ RETURN NEW;
+END;
+$$ LANGUAGE plpgsql;
+CREATE TRIGGER t1_br_insert BEFORE INSERT OR UPDATE
+ ON "S 1"."T 1" FOR EACH ROW EXECUTE PROCEDURE "S 1".F_BRTRIG();
+INSERT INTO ft2 (c1,c2,c3) VALUES (1208, 818, 'fff') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+----+------------+----
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+(1 row)
+
+INSERT INTO ft2 (c1,c2,c3,c6) VALUES (1218, 818, 'ggg', '(--;') RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+----+----+------+------------+----
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+(1 row)
+
+UPDATE ft2 SET c2 = c2 + 600 WHERE c1 % 10 = 8 AND c1 < 1200 RETURNING *;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+------------------------+------------------------------+--------------------------+----+------------+-----
+ 8 | 608 | 00008_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 18 | 608 | 00018_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 28 | 608 | 00028_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 38 | 608 | 00038_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 48 | 608 | 00048_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 58 | 608 | 00058_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 68 | 608 | 00068_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 78 | 608 | 00078_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 88 | 608 | 00088_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 98 | 608 | 00098_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 108 | 608 | 00108_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 118 | 608 | 00118_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 128 | 608 | 00128_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 138 | 608 | 00138_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 148 | 608 | 00148_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 158 | 608 | 00158_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 168 | 608 | 00168_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 178 | 608 | 00178_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 188 | 608 | 00188_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 198 | 608 | 00198_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 208 | 608 | 00208_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 218 | 608 | 00218_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 228 | 608 | 00228_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 238 | 608 | 00238_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 248 | 608 | 00248_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 258 | 608 | 00258_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 268 | 608 | 00268_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 278 | 608 | 00278_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 288 | 608 | 00288_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 298 | 608 | 00298_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 308 | 608 | 00308_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 318 | 608 | 00318_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 328 | 608 | 00328_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 338 | 608 | 00338_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 348 | 608 | 00348_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 358 | 608 | 00358_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 368 | 608 | 00368_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 378 | 608 | 00378_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 388 | 608 | 00388_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 398 | 608 | 00398_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 408 | 608 | 00408_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 418 | 608 | 00418_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 428 | 608 | 00428_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 438 | 608 | 00438_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 448 | 608 | 00448_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 458 | 608 | 00458_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 468 | 608 | 00468_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 478 | 608 | 00478_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 488 | 608 | 00488_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 498 | 608 | 00498_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 508 | 608 | 00508_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 518 | 608 | 00518_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 528 | 608 | 00528_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 538 | 608 | 00538_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 548 | 608 | 00548_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 558 | 608 | 00558_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 568 | 608 | 00568_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 578 | 608 | 00578_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 588 | 608 | 00588_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 598 | 608 | 00598_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 608 | 608 | 00608_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 618 | 608 | 00618_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 628 | 608 | 00628_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 638 | 608 | 00638_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 648 | 608 | 00648_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 658 | 608 | 00658_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 668 | 608 | 00668_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 678 | 608 | 00678_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 688 | 608 | 00688_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 698 | 608 | 00698_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 708 | 608 | 00708_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 718 | 608 | 00718_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 728 | 608 | 00728_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 738 | 608 | 00738_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 748 | 608 | 00748_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 758 | 608 | 00758_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 768 | 608 | 00768_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 778 | 608 | 00778_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 788 | 608 | 00788_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 798 | 608 | 00798_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 808 | 608 | 00808_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 818 | 608 | 00818_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 828 | 608 | 00828_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 838 | 608 | 00838_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 848 | 608 | 00848_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 858 | 608 | 00858_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 868 | 608 | 00868_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 878 | 608 | 00878_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 888 | 608 | 00888_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 898 | 608 | 00898_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 908 | 608 | 00908_trig_update | Fri Jan 09 00:00:00 1970 PST | Fri Jan 09 00:00:00 1970 | 8 | 8 | foo
+ 918 | 608 | 00918_trig_update | Mon Jan 19 00:00:00 1970 PST | Mon Jan 19 00:00:00 1970 | 8 | 8 | foo
+ 928 | 608 | 00928_trig_update | Thu Jan 29 00:00:00 1970 PST | Thu Jan 29 00:00:00 1970 | 8 | 8 | foo
+ 938 | 608 | 00938_trig_update | Sun Feb 08 00:00:00 1970 PST | Sun Feb 08 00:00:00 1970 | 8 | 8 | foo
+ 948 | 608 | 00948_trig_update | Wed Feb 18 00:00:00 1970 PST | Wed Feb 18 00:00:00 1970 | 8 | 8 | foo
+ 958 | 608 | 00958_trig_update | Sat Feb 28 00:00:00 1970 PST | Sat Feb 28 00:00:00 1970 | 8 | 8 | foo
+ 968 | 608 | 00968_trig_update | Tue Mar 10 00:00:00 1970 PST | Tue Mar 10 00:00:00 1970 | 8 | 8 | foo
+ 978 | 608 | 00978_trig_update | Fri Mar 20 00:00:00 1970 PST | Fri Mar 20 00:00:00 1970 | 8 | 8 | foo
+ 988 | 608 | 00988_trig_update | Mon Mar 30 00:00:00 1970 PST | Mon Mar 30 00:00:00 1970 | 8 | 8 | foo
+ 998 | 608 | 00998_trig_update | Thu Apr 09 00:00:00 1970 PST | Thu Apr 09 00:00:00 1970 | 8 | 8 | foo
+ 1008 | 708 | 0000800008_trig_update | | | | ft2 |
+ 1018 | 708 | 0001800018_trig_update | | | | ft2 |
+(102 rows)
+
+-- Test errors thrown on remote side during update
+ALTER TABLE "S 1"."T 1" ADD CONSTRAINT c2positive CHECK (c2 >= 0);
+INSERT INTO ft1(c1, c2) VALUES(11, 12); -- duplicate key
+ERROR: duplicate key value violates unique constraint "t1_pkey"
+DETAIL: Key ("C 1")=(11) already exists.
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT DO NOTHING; -- works
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO NOTHING; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(11, 12) ON CONFLICT (c1, c2) DO UPDATE SET c3 = 'ffg'; -- unsupported
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+-- Test savepoint/rollback behavior
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+begin;
+update ft2 set c2 = 42 where c2 = 0;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 42 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s1;
+update ft2 set c2 = 44 where c2 = 4;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s1;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s2;
+update ft2 set c2 = 46 where c2 = 6;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 42 | 100
+ 44 | 100
+ 46 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+rollback to savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s2;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+savepoint s3;
+update ft2 set c2 = -2 where c2 = 42 and c1 = 10; -- fail on remote side
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (10, -2, 00010_trig_update_trig_update, 1970-01-11 08:00:00+00, 1970-01-11 00:00:00, 0, 0 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (-2) WHERE ((c2 = 42)) AND (("C 1" = 10))
+rollback to savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+release savepoint s3;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+-- none of the above is committed yet remotely
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 0 | 100
+ 1 | 100
+ 4 | 100
+ 6 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+commit;
+select c2, count(*) from ft2 where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+select c2, count(*) from "S 1"."T 1" where c2 < 500 group by 1 order by 1;
+ c2 | count
+-----+-------
+ 1 | 100
+ 6 | 100
+ 42 | 100
+ 44 | 100
+ 100 | 2
+ 101 | 2
+ 104 | 2
+ 106 | 2
+ 201 | 1
+ 204 | 1
+ 303 | 100
+ 403 | 2
+ 407 | 100
+(13 rows)
+
+VACUUM ANALYZE "S 1"."T 1";
+-- Above DMLs add data with c6 as NULL in ft1, so test ORDER BY NULLS LAST and NULLs
+-- FIRST behavior here.
+-- ORDER BY DESC NULLS LAST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS LAST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 795::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS LAST, c1 OFFSET 795 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+--------------------+------------------------------+--------------------------+------+------------+-----
+ 960 | 42 | 00960_trig_update | Mon Mar 02 00:00:00 1970 PST | Mon Mar 02 00:00:00 1970 | 0 | 0 | foo
+ 970 | 42 | 00970_trig_update | Thu Mar 12 00:00:00 1970 PST | Thu Mar 12 00:00:00 1970 | 0 | 0 | foo
+ 980 | 42 | 00980_trig_update | Sun Mar 22 00:00:00 1970 PST | Sun Mar 22 00:00:00 1970 | 0 | 0 | foo
+ 990 | 42 | 00990_trig_update | Wed Apr 01 00:00:00 1970 PST | Wed Apr 01 00:00:00 1970 | 0 | 0 | foo
+ 1000 | 42 | 01000_trig_update | Thu Jan 01 00:00:00 1970 PST | Thu Jan 01 00:00:00 1970 | 0 | 0 | foo
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 1001 | 101 | 0000100001 | | | | ft2 |
+ 1003 | 403 | 0000300003_update3 | | | | ft2 |
+ 1004 | 104 | 0000400004 | | | | ft2 |
+ 1006 | 106 | 0000600006 | | | | ft2 |
+(10 rows)
+
+-- ORDER BY DESC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 DESC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 DESC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-----------------+------------------------------+--------------------------+----+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 9 | 509 | 00009_update9 | Sat Jan 10 00:00:00 1970 PST | Sat Jan 10 00:00:00 1970 | 9 | ft2 | foo
+ 19 | 509 | 00019_update9 | Tue Jan 20 00:00:00 1970 PST | Tue Jan 20 00:00:00 1970 | 9 | ft2 | foo
+ 29 | 509 | 00029_update9 | Fri Jan 30 00:00:00 1970 PST | Fri Jan 30 00:00:00 1970 | 9 | ft2 | foo
+ 39 | 509 | 00039_update9 | Mon Feb 09 00:00:00 1970 PST | Mon Feb 09 00:00:00 1970 | 9 | ft2 | foo
+ 49 | 509 | 00049_update9 | Thu Feb 19 00:00:00 1970 PST | Thu Feb 19 00:00:00 1970 | 9 | ft2 | foo
+(10 rows)
+
+-- ORDER BY ASC NULLS FIRST options
+EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan on public.ft1
+ Output: c1, c2, c3, c4, c5, c6, c7, c8
+ Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" ORDER BY c6 ASC NULLS FIRST, "C 1" ASC NULLS LAST LIMIT 10::bigint OFFSET 15::bigint
+(3 rows)
+
+SELECT * FROM ft1 ORDER BY c6 ASC NULLS FIRST, c1 OFFSET 15 LIMIT 10;
+ c1 | c2 | c3 | c4 | c5 | c6 | c7 | c8
+------+-----+-------------------+------------------------------+--------------------------+------+------------+-----
+ 1020 | 100 | 0002000020 | | | | ft2 |
+ 1101 | 201 | aaa | | | | ft2 |
+ 1103 | 503 | ccc_update3 | | | | ft2 |
+ 1104 | 204 | ddd | | | | ft2 |
+ 1208 | 818 | fff_trig_update | | | | ft2 |
+ 1218 | 818 | ggg_trig_update | | | (--; | ft2 |
+ 10 | 42 | 00010_trig_update | Sun Jan 11 00:00:00 1970 PST | Sun Jan 11 00:00:00 1970 | 0 | 0 | foo
+ 20 | 42 | 00020_trig_update | Wed Jan 21 00:00:00 1970 PST | Wed Jan 21 00:00:00 1970 | 0 | 0 | foo
+ 30 | 42 | 00030_trig_update | Sat Jan 31 00:00:00 1970 PST | Sat Jan 31 00:00:00 1970 | 0 | 0 | foo
+ 40 | 42 | 00040_trig_update | Tue Feb 10 00:00:00 1970 PST | Tue Feb 10 00:00:00 1970 | 0 | 0 | foo
+(10 rows)
+
+-- ===================================================================
+-- test check constraints
+-- ===================================================================
+-- Consistent check constraints provide consistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2positive CHECK (c2 >= 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 < 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 < 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 < 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- check constraint is enforced on the remote side, not locally
+INSERT INTO ft1(c1, c2) VALUES(1111, -2); -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1111, -2, null, null, null, null, ft1 , null).
+CONTEXT: remote SQL command: INSERT INTO "S 1"."T 1"("C 1", c2, c3, c4, c5, c6, c7, c8) VALUES ($1, $2, $3, $4, $5, $6, $7, $8)
+UPDATE ft1 SET c2 = -c2 WHERE c1 = 1; -- c2positive
+ERROR: new row for relation "T 1" violates check constraint "c2positive"
+DETAIL: Failing row contains (1, -1, 00001_trig_update, 1970-01-02 08:00:00+00, 1970-01-02 00:00:00, 1, 1 , foo).
+CONTEXT: remote SQL command: UPDATE "S 1"."T 1" SET c2 = (- c2) WHERE (("C 1" = 1))
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2positive;
+-- But inconsistent check constraints provide inconsistent results
+ALTER FOREIGN TABLE ft1 ADD CONSTRAINT ft1_c2negative CHECK (c2 < 0);
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+------------------------------------------------------------------
+ Foreign Scan
+ Output: (count(*))
+ Relations: Aggregate on (public.ft1)
+ Remote SQL: SELECT count(*) FROM "S 1"."T 1" WHERE ((c2 >= 0))
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 821
+(1 row)
+
+SET constraint_exclusion = 'on';
+EXPLAIN (VERBOSE, COSTS OFF) SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ QUERY PLAN
+--------------------------------
+ Aggregate
+ Output: count(*)
+ -> Result
+ One-Time Filter: false
+(4 rows)
+
+SELECT count(*) FROM ft1 WHERE c2 >= 0;
+ count
+-------
+ 0
+(1 row)
+
+RESET constraint_exclusion;
+-- local check constraint is not actually enforced
+INSERT INTO ft1(c1, c2) VALUES(1111, 2);
+UPDATE ft1 SET c2 = c2 + 1 WHERE c1 = 1;
+ALTER FOREIGN TABLE ft1 DROP CONSTRAINT ft1_c2negative;
+-- ===================================================================
+-- test WITH CHECK OPTION constraints
+-- ===================================================================
+CREATE FUNCTION row_before_insupd_trigfunc() RETURNS trigger AS $$BEGIN NEW.a := NEW.a + 10; RETURN NEW; END$$ LANGUAGE plpgsql;
+CREATE TABLE base_tbl (a int, b int);
+ALTER TABLE base_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON base_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE VIEW rw_view AS SELECT * FROM foreign_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT foreign_tbl.a,
+ foreign_tbl.b
+ FROM foreign_tbl
+ WHERE foreign_tbl.a < foreign_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 5
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Result
+ Output: 0, 15
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 5), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+---------------------------------------------------------------------------------------
+ Update on public.foreign_tbl
+ Remote SQL: UPDATE public.base_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl
+ Output: (foreign_tbl.b + 15), foreign_tbl.ctid, foreign_tbl.*
+ Remote SQL: SELECT a, b, ctid FROM public.base_tbl WHERE ((a < b)) FOR UPDATE
+(5 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------------------------------
+ Insert on public.foreign_tbl
+ Remote SQL: INSERT INTO public.base_tbl(a, b) VALUES ($1, $2) RETURNING a, b
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(5 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP TRIGGER row_before_insupd_trigger ON base_tbl;
+DROP TABLE base_tbl;
+-- test WCO for partitions
+CREATE TABLE child_tbl (a int, b int);
+ALTER TABLE child_tbl SET (autovacuum_enabled = 'false');
+CREATE TRIGGER row_before_insupd_trigger BEFORE INSERT OR UPDATE ON child_tbl FOR EACH ROW EXECUTE PROCEDURE row_before_insupd_trigfunc();
+CREATE FOREIGN TABLE foreign_tbl (a int, b int)
+ SERVER loopback OPTIONS (table_name 'child_tbl');
+CREATE TABLE parent_tbl (a int, b int) PARTITION BY RANGE(a);
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+-- Detach and re-attach once, to stress the concurrent detach case.
+ALTER TABLE parent_tbl DETACH PARTITION foreign_tbl CONCURRENTLY;
+ALTER TABLE parent_tbl ATTACH PARTITION foreign_tbl FOR VALUES FROM (0) TO (100);
+CREATE VIEW rw_view AS SELECT * FROM parent_tbl
+ WHERE a < b WITH CHECK OPTION;
+\d+ rw_view
+ View "public.rw_view"
+ Column | Type | Collation | Nullable | Default | Storage | Description
+--------+---------+-----------+----------+---------+---------+-------------
+ a | integer | | | | plain |
+ b | integer | | | | plain |
+View definition:
+ SELECT parent_tbl.a,
+ parent_tbl.b
+ FROM parent_tbl
+ WHERE parent_tbl.a < parent_tbl.b;
+Options: check_option=cascaded
+
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 5);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 5
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15);
+ QUERY PLAN
+-----------------------------
+ Insert on public.parent_tbl
+ -> Result
+ Output: 0, 15
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15); -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 10 | 15
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 5;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 5), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 5; -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (20, 20).
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = b + 15;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.foreign_tbl parent_tbl_1
+ Remote SQL: UPDATE public.child_tbl SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Foreign Scan on public.foreign_tbl parent_tbl_1
+ Output: (parent_tbl_1.b + 15), parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.child_tbl WHERE ((a < b)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = b + 15; -- ok
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+-- We don't allow batch insert when there are any WCO constraints
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO rw_view VALUES (0, 15), (0, 5);
+ QUERY PLAN
+--------------------------------------------------------
+ Insert on public.parent_tbl
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, "*VALUES*".column2
+(3 rows)
+
+INSERT INTO rw_view VALUES (0, 15), (0, 5); -- should fail
+ERROR: new row violates check option for view "rw_view"
+DETAIL: Failing row contains (10, 5).
+SELECT * FROM foreign_tbl;
+ a | b
+----+----
+ 20 | 30
+(1 row)
+
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+DROP TRIGGER row_before_insupd_trigger ON child_tbl;
+DROP TABLE parent_tbl CASCADE;
+NOTICE: drop cascades to view rw_view
+DROP FUNCTION row_before_insupd_trigfunc;
+-- Try a more complex permutation of WCO where there are multiple levels of
+-- partitioned tables with columns not all in the same order
+CREATE TABLE parent_tbl (a int, b text, c numeric) PARTITION BY RANGE(a);
+CREATE TABLE sub_parent (c numeric, a int, b text) PARTITION BY RANGE(a);
+ALTER TABLE parent_tbl ATTACH PARTITION sub_parent FOR VALUES FROM (1) TO (10);
+CREATE TABLE child_local (b text, c numeric, a int);
+CREATE FOREIGN TABLE child_foreign (b text, c numeric, a int)
+ SERVER loopback OPTIONS (table_name 'child_local');
+ALTER TABLE sub_parent ATTACH PARTITION child_foreign FOR VALUES FROM (1) TO (10);
+CREATE VIEW rw_view AS SELECT * FROM parent_tbl WHERE a < 5 WITH CHECK OPTION;
+INSERT INTO parent_tbl (a) VALUES(1),(5);
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE rw_view SET b = 'text', c = 123.456;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ Update on public.parent_tbl
+ Foreign Update on public.child_foreign parent_tbl_1
+ Remote SQL: UPDATE public.child_local SET b = $2, c = $3 WHERE ctid = $1 RETURNING a
+ -> Foreign Scan on public.child_foreign parent_tbl_1
+ Output: 'text'::text, 123.456, parent_tbl_1.tableoid, parent_tbl_1.ctid, parent_tbl_1.*
+ Remote SQL: SELECT b, c, a, ctid FROM public.child_local WHERE ((a < 5)) FOR UPDATE
+(6 rows)
+
+UPDATE rw_view SET b = 'text', c = 123.456;
+SELECT * FROM parent_tbl ORDER BY a;
+ a | b | c
+---+------+---------
+ 1 | text | 123.456
+ 5 | |
+(2 rows)
+
+DROP VIEW rw_view;
+DROP TABLE child_local;
+DROP FOREIGN TABLE child_foreign;
+DROP TABLE sub_parent;
+DROP TABLE parent_tbl;
+-- ===================================================================
+-- test serial columns (ie, sequence-based defaults)
+-- ===================================================================
+create table loc1 (f1 serial, f2 text);
+alter table loc1 set (autovacuum_enabled = 'false');
+create foreign table rem1 (f1 serial, f2 text)
+ server loopback options(table_name 'loc1');
+select pg_catalog.setval('rem1_f1_seq', 10, false);
+ setval
+--------
+ 10
+(1 row)
+
+insert into loc1(f2) values('hi');
+insert into rem1(f2) values('hi remote');
+insert into loc1(f2) values('bye');
+insert into rem1(f2) values('bye remote');
+select * from loc1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+select * from rem1;
+ f1 | f2
+----+------------
+ 1 | hi
+ 10 | hi remote
+ 2 | bye
+ 11 | bye remote
+(4 rows)
+
+-- ===================================================================
+-- test generated columns
+-- ===================================================================
+create table gloc1 (
+ a int,
+ b int generated always as (a * 2) stored);
+alter table gloc1 set (autovacuum_enabled = 'false');
+create foreign table grem1 (
+ a int,
+ b int generated always as (a * 2) stored)
+ server loopback options(table_name 'gloc1');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+explain (verbose, costs off)
+update grem1 set a = 22 where a = 2;
+ QUERY PLAN
+------------------------------------------------------------------------------------
+ Update on public.grem1
+ Remote SQL: UPDATE public.gloc1 SET a = $2, b = DEFAULT WHERE ctid = $1
+ -> Foreign Scan on public.grem1
+ Output: 22, ctid, grem1.*
+ Remote SQL: SELECT a, b, ctid FROM public.gloc1 WHERE ((a = 2)) FOR UPDATE
+(5 rows)
+
+update grem1 set a = 22 where a = 2;
+select * from gloc1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+select * from grem1;
+ a | b
+----+----
+ 1 | 2
+ 22 | 44
+(2 rows)
+
+delete from grem1;
+-- test copy from
+copy grem1 from stdin;
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+-- test batch insert
+alter server loopback options (add batch_size '10');
+explain (verbose, costs off)
+insert into grem1 (a) values (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------------
+ Insert on public.grem1
+ Remote SQL: INSERT INTO public.gloc1(a, b) VALUES ($1, DEFAULT)
+ Batch Size: 10
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1, NULL::integer
+(5 rows)
+
+insert into grem1 (a) values (1), (2);
+select * from gloc1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+select * from grem1;
+ a | b
+---+---
+ 1 | 2
+ 2 | 4
+(2 rows)
+
+delete from grem1;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test local triggers
+-- ===================================================================
+-- Trigger functions "borrowed" from triggers regress test.
+CREATE FUNCTION trigger_func() RETURNS trigger LANGUAGE plpgsql AS $$
+BEGIN
+ RAISE NOTICE 'trigger_func(%) called: action = %, when = %, level = %',
+ TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
+ RETURN NULL;
+END;$$;
+CREATE TRIGGER trig_stmt_before BEFORE DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE TRIGGER trig_stmt_after AFTER DELETE OR INSERT OR UPDATE OR TRUNCATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+CREATE OR REPLACE FUNCTION trigger_data() RETURNS trigger
+LANGUAGE plpgsql AS $$
+
+declare
+ oldnew text[];
+ relid text;
+ argstr text;
+begin
+
+ relid := TG_relid::regclass;
+ argstr := '';
+ for i in 0 .. TG_nargs - 1 loop
+ if i > 0 then
+ argstr := argstr || ', ';
+ end if;
+ argstr := argstr || TG_argv[i];
+ end loop;
+
+ RAISE NOTICE '%(%) % % % ON %',
+ tg_name, argstr, TG_when, TG_level, TG_OP, relid;
+ oldnew := '{}'::text[];
+ if TG_OP != 'INSERT' then
+ oldnew := array_append(oldnew, format('OLD: %s', OLD));
+ end if;
+
+ if TG_OP != 'DELETE' then
+ oldnew := array_append(oldnew, format('NEW: %s', NEW));
+ end if;
+
+ RAISE NOTICE '%', array_to_string(oldnew, ',');
+
+ if TG_OP = 'DELETE' then
+ return OLD;
+ else
+ return NEW;
+ end if;
+end;
+$$;
+-- Test basic functionality
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+delete from rem1;
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,hi)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (10,"hi remote")
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,bye)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (11,"bye remote")
+NOTICE: trigger_func(<NULL>) called: action = DELETE, when = AFTER, level = STATEMENT
+insert into rem1 values(1,'insert');
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+update rem1 set f2 = f2 || f2;
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trigger_func(<NULL>) called: action = UPDATE, when = AFTER, level = STATEMENT
+truncate rem1;
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = BEFORE, level = STATEMENT
+NOTICE: trigger_func(<NULL>) called: action = TRUNCATE, when = AFTER, level = STATEMENT
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_stmt_before ON rem1;
+DROP TRIGGER trig_stmt_after ON rem1;
+DELETE from rem1;
+-- Test multiple AFTER ROW triggers on a foreign table
+CREATE TRIGGER trig_row_after1
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after2
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+insert into rem1 values(1,'insert');
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (1,insert)
+update rem1 set f2 = 'update' where f1 = 1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,insert),NEW: (1,update)
+update rem1 set f2 = f2 || f2;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (1,update),NEW: (1,updateupdate)
+delete from rem1;
+NOTICE: trig_row_after1(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+NOTICE: trig_row_after2(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (1,updateupdate)
+-- cleanup
+DROP TRIGGER trig_row_after1 ON rem1;
+DROP TRIGGER trig_row_after2 ON rem1;
+-- Test WHEN conditions
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_insupd
+AFTER INSERT OR UPDATE ON rem1
+FOR EACH ROW
+WHEN (NEW.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Insert or update not matching: nothing happens
+INSERT INTO rem1 values(1, 'insert');
+UPDATE rem1 set f2 = 'test';
+-- Insert or update matching: triggers are fired
+INSERT INTO rem1 values(2, 'update');
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (2,update)
+UPDATE rem1 set f2 = 'update update' where f1 = '2';
+NOTICE: trig_row_before_insupd(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+NOTICE: trig_row_after_insupd(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (2,update),NEW: (2,"update update")
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW
+WHEN (OLD.f2 like '%update%')
+EXECUTE PROCEDURE trigger_data(23,'skidoo');
+-- Trigger is fired for f1=2, not for f1=1
+DELETE FROM rem1;
+NOTICE: trig_row_before_delete(23, skidoo) BEFORE ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+NOTICE: trig_row_after_delete(23, skidoo) AFTER ROW DELETE ON rem1
+NOTICE: OLD: (2,"update update")
+-- cleanup
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_after_insupd ON rem1;
+DROP TRIGGER trig_row_before_delete ON rem1;
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- Test various RETURN statements in BEFORE triggers.
+CREATE FUNCTION trig_row_before_insupdate() RETURNS TRIGGER AS $$
+ BEGIN
+ NEW.f2 := NEW.f2 || ' triggered !';
+ RETURN NEW;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_row_before_insupd
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+-- The new values should have 'triggered' appended
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------
+ insert triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | insert triggered !
+ 2 | insert triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------
+ 1 | triggered !
+ 2 | triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------
+ skidoo triggered !
+ skidoo triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------
+ 1 | skidoo triggered !
+ 2 | skidoo triggered !
+(2 rows)
+
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f1 = 10; -- all columns should be transmitted
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: 10, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+UPDATE rem1 set f1 = 10;
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 10 | skidoo triggered ! triggered !
+ 10 | skidoo triggered ! triggered !
+(2 rows)
+
+DELETE FROM rem1;
+-- Add a second trigger, to check that the changes are propagated correctly
+-- from trigger to trigger
+CREATE TRIGGER trig_row_before_insupd2
+BEFORE INSERT OR UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1 values(1, 'insert');
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+(1 row)
+
+INSERT INTO rem1 values(2, 'insert') RETURNING f2;
+ f2
+--------------------------------
+ insert triggered ! triggered !
+(1 row)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | insert triggered ! triggered !
+ 2 | insert triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = '';
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------
+ 1 | triggered ! triggered !
+ 2 | triggered ! triggered !
+(2 rows)
+
+UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
+ f2
+--------------------------------
+ skidoo triggered ! triggered !
+ skidoo triggered ! triggered !
+(2 rows)
+
+SELECT * from loc1;
+ f1 | f2
+----+--------------------------------
+ 1 | skidoo triggered ! triggered !
+ 2 | skidoo triggered ! triggered !
+(2 rows)
+
+DROP TRIGGER trig_row_before_insupd ON rem1;
+DROP TRIGGER trig_row_before_insupd2 ON rem1;
+DELETE from rem1;
+INSERT INTO rem1 VALUES (1, 'test');
+-- Test with a trigger returning NULL
+CREATE FUNCTION trig_null() RETURNS TRIGGER AS $$
+ BEGIN
+ RETURN NULL;
+ END
+$$ language plpgsql;
+CREATE TRIGGER trig_null
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trig_null();
+-- Nothing should have changed.
+INSERT INTO rem1 VALUES (2, 'test2');
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+UPDATE rem1 SET f2 = 'test2';
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DELETE from rem1;
+SELECT * from loc1;
+ f1 | f2
+----+------
+ 1 | test
+(1 row)
+
+DROP TRIGGER trig_null ON rem1;
+DELETE from rem1;
+-- Test a combination of local and remote triggers
+CREATE TRIGGER trig_row_before
+BEFORE INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER INSERT OR UPDATE OR DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_local_before BEFORE INSERT OR UPDATE ON loc1
+FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
+INSERT INTO rem1(f2) VALUES ('test');
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (12,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (12,"test triggered !")
+UPDATE rem1 SET f2 = 'testo';
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,testo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON rem1
+NOTICE: OLD: (12,"test triggered !"),NEW: (12,"testo triggered !")
+-- Test returning a system attribute
+INSERT INTO rem1(f2) VALUES ('test') RETURNING ctid;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem1
+NOTICE: NEW: (13,test)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem1
+NOTICE: NEW: (13,"test triggered !")
+ ctid
+--------
+ (0,25)
+(1 row)
+
+-- cleanup
+DROP TRIGGER trig_row_before ON rem1;
+DROP TRIGGER trig_row_after ON rem1;
+DROP TRIGGER trig_local_before ON loc1;
+-- Test direct foreign table modification functionality
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1 WHERE false; -- currently can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Result
+ Output: ctid
+ One-Time Filter: false
+(5 rows)
+
+-- Test with statement-level triggers
+CREATE TRIGGER trig_stmt_before
+ BEFORE DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_before ON rem1;
+CREATE TRIGGER trig_stmt_after
+ AFTER DELETE OR INSERT OR UPDATE ON rem1
+ FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_stmt_after ON rem1;
+-- Test with row-level ON INSERT triggers
+CREATE TRIGGER trig_row_before_insert
+BEFORE INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_insert ON rem1;
+CREATE TRIGGER trig_row_after_insert
+AFTER INSERT ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_insert ON rem1;
+-- Test with row-level ON UPDATE triggers
+CREATE TRIGGER trig_row_before_update
+BEFORE UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f1 = $2, f2 = $3 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_before_update ON rem1;
+CREATE TRIGGER trig_row_after_update
+AFTER UPDATE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can't be pushed down
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = $2 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ''::text, ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can be pushed down
+ QUERY PLAN
+---------------------------------------------
+ Delete on public.rem1
+ -> Foreign Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1
+(3 rows)
+
+DROP TRIGGER trig_row_after_update ON rem1;
+-- Test with row-level ON DELETE triggers
+CREATE TRIGGER trig_row_before_delete
+BEFORE DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+---------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_before_delete ON rem1;
+CREATE TRIGGER trig_row_after_delete
+AFTER DELETE ON rem1
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (verbose, costs off)
+UPDATE rem1 set f2 = ''; -- can be pushed down
+ QUERY PLAN
+----------------------------------------------------------
+ Update on public.rem1
+ -> Foreign Update on public.rem1
+ Remote SQL: UPDATE public.loc1 SET f2 = ''::text
+(3 rows)
+
+EXPLAIN (verbose, costs off)
+DELETE FROM rem1; -- can't be pushed down
+ QUERY PLAN
+------------------------------------------------------------------------
+ Delete on public.rem1
+ Remote SQL: DELETE FROM public.loc1 WHERE ctid = $1 RETURNING f1, f2
+ -> Foreign Scan on public.rem1
+ Output: ctid, rem1.*
+ Remote SQL: SELECT f1, f2, ctid FROM public.loc1 FOR UPDATE
+(5 rows)
+
+DROP TRIGGER trig_row_after_delete ON rem1;
+-- ===================================================================
+-- test inheritance features
+-- ===================================================================
+CREATE TABLE a (aa TEXT);
+CREATE TABLE loct (aa TEXT, bb TEXT);
+ALTER TABLE a SET (autovacuum_enabled = 'false');
+ALTER TABLE loct SET (autovacuum_enabled = 'false');
+CREATE FOREIGN TABLE b (bb TEXT) INHERITS (a)
+ SERVER loopback OPTIONS (table_name 'loct');
+INSERT INTO a(aa) VALUES('aaa');
+INSERT INTO a(aa) VALUES('aaaa');
+INSERT INTO a(aa) VALUES('aaaaa');
+INSERT INTO b(aa) VALUES('bbb');
+INSERT INTO b(aa) VALUES('bbbb');
+INSERT INTO b(aa) VALUES('bbbbb');
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+-------
+ a | aaa
+ a | aaaa
+ a | aaaaa
+(3 rows)
+
+UPDATE a SET aa = 'zzzzzz' WHERE aa LIKE 'aaaa%';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | bbb
+ b | bbbb
+ b | bbbbb
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-------+----
+ b | bbb |
+ b | bbbb |
+ b | bbbbb |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE b SET aa = 'new';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+ b | new
+ b | new
+ b | new
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+-----+----
+ b | new |
+ b | new |
+ b | new |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | aaa
+ a | zzzzzz
+ a | zzzzzz
+(3 rows)
+
+UPDATE a SET aa = 'newtoo';
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+ b | newtoo
+ b | newtoo
+ b | newtoo
+(6 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+--------+----
+ b | newtoo |
+ b | newtoo |
+ b | newtoo |
+(3 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+--------
+ a | newtoo
+ a | newtoo
+ a | newtoo
+(3 rows)
+
+DELETE FROM a;
+SELECT tableoid::regclass, * FROM a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM b;
+ tableoid | aa | bb
+----------+----+----
+(0 rows)
+
+SELECT tableoid::regclass, * FROM ONLY a;
+ tableoid | aa
+----------+----
+(0 rows)
+
+DROP TABLE a CASCADE;
+NOTICE: drop cascades to foreign table b
+DROP TABLE loct;
+-- Check SELECT FOR UPDATE/SHARE with an inherited source table
+create table loct1 (f1 int, f2 int, f3 int);
+create table loct2 (f1 int, f2 int, f3 int);
+alter table loct1 set (autovacuum_enabled = 'false');
+alter table loct2 set (autovacuum_enabled = 'false');
+create table foo (f1 int, f2 int);
+create foreign table foo2 (f3 int) inherits (foo)
+ server loopback options (table_name 'loct1');
+create table bar (f1 int, f2 int);
+create foreign table bar2 (f3 int) inherits (bar)
+ server loopback options (table_name 'loct2');
+alter table foo set (autovacuum_enabled = 'false');
+alter table bar set (autovacuum_enabled = 'false');
+insert into foo values(1,1);
+insert into foo values(3,3);
+insert into foo2 values(2,2,2);
+insert into foo2 values(4,4,4);
+insert into bar values(1,11);
+insert into bar values(2,22);
+insert into bar values(6,66);
+insert into bar2 values(3,33,33);
+insert into bar2 values(4,44,44);
+insert into bar2 values(7,77,77);
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for update;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for update;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo) for share;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo.ctid, bar.*, bar.tableoid, foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo) for share;
+ f1 | f2
+----+----
+ 1 | 11
+ 2 | 22
+ 3 | 33
+ 4 | 44
+(4 rows)
+
+-- Now check SELECT FOR UPDATE/SHARE with an inherited source table,
+-- where the parent is itself a foreign table
+create table loct4 (f1 int, f2 int, f3 int);
+create foreign table foo2child (f3 int) inherits (foo2)
+ server loopback options (table_name 'loct4');
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct1
+ -> Foreign Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.tableoid
+ Remote SQL: SELECT f1, f2, f3 FROM public.loct4
+(24 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop foreign table foo2child;
+-- And with a local child relation of the foreign table parent
+create table foo2child (f3 int) inherits (foo2);
+NOTICE: moving and merging column "f3" with inherited definition
+DETAIL: User-specified column moved to the position of the inherited column.
+explain (verbose, costs off)
+select * from bar where f1 in (select f1 from foo2) for share;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------
+ LockRows
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ -> Hash Join
+ Output: bar.f1, bar.f2, bar.ctid, foo2.*, bar.*, bar.tableoid, foo2.ctid, foo2.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo2.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f1, bar_1.f2, bar_1.ctid, bar_1.*, bar_1.tableoid
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f1, bar_2.f2, bar_2.ctid, bar_2.*, bar_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR SHARE
+ -> Hash
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ -> HashAggregate
+ Output: foo2.*, foo2.f1, foo2.ctid, foo2.tableoid
+ Group Key: foo2.f1
+ -> Append
+ -> Foreign Scan on public.foo2 foo2_1
+ Output: foo2_1.*, foo2_1.f1, foo2_1.ctid, foo2_1.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+ -> Seq Scan on public.foo2child foo2_2
+ Output: foo2_2.*, foo2_2.f1, foo2_2.ctid, foo2_2.tableoid
+(23 rows)
+
+select * from bar where f1 in (select f1 from foo2) for share;
+ f1 | f2
+----+----
+ 2 | 22
+ 4 | 44
+(2 rows)
+
+drop table foo2child;
+-- Check UPDATE with inherited target and an inherited source table
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Hash Join
+ Output: (bar.f2 + 100), foo.ctid, bar.tableoid, bar.ctid, (NULL::record), foo.*, foo.tableoid
+ Inner Unique: true
+ Hash Cond: (bar.f1 = foo.f1)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Hash
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ -> HashAggregate
+ Output: foo.ctid, foo.f1, foo.*, foo.tableoid
+ Group Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo foo_1
+ Output: foo_1.ctid, foo_1.f1, foo_1.*, foo_1.tableoid
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.ctid, foo_2.f1, foo_2.*, foo_2.tableoid
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct1
+(25 rows)
+
+update bar set f2 = f2 + 100 where f1 in (select f1 from foo);
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 111
+ bar | 2 | 122
+ bar | 6 | 66
+ bar2 | 3 | 133
+ bar2 | 4 | 144
+ bar2 | 7 | 77
+(6 rows)
+
+-- Check UPDATE with inherited target and an appendrel subquery
+explain (verbose, costs off)
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = $2 WHERE ctid = $1
+ -> Merge Join
+ Output: (bar.f2 + 100), (ROW(foo.f1)), bar.tableoid, bar.ctid, (NULL::record)
+ Merge Cond: (bar.f1 = foo.f1)
+ -> Sort
+ Output: bar.f2, bar.f1, bar.tableoid, bar.ctid, (NULL::record)
+ Sort Key: bar.f1
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.f1, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.f1, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+ -> Sort
+ Output: (ROW(foo.f1)), foo.f1
+ Sort Key: foo.f1
+ -> Append
+ -> Seq Scan on public.foo
+ Output: ROW(foo.f1), foo.f1
+ -> Foreign Scan on public.foo2 foo_1
+ Output: ROW(foo_1.f1), foo_1.f1
+ Remote SQL: SELECT f1 FROM public.loct1
+ -> Seq Scan on public.foo foo_2
+ Output: ROW((foo_2.f1 + 3)), (foo_2.f1 + 3)
+ -> Foreign Scan on public.foo2 foo_3
+ Output: ROW((foo_3.f1 + 3)), (foo_3.f1 + 3)
+ Remote SQL: SELECT f1 FROM public.loct1
+(30 rows)
+
+update bar set f2 = f2 + 100
+from
+ ( select f1 from foo union all select f1+3 from foo ) ss
+where bar.f1 = ss.f1;
+select tableoid::regclass, * from bar order by 1,2;
+ tableoid | f1 | f2
+----------+----+-----
+ bar | 1 | 211
+ bar | 2 | 222
+ bar | 6 | 166
+ bar2 | 3 | 233
+ bar2 | 4 | 244
+ bar2 | 7 | 177
+(6 rows)
+
+-- Test forcing the remote server to produce sorted data for a merge join,
+-- but the foreign table is an inheritance child.
+truncate table loct1;
+truncate table only foo;
+\set num_rows_foo 2000
+insert into loct1 select generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2), generate_series(0, :num_rows_foo, 2);
+insert into foo select generate_series(1, :num_rows_foo, 2), generate_series(1, :num_rows_foo, 2);
+SET enable_hashjoin to false;
+SET enable_nestloop to false;
+alter foreign table foo2 options (use_remote_estimate 'true');
+create index i_loct1_f1 on loct1(f1);
+create index i_foo_f1 on foo(f1);
+analyze foo;
+analyze loct1;
+-- inner join; expressions in the clauses appear in the equivalence class list
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 20 | 20
+ 22 | 22
+ 24 | 24
+ 26 | 26
+ 28 | 28
+ 30 | 30
+ 32 | 32
+ 34 | 34
+ 36 | 36
+ 38 | 38
+(10 rows)
+
+-- outer join; expressions in the clauses do not appear in equivalence class
+-- list but no output change as compared to the previous query
+explain (verbose, costs off)
+ select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------
+ Limit
+ Output: foo.f1, loct1.f1, foo.f2
+ -> Sort
+ Output: foo.f1, loct1.f1, foo.f2
+ Sort Key: foo.f2
+ -> Merge Left Join
+ Output: foo.f1, loct1.f1, foo.f2
+ Merge Cond: (foo.f1 = loct1.f1)
+ -> Merge Append
+ Sort Key: foo.f1
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.f1, foo_1.f2
+ -> Foreign Scan on public.foo2 foo_2
+ Output: foo_2.f1, foo_2.f2
+ Remote SQL: SELECT f1, f2 FROM public.loct1 ORDER BY f1 ASC NULLS LAST
+ -> Index Only Scan using i_loct1_f1 on public.loct1
+ Output: loct1.f1
+(17 rows)
+
+select foo.f1, loct1.f1 from foo left join loct1 on (foo.f1 = loct1.f1) order by foo.f2 offset 10 limit 10;
+ f1 | f1
+----+----
+ 10 | 10
+ 11 |
+ 12 | 12
+ 13 |
+ 14 | 14
+ 15 |
+ 16 | 16
+ 17 |
+ 18 | 18
+ 19 |
+(10 rows)
+
+RESET enable_hashjoin;
+RESET enable_nestloop;
+-- Test that WHERE CURRENT OF is not supported
+begin;
+declare c cursor for select * from bar where f1 = 7;
+fetch from c;
+ f1 | f2
+----+-----
+ 7 | 177
+(1 row)
+
+update bar set f2 = null where current of c;
+ERROR: WHERE CURRENT OF is not supported for this table type
+rollback;
+explain (verbose, costs off)
+delete from foo where f1 < 5 returning *;
+ QUERY PLAN
+--------------------------------------------------------------------------------------
+ Delete on public.foo
+ Output: foo_1.f1, foo_1.f2
+ Delete on public.foo foo_1
+ Foreign Delete on public.foo2 foo_2
+ -> Append
+ -> Index Scan using i_foo_f1 on public.foo foo_1
+ Output: foo_1.tableoid, foo_1.ctid
+ Index Cond: (foo_1.f1 < 5)
+ -> Foreign Delete on public.foo2 foo_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ((f1 < 5)) RETURNING f1, f2
+(10 rows)
+
+delete from foo where f1 < 5 returning *;
+ f1 | f2
+----+----
+ 1 | 1
+ 3 | 3
+ 0 | 0
+ 2 | 2
+ 4 | 4
+(5 rows)
+
+explain (verbose, costs off)
+update bar set f2 = f2 + 100 returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Update on public.bar
+ Output: bar_1.f1, bar_1.f2
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f2 = (f2 + 100) RETURNING f1, f2
+(11 rows)
+
+update bar set f2 = f2 + 100 returning *;
+ f1 | f2
+----+-----
+ 1 | 311
+ 2 | 322
+ 6 | 266
+ 3 | 333
+ 4 | 344
+ 7 | 277
+(6 rows)
+
+-- Test that UPDATE/DELETE with inherited target works with row-level triggers
+CREATE TRIGGER trig_row_before
+BEFORE UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+CREATE TRIGGER trig_row_after
+AFTER UPDATE OR DELETE ON bar2
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+explain (verbose, costs off)
+update bar set f2 = f2 + 100;
+ QUERY PLAN
+--------------------------------------------------------------------------------------------------------
+ Update on public.bar
+ Update on public.bar bar_1
+ Foreign Update on public.bar2 bar_2
+ Remote SQL: UPDATE public.loct2 SET f1 = $2, f2 = $3, f3 = $4 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Result
+ Output: (bar.f2 + 100), bar.tableoid, bar.ctid, (NULL::record)
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.f2, bar_1.tableoid, bar_1.ctid, NULL::record
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.f2, bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 FOR UPDATE
+(12 rows)
+
+update bar set f2 = f2 + 100;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (3,333,33),NEW: (3,433,33)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (4,344,44),NEW: (4,444,44)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW UPDATE ON bar2
+NOTICE: OLD: (7,277,77),NEW: (7,377,77)
+explain (verbose, costs off)
+delete from bar where f2 < 400;
+ QUERY PLAN
+---------------------------------------------------------------------------------------------------
+ Delete on public.bar
+ Delete on public.bar bar_1
+ Foreign Delete on public.bar2 bar_2
+ Remote SQL: DELETE FROM public.loct2 WHERE ctid = $1 RETURNING f1, f2, f3
+ -> Append
+ -> Seq Scan on public.bar bar_1
+ Output: bar_1.tableoid, bar_1.ctid, NULL::record
+ Filter: (bar_1.f2 < 400)
+ -> Foreign Scan on public.bar2 bar_2
+ Output: bar_2.tableoid, bar_2.ctid, bar_2.*
+ Remote SQL: SELECT f1, f2, f3, ctid FROM public.loct2 WHERE ((f2 < 400)) FOR UPDATE
+(11 rows)
+
+delete from bar where f2 < 400;
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW DELETE ON bar2
+NOTICE: OLD: (7,377,77)
+-- cleanup
+drop table foo cascade;
+NOTICE: drop cascades to foreign table foo2
+drop table bar cascade;
+NOTICE: drop cascades to foreign table bar2
+drop table loct1;
+drop table loct2;
+-- Test pushing down UPDATE/DELETE joins to the remote server
+create table parent (a int, b text);
+create table loct1 (a int, b text);
+create table loct2 (a int, b text);
+create foreign table remt1 (a int, b text)
+ server loopback options (table_name 'loct1');
+create foreign table remt2 (a int, b text)
+ server loopback options (table_name 'loct2');
+alter foreign table remt1 inherit parent;
+insert into remt1 values (1, 'foo');
+insert into remt1 values (2, 'bar');
+insert into remt2 values (1, 'foo');
+insert into remt2 values (2, 'bar');
+analyze remt1;
+analyze remt2;
+explain (verbose, costs off)
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------
+ Update on public.parent
+ Output: parent_1.a, parent_1.b, remt2.a, remt2.b
+ Update on public.parent parent_1
+ Foreign Update on public.remt1 parent_2
+ Remote SQL: UPDATE public.loct1 SET b = $2 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: (parent.b || remt2.b), remt2.*, remt2.a, remt2.b, parent.tableoid, parent.ctid, (NULL::record)
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.b, parent_1.a, parent_1.tableoid, parent_1.ctid, NULL::record
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.b, parent_2.a, parent_2.tableoid, parent_2.ctid, parent_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.b, remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.b, remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+update parent set b = parent.b || remt2.b from remt2 where parent.a = remt2.a returning *;
+ a | b | a | b
+---+--------+---+-----
+ 1 | foofoo | 1 | foo
+ 2 | barbar | 2 | bar
+(2 rows)
+
+explain (verbose, costs off)
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Delete on public.parent
+ Output: parent_1.*
+ Delete on public.parent parent_1
+ Foreign Delete on public.remt1 parent_2
+ Remote SQL: DELETE FROM public.loct1 WHERE ctid = $1 RETURNING a, b
+ -> Nested Loop
+ Output: remt2.*, parent.tableoid, parent.ctid
+ Join Filter: (parent.a = remt2.a)
+ -> Append
+ -> Seq Scan on public.parent parent_1
+ Output: parent_1.a, parent_1.tableoid, parent_1.ctid
+ -> Foreign Scan on public.remt1 parent_2
+ Output: parent_2.a, parent_2.tableoid, parent_2.ctid
+ Remote SQL: SELECT a, ctid FROM public.loct1 FOR UPDATE
+ -> Materialize
+ Output: remt2.*, remt2.a
+ -> Foreign Scan on public.remt2
+ Output: remt2.*, remt2.a
+ Remote SQL: SELECT a, b FROM public.loct2
+(19 rows)
+
+delete from parent using remt2 where parent.a = remt2.a returning parent;
+ parent
+------------
+ (1,foofoo)
+ (2,barbar)
+(2 rows)
+
+-- cleanup
+drop foreign table remt1;
+drop foreign table remt2;
+drop table loct1;
+drop table loct2;
+drop table parent;
+-- ===================================================================
+-- test tuple routing for foreign-table partitions
+-- ===================================================================
+-- Test insert tuple routing
+create table itrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table itrtest attach partition remp1 for values in (1);
+alter table itrtest attach partition remp2 for values in (2);
+insert into itrtest values (1, 'foo');
+insert into itrtest values (1, 'bar') returning *;
+ a | b
+---+-----
+ 1 | bar
+(1 row)
+
+insert into itrtest values (2, 'baz');
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----
+ 2 | qux
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------
+ 1 | test1
+ 2 | test2
+(2 rows)
+
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from itrtest;
+-- MERGE ought to fail cleanly
+merge into itrtest using (select 1, 'foo') as source on (true)
+ when matched then do nothing;
+ERROR: cannot execute MERGE on relation "remp1"
+DETAIL: This operation is not supported for foreign tables.
+create unique index loct1_idx on loct1 (a);
+-- DO NOTHING without an inference specification is supported
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+-----
+ 1 | foo
+(1 row)
+
+insert into itrtest values (1, 'foo') on conflict do nothing returning *;
+ a | b
+---+---
+(0 rows)
+
+-- But other cases are not supported
+insert into itrtest values (1, 'bar') on conflict (a) do nothing;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+insert into itrtest values (1, 'bar') on conflict (a) do update set b = excluded.b;
+ERROR: there is no unique or exclusion constraint matching the ON CONFLICT specification
+select tableoid::regclass, * FROM itrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+delete from itrtest;
+drop index loct1_idx;
+-- Test that remote triggers work with insert tuple routing
+create function br_insert_trigfunc() returns trigger as $$
+begin
+ new.b := new.b || ' triggered !';
+ return new;
+end
+$$ language plpgsql;
+create trigger loct1_br_insert_trigger before insert on loct1
+ for each row execute procedure br_insert_trigfunc();
+create trigger loct2_br_insert_trigger before insert on loct2
+ for each row execute procedure br_insert_trigfunc();
+-- The new values are concatenated with ' triggered !'
+insert into itrtest values (1, 'foo') returning *;
+ a | b
+---+-----------------
+ 1 | foo triggered !
+(1 row)
+
+insert into itrtest values (2, 'qux') returning *;
+ a | b
+---+-----------------
+ 2 | qux triggered !
+(1 row)
+
+insert into itrtest values (1, 'test1'), (2, 'test2') returning *;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+with result as (insert into itrtest values (1, 'test1'), (2, 'test2') returning *) select * from result;
+ a | b
+---+-------------------
+ 1 | test1 triggered !
+ 2 | test2 triggered !
+(2 rows)
+
+drop trigger loct1_br_insert_trigger on loct1;
+drop trigger loct2_br_insert_trigger on loct2;
+drop table itrtest;
+drop table loct1;
+drop table loct2;
+-- Test update tuple routing
+create table utrtest (a int, b text) partition by list (a);
+create table loct (a int check (a in (1)), b text);
+create foreign table remp (a int check (a in (1)), b text) server loopback options (table_name 'loct');
+create table locp (a int check (a in (2)), b text);
+alter table utrtest attach partition remp for values in (1);
+alter table utrtest attach partition locp for values in (2);
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- It's not allowed to move a row from a partition that is foreign to another
+update utrtest set a = 2 where b = 'foo' returning *;
+ERROR: new row for relation "loct" violates check constraint "loct_a_check"
+DETAIL: Failing row contains (2, foo).
+CONTEXT: remote SQL command: UPDATE public.loct SET a = 2 WHERE ((b = 'foo')) RETURNING a, b
+-- But the reverse is allowed
+update utrtest set a = 1 where b = 'qux' returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+select tableoid::regclass, * FROM utrtest;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+ locp | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp;
+ tableoid | a | b
+----------+---+-----
+ remp | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM locp;
+ tableoid | a | b
+----------+---+-----
+ locp | 2 | qux
+(1 row)
+
+-- The executor should not let unexercised FDWs shut down
+update utrtest set a = 1 where b = 'foo';
+-- Test that remote triggers work with update tuple routing
+create trigger loct_br_insert_trigger before insert on loct
+ for each row execute procedure br_insert_trigfunc();
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition is a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 WHERE (((a = 1) OR (a = 2))) RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ Filter: ((utrtest_2.a = 1) OR (utrtest_2.a = 2))
+(10 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 1 or a = 2 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (2, 'qux');
+-- Check case where the foreign partition isn't a subplan target rel
+explain (verbose, costs off)
+update utrtest set a = 1 where a = 2 returning *;
+ QUERY PLAN
+-------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ -> Seq Scan on public.locp utrtest_1
+ Output: 1, utrtest_1.tableoid, utrtest_1.ctid
+ Filter: (utrtest_1.a = 2)
+(6 rows)
+
+-- The new values are concatenated with ' triggered !'
+update utrtest set a = 1 where a = 2 returning *;
+ a | b
+---+-----------------
+ 1 | qux triggered !
+(1 row)
+
+drop trigger loct_br_insert_trigger on loct;
+-- We can move rows to a foreign partition that has been updated already,
+-- but can't move rows to a foreign partition that hasn't been updated yet
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- Test the former case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Foreign Update on public.remp utrtest_1
+ Update on public.locp utrtest_2
+ -> Append
+ -> Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = 1 RETURNING a, b
+ -> Seq Scan on public.locp utrtest_2
+ Output: 1, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+(9 rows)
+
+update utrtest set a = 1 returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+delete from utrtest;
+insert into utrtest values (1, 'foo');
+insert into utrtest values (2, 'qux');
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Foreign Update on public.remp utrtest_1
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ Update on public.locp utrtest_2
+ -> Hash Join
+ Output: 1, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, utrtest.*
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Foreign Scan on public.remp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, utrtest_1.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Seq Scan on public.locp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, NULL::record
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 1 from (values (1), (2)) s(x) where a = s.x returning *;
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- Change the definition of utrtest so that the foreign partition get updated
+-- after the local partition
+delete from utrtest;
+alter table utrtest detach partition remp;
+drop foreign table remp;
+alter table loct drop constraint loct_a_check;
+alter table loct add check (a in (3));
+create foreign table remp (a int check (a in (3)), b text) server loopback options (table_name 'loct');
+alter table utrtest attach partition remp for values in (3);
+insert into utrtest values (2, 'qux');
+insert into utrtest values (3, 'xyzzy');
+-- Test the latter case:
+-- with a direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 returning *;
+ QUERY PLAN
+---------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: 3, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = 3 RETURNING a, b
+(9 rows)
+
+update utrtest set a = 3 returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+-- with a non-direct modification plan
+explain (verbose, costs off)
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Update on public.utrtest
+ Output: utrtest_1.a, utrtest_1.b, "*VALUES*".column1
+ Update on public.locp utrtest_1
+ Foreign Update on public.remp utrtest_2
+ Remote SQL: UPDATE public.loct SET a = $2 WHERE ctid = $1 RETURNING a, b
+ -> Hash Join
+ Output: 3, "*VALUES*".*, "*VALUES*".column1, utrtest.tableoid, utrtest.ctid, (NULL::record)
+ Hash Cond: (utrtest.a = "*VALUES*".column1)
+ -> Append
+ -> Seq Scan on public.locp utrtest_1
+ Output: utrtest_1.a, utrtest_1.tableoid, utrtest_1.ctid, NULL::record
+ -> Foreign Scan on public.remp utrtest_2
+ Output: utrtest_2.a, utrtest_2.tableoid, utrtest_2.ctid, utrtest_2.*
+ Remote SQL: SELECT a, b, ctid FROM public.loct FOR UPDATE
+ -> Hash
+ Output: "*VALUES*".*, "*VALUES*".column1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".*, "*VALUES*".column1
+(18 rows)
+
+update utrtest set a = 3 from (values (2), (3)) s(x) where a = s.x returning *; -- ERROR
+ERROR: cannot route tuples into foreign table to be updated "remp"
+drop table utrtest;
+drop table loct;
+-- Test copy tuple routing
+create table ctrtest (a int, b text) partition by list (a);
+create table loct1 (a int check (a in (1)), b text);
+create foreign table remp1 (a int check (a in (1)), b text) server loopback options (table_name 'loct1');
+create table loct2 (a int check (a in (2)), b text);
+create foreign table remp2 (b text, a int check (a in (2))) server loopback options (table_name 'loct2');
+alter table ctrtest attach partition remp1 for values in (1);
+alter table ctrtest attach partition remp2 for values in (2);
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp2 | 2 | qux
+(2 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+(1 row)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-----+---
+ remp2 | qux | 2
+(1 row)
+
+-- Copying into foreign partitions directly should work as well
+copy remp1 from stdin;
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-----
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+(2 rows)
+
+delete from ctrtest;
+-- Test copy tuple routing with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+copy ctrtest from stdin;
+select tableoid::regclass, * FROM ctrtest;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+ remp2 | 2 | baz
+ remp2 | 2 | qux
+ remp2 | 2 | test2
+(6 rows)
+
+select tableoid::regclass, * FROM remp1;
+ tableoid | a | b
+----------+---+-------
+ remp1 | 1 | foo
+ remp1 | 1 | bar
+ remp1 | 1 | test1
+(3 rows)
+
+select tableoid::regclass, * FROM remp2;
+ tableoid | b | a
+----------+-------+---
+ remp2 | baz | 2
+ remp2 | qux | 2
+ remp2 | test2 | 2
+(3 rows)
+
+delete from ctrtest;
+alter server loopback options (drop batch_size);
+drop table ctrtest;
+drop table loct1;
+drop table loct2;
+-- ===================================================================
+-- test COPY FROM
+-- ===================================================================
+create table loc2 (f1 int, f2 text);
+alter table loc2 set (autovacuum_enabled = 'false');
+create foreign table rem2 (f1 int, f2 text) server loopback options(table_name 'loc2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2, line 1: "-1 xyzzy"
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test local triggers
+create trigger trig_stmt_before before insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_stmt_after after insert on rem2
+ for each statement execute procedure trigger_func();
+create trigger trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+copy rem2 from stdin;
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = BEFORE, level = STATEMENT
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: trigger_func(<NULL>) called: action = INSERT, when = AFTER, level = STATEMENT
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop trigger trig_row_before on rem2;
+drop trigger trig_row_after on rem2;
+drop trigger trig_stmt_before on rem2;
+drop trigger trig_stmt_after on rem2;
+delete from rem2;
+create trigger trig_row_before_insert before insert on rem2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on rem2;
+delete from rem2;
+create trigger trig_null before insert on rem2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on rem2;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Test a combination of local and remote triggers
+create trigger rem2_trig_row_before before insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger rem2_trig_row_after after insert on rem2
+ for each row execute procedure trigger_data(23,'skidoo');
+create trigger loc2_trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+copy rem2 from stdin;
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (1,foo)
+NOTICE: rem2_trig_row_before(23, skidoo) BEFORE ROW INSERT ON rem2
+NOTICE: NEW: (2,bar)
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (1,"foo triggered !")
+NOTICE: rem2_trig_row_after(23, skidoo) AFTER ROW INSERT ON rem2
+NOTICE: NEW: (2,"bar triggered !")
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+(2 rows)
+
+drop trigger rem2_trig_row_before on rem2;
+drop trigger rem2_trig_row_after on rem2;
+drop trigger loc2_trig_row_before_insert on loc2;
+delete from rem2;
+-- test COPY FROM with foreign table created in the same transaction
+create table loc3 (f1 int, f2 text);
+begin;
+create foreign table rem3 (f1 int, f2 text)
+ server loopback options(table_name 'loc3');
+copy rem3 from stdin;
+commit;
+select * from rem3;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+(2 rows)
+
+drop foreign table rem3;
+drop table loc3;
+-- Test COPY FROM with the batch_size option enabled
+alter server loopback options (add batch_size '2');
+-- Test basic functionality
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+delete from rem2;
+-- Test check constraints
+alter table loc2 add constraint loc2_f1positive check (f1 >= 0);
+alter foreign table rem2 add constraint rem2_f1positive check (f1 >= 0);
+-- check constraint is enforced on the remote side, not locally
+copy rem2 from stdin;
+copy rem2 from stdin; -- ERROR
+ERROR: new row for relation "loc2" violates check constraint "loc2_f1positive"
+DETAIL: Failing row contains (-1, xyzzy).
+CONTEXT: remote SQL command: INSERT INTO public.loc2(f1, f2) VALUES ($1, $2)
+COPY rem2
+select * from rem2;
+ f1 | f2
+----+-----
+ 1 | foo
+ 2 | bar
+ 3 | baz
+(3 rows)
+
+alter foreign table rem2 drop constraint rem2_f1positive;
+alter table loc2 drop constraint loc2_f1positive;
+delete from rem2;
+-- Test remote triggers
+create trigger trig_row_before_insert before insert on loc2
+ for each row execute procedure trig_row_before_insupdate();
+-- The new values are concatenated with ' triggered !'
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+-----------------
+ 1 | foo triggered !
+ 2 | bar triggered !
+ 3 | baz triggered !
+(3 rows)
+
+drop trigger trig_row_before_insert on loc2;
+delete from rem2;
+create trigger trig_null before insert on loc2
+ for each row execute procedure trig_null();
+-- Nothing happens
+copy rem2 from stdin;
+select * from rem2;
+ f1 | f2
+----+----
+(0 rows)
+
+drop trigger trig_null on loc2;
+delete from rem2;
+-- Check with zero-column foreign table; batch insert will be disabled
+alter table loc2 drop column f1;
+alter table loc2 drop column f2;
+alter table rem2 drop column f1;
+alter table rem2 drop column f2;
+copy rem2 from stdin;
+select * from rem2;
+--
+(3 rows)
+
+delete from rem2;
+alter server loopback options (drop batch_size);
+-- ===================================================================
+-- test for TRUNCATE
+-- ===================================================================
+CREATE TABLE tru_rtable0 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable0');
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(1,10) x);
+CREATE TABLE tru_ptable (id int) PARTITION BY HASH(id);
+CREATE TABLE tru_ptable__p0 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0);
+CREATE TABLE tru_rtable1 (id int primary key);
+CREATE FOREIGN TABLE tru_ftable__p1 PARTITION OF tru_ptable
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback OPTIONS (table_name 'tru_rtable1');
+INSERT INTO tru_ptable (SELECT x FROM generate_series(11,20) x);
+CREATE TABLE tru_pk_table(id int primary key);
+CREATE TABLE tru_fk_table(fkey int references tru_pk_table(id));
+INSERT INTO tru_pk_table (SELECT x FROM generate_series(1,10) x);
+INSERT INTO tru_fk_table (SELECT x % 10 + 1 FROM generate_series(5,25) x);
+CREATE FOREIGN TABLE tru_pk_ftable (id int)
+ SERVER loopback OPTIONS (table_name 'tru_pk_table');
+CREATE TABLE tru_rtable_parent (id int);
+CREATE TABLE tru_rtable_child (id int);
+CREATE FOREIGN TABLE tru_ftable_parent (id int)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_parent');
+CREATE FOREIGN TABLE tru_ftable_child () INHERITS (tru_ftable_parent)
+ SERVER loopback OPTIONS (table_name 'tru_rtable_child');
+INSERT INTO tru_rtable_parent (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_rtable_child (SELECT x FROM generate_series(10, 18) x);
+-- normal truncate
+SELECT sum(id) FROM tru_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_ftable;
+SELECT count(*) FROM tru_rtable0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'truncatable' option
+ALTER SERVER loopback OPTIONS (ADD truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (ADD truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER SERVER loopback OPTIONS (DROP truncatable);
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'false');
+TRUNCATE tru_ftable; -- error
+ERROR: foreign table "tru_ftable" does not allow truncates
+ALTER FOREIGN TABLE tru_ftable OPTIONS (SET truncatable 'true');
+TRUNCATE tru_ftable; -- accepted
+-- partitioned table with both local and foreign tables as partitions
+SELECT sum(id) FROM tru_ptable; -- 155
+ sum
+-----
+ 155
+(1 row)
+
+TRUNCATE tru_ptable;
+SELECT count(*) FROM tru_ptable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ptable__p0; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_ftable__p1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_rtable1; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- 'CASCADE' option
+SELECT sum(id) FROM tru_pk_ftable; -- 55
+ sum
+-----
+ 55
+(1 row)
+
+TRUNCATE tru_pk_ftable; -- failed by FK reference
+ERROR: cannot truncate a table referenced in a foreign key constraint
+DETAIL: Table "tru_fk_table" references "tru_pk_table".
+HINT: Truncate table "tru_fk_table" at the same time, or use TRUNCATE ... CASCADE.
+CONTEXT: remote SQL command: TRUNCATE public.tru_pk_table CONTINUE IDENTITY RESTRICT
+TRUNCATE tru_pk_ftable CASCADE;
+SELECT count(*) FROM tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) FROM tru_fk_table; -- also truncated,0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate two tables at a command
+INSERT INTO tru_ftable (SELECT x FROM generate_series(1,8) x);
+INSERT INTO tru_pk_ftable (SELECT x FROM generate_series(3,10) x);
+SELECT count(*) from tru_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 8
+ count
+-------
+ 8
+(1 row)
+
+TRUNCATE tru_ftable, tru_pk_ftable CASCADE;
+SELECT count(*) from tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*) from tru_pk_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- truncate with ONLY clause
+-- Since ONLY is specified, the table tru_ftable_child that inherits
+-- tru_ftable_parent locally is not truncated.
+TRUNCATE ONLY tru_ftable_parent;
+SELECT sum(id) FROM tru_ftable_parent; -- 126
+ sum
+-----
+ 126
+(1 row)
+
+TRUNCATE tru_ftable_parent;
+SELECT count(*) FROM tru_ftable_parent; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- in case when remote table has inherited children
+CREATE TABLE tru_rtable0_child () INHERITS (tru_rtable0);
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(5,9) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(10,14) x);
+SELECT sum(id) FROM tru_ftable; -- 95
+ sum
+-----
+ 95
+(1 row)
+
+-- Both parent and child tables in the foreign server are truncated
+-- even though ONLY is specified because ONLY has no effect
+-- when truncating a foreign table.
+TRUNCATE ONLY tru_ftable;
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+INSERT INTO tru_rtable0 (SELECT x FROM generate_series(21,25) x);
+INSERT INTO tru_rtable0_child (SELECT x FROM generate_series(26,30) x);
+SELECT sum(id) FROM tru_ftable; -- 255
+ sum
+-----
+ 255
+(1 row)
+
+TRUNCATE tru_ftable; -- truncate both of parent and child
+SELECT count(*) FROM tru_ftable; -- 0
+ count
+-------
+ 0
+(1 row)
+
+-- cleanup
+DROP FOREIGN TABLE tru_ftable_parent, tru_ftable_child, tru_pk_ftable,tru_ftable__p1,tru_ftable;
+DROP TABLE tru_rtable0, tru_rtable1, tru_ptable, tru_ptable__p0, tru_pk_table, tru_fk_table,
+tru_rtable_parent,tru_rtable_child, tru_rtable0_child;
+-- ===================================================================
+-- test IMPORT FOREIGN SCHEMA
+-- ===================================================================
+CREATE SCHEMA import_source;
+CREATE TABLE import_source.t1 (c1 int, c2 varchar NOT NULL);
+CREATE TABLE import_source.t2 (c1 int default 42, c2 varchar NULL, c3 text collate "POSIX");
+CREATE TYPE typ1 AS (m1 int, m2 varchar);
+CREATE TABLE import_source.t3 (c1 timestamptz default now(), c2 typ1);
+CREATE TABLE import_source."x 4" (c1 float8, "C 2" text, c3 varchar(42));
+CREATE TABLE import_source."x 5" (c1 float8);
+ALTER TABLE import_source."x 5" DROP COLUMN c1;
+CREATE TABLE import_source."x 6" (c1 int, c2 int generated always as (c1 * 2) stored);
+CREATE TABLE import_source.t4 (c1 int) PARTITION BY RANGE (c1);
+CREATE TABLE import_source.t4_part PARTITION OF import_source.t4
+ FOR VALUES FROM (1) TO (100);
+CREATE TABLE import_source.t4_part2 PARTITION OF import_source.t4
+ FOR VALUES FROM (100) TO (200);
+CREATE SCHEMA import_dest1;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest1;
+\det+ import_dest1.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest1 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest1 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest1 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest1 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest1 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest1 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest1 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest1.*
+ Foreign table "import_dest1.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest1.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest1.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest1.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest1.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest1.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest1.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Options
+CREATE SCHEMA import_dest2;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest2
+ OPTIONS (import_default 'true');
+\det+ import_dest2.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest2 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest2 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest2 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest2 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest2 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest2 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest2 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest2.*
+ Foreign table "import_dest2.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | not null | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest2.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | 42 | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | POSIX | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest2.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | now() | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest2.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest2.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest2.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest2.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+-------------------------------------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | generated always as (c1 * 2) stored | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+CREATE SCHEMA import_dest3;
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest3
+ OPTIONS (import_collate 'false', import_generated 'false', import_not_null 'false');
+\det+ import_dest3.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+-------+----------+-------------------------------------------------+-------------
+ import_dest3 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest3 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest3 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest3 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest3 | x 4 | loopback | (schema_name 'import_source', table_name 'x 4') |
+ import_dest3 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest3 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+\d import_dest3.*
+ Foreign table "import_dest3.t1"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't1')
+
+ Foreign table "import_dest3.t2"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-------------------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | character varying | | | | (column_name 'c2')
+ c3 | text | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't2')
+
+ Foreign table "import_dest3.t3"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+--------------------------+-----------+----------+---------+--------------------
+ c1 | timestamp with time zone | | | | (column_name 'c1')
+ c2 | typ1 | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't3')
+
+ Foreign table "import_dest3.t4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 't4')
+
+ Foreign table "import_dest3.x 4"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+-----------------------+-----------+----------+---------+---------------------
+ c1 | double precision | | | | (column_name 'c1')
+ C 2 | text | | | | (column_name 'C 2')
+ c3 | character varying(42) | | | | (column_name 'c3')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 4')
+
+ Foreign table "import_dest3.x 5"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+------+-----------+----------+---------+-------------
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 5')
+
+ Foreign table "import_dest3.x 6"
+ Column | Type | Collation | Nullable | Default | FDW options
+--------+---------+-----------+----------+---------+--------------------
+ c1 | integer | | | | (column_name 'c1')
+ c2 | integer | | | | (column_name 'c2')
+Server: loopback
+FDW options: (schema_name 'import_source', table_name 'x 6')
+
+-- Check LIMIT TO and EXCEPT
+CREATE SCHEMA import_dest4;
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t1, nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+(2 rows)
+
+IMPORT FOREIGN SCHEMA import_source EXCEPT (t1, "x 4", nonesuch, t4_part)
+ FROM SERVER loopback INTO import_dest4;
+\det+ import_dest4.*
+ List of foreign tables
+ Schema | Table | Server | FDW options | Description
+--------------+---------+----------+-----------------------------------------------------+-------------
+ import_dest4 | t1 | loopback | (schema_name 'import_source', table_name 't1') |
+ import_dest4 | t2 | loopback | (schema_name 'import_source', table_name 't2') |
+ import_dest4 | t3 | loopback | (schema_name 'import_source', table_name 't3') |
+ import_dest4 | t4 | loopback | (schema_name 'import_source', table_name 't4') |
+ import_dest4 | t4_part | loopback | (schema_name 'import_source', table_name 't4_part') |
+ import_dest4 | x 5 | loopback | (schema_name 'import_source', table_name 'x 5') |
+ import_dest4 | x 6 | loopback | (schema_name 'import_source', table_name 'x 6') |
+(7 rows)
+
+-- Assorted error cases
+IMPORT FOREIGN SCHEMA import_source FROM SERVER loopback INTO import_dest4;
+ERROR: relation "t1" already exists
+CONTEXT: importing foreign table "t1"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO import_dest4;
+ERROR: schema "nonesuch" is not present on foreign server "loopback"
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER loopback INTO notthere;
+ERROR: schema "notthere" does not exist
+IMPORT FOREIGN SCHEMA nonesuch FROM SERVER nowhere INTO notthere;
+ERROR: server "nowhere" does not exist
+-- Check case of a type present only on the remote server.
+-- We can fake this by dropping the type locally in our transaction.
+CREATE TYPE "Colors" AS ENUM ('red', 'green', 'blue');
+CREATE TABLE import_source.t5 (c1 int, c2 text collate "C", "Col" "Colors");
+CREATE SCHEMA import_dest5;
+BEGIN;
+DROP TYPE "Colors" CASCADE;
+NOTICE: drop cascades to column Col of table import_source.t5
+IMPORT FOREIGN SCHEMA import_source LIMIT TO (t5)
+ FROM SERVER loopback INTO import_dest5; -- ERROR
+ERROR: type "public.Colors" does not exist
+LINE 4: "Col" public."Colors" OPTIONS (column_name 'Col')
+ ^
+QUERY: CREATE FOREIGN TABLE t5 (
+ c1 integer OPTIONS (column_name 'c1'),
+ c2 text OPTIONS (column_name 'c2') COLLATE pg_catalog."C",
+ "Col" public."Colors" OPTIONS (column_name 'Col')
+) SERVER loopback
+OPTIONS (schema_name 'import_source', table_name 't5');
+CONTEXT: importing foreign table "t5"
+ROLLBACK;
+BEGIN;
+CREATE SERVER fetch101 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( fetch_size '101' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER fetch101 OPTIONS( SET fetch_size '202' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=101'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'fetch101'
+AND srvoptions @> array['fetch_size=202'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30000 ( x int ) SERVER fetch101 OPTIONS ( fetch_size '30000' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30000 OPTIONS ( SET fetch_size '60000');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=30000'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30000'::regclass
+AND ftoptions @> array['fetch_size=60000'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+-- ===================================================================
+-- test partitionwise joins
+-- ===================================================================
+SET enable_partitionwise_join=on;
+CREATE TABLE fprt1 (a int, b int, c varchar) PARTITION BY RANGE(a);
+CREATE TABLE fprt1_p1 (LIKE fprt1);
+CREATE TABLE fprt1_p2 (LIKE fprt1);
+ALTER TABLE fprt1_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt1_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt1_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 2) i;
+INSERT INTO fprt1_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 2) i;
+CREATE FOREIGN TABLE ftprt1_p1 PARTITION OF fprt1 FOR VALUES FROM (0) TO (250)
+ SERVER loopback OPTIONS (table_name 'fprt1_p1', use_remote_estimate 'true');
+CREATE FOREIGN TABLE ftprt1_p2 PARTITION OF fprt1 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (TABLE_NAME 'fprt1_p2');
+ANALYZE fprt1;
+ANALYZE fprt1_p1;
+ANALYZE fprt1_p2;
+CREATE TABLE fprt2 (a int, b int, c varchar) PARTITION BY RANGE(b);
+CREATE TABLE fprt2_p1 (LIKE fprt2);
+CREATE TABLE fprt2_p2 (LIKE fprt2);
+ALTER TABLE fprt2_p1 SET (autovacuum_enabled = 'false');
+ALTER TABLE fprt2_p2 SET (autovacuum_enabled = 'false');
+INSERT INTO fprt2_p1 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(0, 249, 3) i;
+INSERT INTO fprt2_p2 SELECT i, i, to_char(i/50, 'FM0000') FROM generate_series(250, 499, 3) i;
+CREATE FOREIGN TABLE ftprt2_p1 (b int, c varchar, a int)
+ SERVER loopback OPTIONS (table_name 'fprt2_p1', use_remote_estimate 'true');
+ALTER TABLE fprt2 ATTACH PARTITION ftprt2_p1 FOR VALUES FROM (0) TO (250);
+CREATE FOREIGN TABLE ftprt2_p2 PARTITION OF fprt2 FOR VALUES FROM (250) TO (500)
+ SERVER loopback OPTIONS (table_name 'fprt2_p2', use_remote_estimate 'true');
+ANALYZE fprt2;
+ANALYZE fprt2_p1;
+ANALYZE fprt2_p2;
+-- inner join three tables
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t3.c
+ -> Append
+ -> Foreign Scan
+ Relations: ((ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)) INNER JOIN (ftprt1_p1 t3_1)
+ -> Foreign Scan
+ Relations: ((ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)) INNER JOIN (ftprt1_p2 t3_2)
+(7 rows)
+
+SELECT t1.a,t2.b,t3.c FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) INNER JOIN fprt1 t3 ON (t2.b = t3.a) WHERE t1.a % 25 =0 ORDER BY 1,2,3;
+ a | b | c
+-----+-----+------
+ 0 | 0 | 0000
+ 150 | 150 | 0003
+ 250 | 250 | 0005
+ 400 | 400 | 0008
+(4 rows)
+
+-- left outer join + nullable clause
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Foreign Scan
+ Output: t1.a, fprt2.b, fprt2.c
+ Relations: (public.ftprt1_p1 t1) LEFT JOIN (public.ftprt2_p1 fprt2)
+ Remote SQL: SELECT r5.a, r6.b, r6.c FROM (public.fprt1_p1 r5 LEFT JOIN public.fprt2_p1 r6 ON (((r5.a = r6.b)) AND ((r5.b = r6.a)) AND ((r6.a < 10)))) WHERE ((r5.a < 10)) ORDER BY r5.a ASC NULLS LAST, r6.b ASC NULLS LAST, r6.c ASC NULLS LAST
+(4 rows)
+
+SELECT t1.a,t2.b,t2.c FROM fprt1 t1 LEFT JOIN (SELECT * FROM fprt2 WHERE a < 10) t2 ON (t1.a = t2.b and t1.b = t2.a) WHERE t1.a < 10 ORDER BY 1,2,3;
+ a | b | c
+---+---+------
+ 0 | 0 | 0000
+ 2 | |
+ 4 | |
+ 6 | 6 | 0000
+ 8 | |
+(5 rows)
+
+-- with whole-row reference; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ QUERY PLAN
+--------------------------------------------------------
+ Sort
+ Sort Key: ((t1.*)::fprt1), ((t2.*)::fprt2)
+ -> Hash Full Join
+ Hash Cond: (t1.a = t2.b)
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+(11 rows)
+
+SELECT t1.wr, t2.wr FROM (SELECT t1 wr, a FROM fprt1 t1 WHERE t1.a % 25 = 0) t1 FULL JOIN (SELECT t2 wr, b FROM fprt2 t2 WHERE t2.b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY 1,2;
+ wr | wr
+----------------+----------------
+ (0,0,0000) | (0,0,0000)
+ (50,50,0001) |
+ (100,100,0002) |
+ (150,150,0003) | (150,150,0003)
+ (200,200,0004) |
+ (250,250,0005) | (250,250,0005)
+ (300,300,0006) |
+ (350,350,0007) |
+ (400,400,0008) | (400,400,0008)
+ (450,450,0009) |
+ | (75,75,0001)
+ | (225,225,0004)
+ | (325,325,0006)
+ | (475,475,0009)
+(14 rows)
+
+-- join with lateral reference
+EXPLAIN (COSTS OFF)
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Sort
+ Sort Key: t1.a, t1.b
+ -> Append
+ -> Foreign Scan
+ Relations: (ftprt1_p1 t1_1) INNER JOIN (ftprt2_p1 t2_1)
+ -> Foreign Scan
+ Relations: (ftprt1_p2 t1_2) INNER JOIN (ftprt2_p2 t2_2)
+(7 rows)
+
+SELECT t1.a,t1.b FROM fprt1 t1, LATERAL (SELECT t2.a, t2.b FROM fprt2 t2 WHERE t1.a = t2.b AND t1.b = t2.a) q WHERE t1.a%25 = 0 ORDER BY 1,2;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+-- with PHVs, partitionwise join selected but no join pushdown
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: fprt1.a, fprt2.b
+ -> Append
+ -> Hash Full Join
+ Hash Cond: (fprt1_1.a = fprt2_1.b)
+ -> Foreign Scan on ftprt1_p1 fprt1_1
+ -> Hash
+ -> Foreign Scan on ftprt2_p1 fprt2_1
+ -> Hash Full Join
+ Hash Cond: (fprt1_2.a = fprt2_2.b)
+ -> Foreign Scan on ftprt1_p2 fprt1_2
+ -> Hash
+ -> Foreign Scan on ftprt2_p2 fprt2_2
+(13 rows)
+
+SELECT t1.a, t1.phv, t2.b, t2.phv FROM (SELECT 't1_phv' phv, * FROM fprt1 WHERE a % 25 = 0) t1 FULL JOIN (SELECT 't2_phv' phv, * FROM fprt2 WHERE b % 25 = 0) t2 ON (t1.a = t2.b) ORDER BY t1.a, t2.b;
+ a | phv | b | phv
+-----+--------+-----+--------
+ 0 | t1_phv | 0 | t2_phv
+ 50 | t1_phv | |
+ 100 | t1_phv | |
+ 150 | t1_phv | 150 | t2_phv
+ 200 | t1_phv | |
+ 250 | t1_phv | 250 | t2_phv
+ 300 | t1_phv | |
+ 350 | t1_phv | |
+ 400 | t1_phv | 400 | t2_phv
+ 450 | t1_phv | |
+ | | 75 | t2_phv
+ | | 225 | t2_phv
+ | | 325 | t2_phv
+ | | 475 | t2_phv
+(14 rows)
+
+-- test FOR UPDATE; partitionwise join does not apply
+EXPLAIN (COSTS OFF)
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ QUERY PLAN
+--------------------------------------------------------------
+ LockRows
+ -> Sort
+ Sort Key: t1.a
+ -> Hash Join
+ Hash Cond: (t2.b = t1.a)
+ -> Append
+ -> Foreign Scan on ftprt2_p1 t2_1
+ -> Foreign Scan on ftprt2_p2 t2_2
+ -> Hash
+ -> Append
+ -> Foreign Scan on ftprt1_p1 t1_1
+ -> Foreign Scan on ftprt1_p2 t1_2
+(12 rows)
+
+SELECT t1.a, t2.b FROM fprt1 t1 INNER JOIN fprt2 t2 ON (t1.a = t2.b) WHERE t1.a % 25 = 0 ORDER BY 1,2 FOR UPDATE OF t1;
+ a | b
+-----+-----
+ 0 | 0
+ 150 | 150
+ 250 | 250
+ 400 | 400
+(4 rows)
+
+RESET enable_partitionwise_join;
+-- ===================================================================
+-- test partitionwise aggregates
+-- ===================================================================
+CREATE TABLE pagg_tab (a int, b int, c text) PARTITION BY RANGE(a);
+CREATE TABLE pagg_tab_p1 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p2 (LIKE pagg_tab);
+CREATE TABLE pagg_tab_p3 (LIKE pagg_tab);
+INSERT INTO pagg_tab_p1 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 10;
+INSERT INTO pagg_tab_p2 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 20 and (i % 30) >= 10;
+INSERT INTO pagg_tab_p3 SELECT i % 30, i % 50, to_char(i/30, 'FM0000') FROM generate_series(1, 3000) i WHERE (i % 30) < 30 and (i % 30) >= 20;
+-- Create foreign partitions
+CREATE FOREIGN TABLE fpagg_tab_p1 PARTITION OF pagg_tab FOR VALUES FROM (0) TO (10) SERVER loopback OPTIONS (table_name 'pagg_tab_p1');
+CREATE FOREIGN TABLE fpagg_tab_p2 PARTITION OF pagg_tab FOR VALUES FROM (10) TO (20) SERVER loopback OPTIONS (table_name 'pagg_tab_p2');
+CREATE FOREIGN TABLE fpagg_tab_p3 PARTITION OF pagg_tab FOR VALUES FROM (20) TO (30) SERVER loopback OPTIONS (table_name 'pagg_tab_p3');
+ANALYZE pagg_tab;
+ANALYZE fpagg_tab_p1;
+ANALYZE fpagg_tab_p2;
+ANALYZE fpagg_tab_p3;
+-- When GROUP BY clause matches with PARTITION KEY.
+-- Plan with partitionwise aggregates is disabled
+SET enable_partitionwise_aggregate TO false;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> HashAggregate
+ Group Key: pagg_tab.a
+ Filter: (avg(pagg_tab.b) < '22'::numeric)
+ -> Append
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab_1
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_2
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_3
+(9 rows)
+
+-- Plan with partitionwise aggregates is enabled
+SET enable_partitionwise_aggregate TO true;
+EXPLAIN (COSTS OFF)
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.a
+ -> Append
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p1 pagg_tab)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p2 pagg_tab_1)
+ -> Foreign Scan
+ Relations: Aggregate on (fpagg_tab_p3 pagg_tab_2)
+(9 rows)
+
+SELECT a, sum(b), min(b), count(*) FROM pagg_tab GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | sum | min | count
+----+------+-----+-------
+ 0 | 2000 | 0 | 100
+ 1 | 2100 | 1 | 100
+ 10 | 2000 | 0 | 100
+ 11 | 2100 | 1 | 100
+ 20 | 2000 | 0 | 100
+ 21 | 2100 | 1 | 100
+(6 rows)
+
+-- Check with whole-row reference
+-- Should have all the columns in the target list for the given relation
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ QUERY PLAN
+------------------------------------------------------------------------
+ Sort
+ Output: t1.a, (count(((t1.*)::pagg_tab)))
+ Sort Key: t1.a
+ -> Append
+ -> HashAggregate
+ Output: t1.a, count(((t1.*)::pagg_tab))
+ Group Key: t1.a
+ Filter: (avg(t1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p1 t1
+ Output: t1.a, t1.*, t1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p1
+ -> HashAggregate
+ Output: t1_1.a, count(((t1_1.*)::pagg_tab))
+ Group Key: t1_1.a
+ Filter: (avg(t1_1.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p2 t1_1
+ Output: t1_1.a, t1_1.*, t1_1.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p2
+ -> HashAggregate
+ Output: t1_2.a, count(((t1_2.*)::pagg_tab))
+ Group Key: t1_2.a
+ Filter: (avg(t1_2.b) < '22'::numeric)
+ -> Foreign Scan on public.fpagg_tab_p3 t1_2
+ Output: t1_2.a, t1_2.*, t1_2.b
+ Remote SQL: SELECT a, b, c FROM public.pagg_tab_p3
+(25 rows)
+
+SELECT a, count(t1) FROM pagg_tab t1 GROUP BY a HAVING avg(b) < 22 ORDER BY 1;
+ a | count
+----+-------
+ 0 | 100
+ 1 | 100
+ 10 | 100
+ 11 | 100
+ 20 | 100
+ 21 | 100
+(6 rows)
+
+-- When GROUP BY clause does not match with PARTITION KEY.
+EXPLAIN (COSTS OFF)
+SELECT b, avg(a), max(a), count(*) FROM pagg_tab GROUP BY b HAVING sum(a) < 700 ORDER BY 1;
+ QUERY PLAN
+-----------------------------------------------------------------
+ Sort
+ Sort Key: pagg_tab.b
+ -> Finalize HashAggregate
+ Group Key: pagg_tab.b
+ Filter: (sum(pagg_tab.a) < 700)
+ -> Append
+ -> Partial HashAggregate
+ Group Key: pagg_tab.b
+ -> Foreign Scan on fpagg_tab_p1 pagg_tab
+ -> Partial HashAggregate
+ Group Key: pagg_tab_1.b
+ -> Foreign Scan on fpagg_tab_p2 pagg_tab_1
+ -> Partial HashAggregate
+ Group Key: pagg_tab_2.b
+ -> Foreign Scan on fpagg_tab_p3 pagg_tab_2
+(15 rows)
+
+-- ===================================================================
+-- access rights and superuser
+-- ===================================================================
+-- Non-superuser cannot create a FDW without a password in the connstr
+CREATE ROLE regress_nosuper NOSUPERUSER;
+GRANT USAGE ON FOREIGN DATA WRAPPER postgres_fdw TO regress_nosuper;
+SET ROLE regress_nosuper;
+SHOW is_superuser;
+ is_superuser
+--------------
+ off
+(1 row)
+
+-- This will be OK, we can create the FDW
+DO $d$
+ BEGIN
+ EXECUTE $$CREATE SERVER loopback_nopw FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS (dbname '$$||current_database()||$$',
+ port '$$||current_setting('port')||$$'
+ )$$;
+ END;
+$d$;
+-- But creation of user mappings for non-superusers should fail
+CREATE USER MAPPING FOR public SERVER loopback_nopw;
+CREATE USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+CREATE FOREIGN TABLE pg_temp.ft1_nopw (
+ c1 int NOT NULL,
+ c2 int NOT NULL,
+ c3 text,
+ c4 timestamptz,
+ c5 timestamp,
+ c6 varchar(10),
+ c7 char(10) default 'ft1',
+ c8 user_enum
+) SERVER loopback_nopw OPTIONS (schema_name 'public', table_name 'ft1');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+-- If we add a password to the connstr it'll fail, because we don't allow passwords
+-- in connstrs only in user mappings.
+ALTER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+ERROR: invalid option "password"
+HINT: Perhaps you meant the option "passfile".
+-- If we add a password for our user mapping instead, we should get a different
+-- error because the password wasn't actually *used* when we run with trust auth.
+--
+-- This won't work with installcheck, but neither will most of the FDW checks.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password 'dummypw');
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+-- Unpriv user cannot make the mapping passwordless
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+ERROR: password_required=false is superuser-only
+HINT: User mappings with the password_required option set to false may only be created or modified by the superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superuser cannot connect if the server does not request a password.
+HINT: Target server's authentication method must be changed or password_required=false set in the user mapping attributes.
+RESET ROLE;
+-- But the superuser can
+ALTER USER MAPPING FOR regress_nosuper SERVER loopback_nopw OPTIONS (ADD password_required 'false');
+SET ROLE regress_nosuper;
+-- Should finally work now
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- unpriv user also cannot set sslcert / sslkey on the user mapping
+-- first set password_required so we see the right error messages
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (SET password_required 'true');
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslcert 'foo.crt');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+ALTER USER MAPPING FOR CURRENT_USER SERVER loopback_nopw OPTIONS (ADD sslkey 'foo.key');
+ERROR: sslcert and sslkey are superuser-only
+HINT: User mappings with the sslcert or sslkey options set may only be created or modified by the superuser.
+-- We're done with the role named after a specific user and need to check the
+-- changes to the public mapping.
+DROP USER MAPPING FOR CURRENT_USER SERVER loopback_nopw;
+-- This will fail again as it'll resolve the user mapping for public, which
+-- lacks password_required=false
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ERROR: password is required
+DETAIL: Non-superusers must provide a password in the user mapping.
+RESET ROLE;
+-- The user mapping for public is passwordless and lacks the password_required=false
+-- mapping option, but will work because the current user is a superuser.
+SELECT 1 FROM ft1_nopw LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- cleanup
+DROP USER MAPPING FOR public SERVER loopback_nopw;
+DROP OWNED BY regress_nosuper;
+DROP ROLE regress_nosuper;
+-- Clean-up
+RESET enable_partitionwise_aggregate;
+-- Two-phase transactions are not supported.
+BEGIN;
+SELECT count(*) FROM ft1;
+ count
+-------
+ 822
+(1 row)
+
+-- error here
+PREPARE TRANSACTION 'fdw_tpc';
+ERROR: cannot PREPARE a transaction that has operated on postgres_fdw foreign tables
+ROLLBACK;
+WARNING: there is no transaction in progress
+-- ===================================================================
+-- reestablish new connection
+-- ===================================================================
+-- Change application_name of remote connection to special one
+-- so that we can easily terminate the connection later.
+ALTER SERVER loopback OPTIONS (application_name 'fdw_retry_check');
+-- If debug_discard_caches is active, it results in
+-- dropping remote connections after every transaction, making it
+-- impossible to test termination meaningfully. So turn that off
+-- for this test.
+SET debug_discard_caches = 0;
+-- Make sure we have a remote connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- This query should detect the broken connection when starting new remote
+-- transaction, reestablish new connection, and then succeed.
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- If we detect the broken connection when starting a new remote
+-- subtransaction, we should fail instead of establishing a new connection.
+-- Terminate the remote connection and wait for the termination to complete.
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_retry_check';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+SAVEPOINT s;
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT 1 FROM ft1 LIMIT 1; -- should fail
+ERROR: 08006
+\set VERBOSITY default
+COMMIT;
+RESET debug_discard_caches;
+-- =============================================================================
+-- test connection invalidation cases and postgres_fdw_get_connections function
+-- =============================================================================
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- This test case is for closing the connection in pgfdw_xact_callback
+BEGIN;
+-- Connection xact depth becomes 1 i.e. the connection is in midst of the xact.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT 1 FROM ft7 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback3 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback3
+(2 rows)
+
+-- Connections are not closed at the end of the alter and drop statements.
+-- That's because the connections are in midst of this xact,
+-- they are just marked as invalid in pgfdw_inval_callback.
+ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
+DROP SERVER loopback3 CASCADE;
+NOTICE: drop cascades to 2 other objects
+DETAIL: drop cascades to user mapping for public on server loopback3
+drop cascades to foreign table ft7
+-- List all the existing cached connections. loopback and loopback3
+-- should be output as invalid connections. Also the server name for
+-- loopback3 should be NULL because the server was dropped.
+SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | valid
+-------------+-------
+ loopback | f
+ | f
+(2 rows)
+
+-- The invalid connections get closed in pgfdw_xact_callback during commit.
+COMMIT;
+-- All cached connections were closed while committing above xact, so no
+-- records should be output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+(0 rows)
+
+-- =======================================================================
+-- test postgres_fdw_disconnect and postgres_fdw_disconnect_all functions
+-- =======================================================================
+BEGIN;
+-- Ensure to cache loopback connection.
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Ensure to cache loopback2 connection.
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Issue a warning and return false as loopback connection is still in use and
+-- can not be closed.
+SELECT postgres_fdw_disconnect('loopback');
+WARNING: cannot close connection for server "loopback" because it is still in use
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- List all the existing cached connections. loopback and loopback2 should be
+-- output.
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback2
+(2 rows)
+
+-- Return false as connections are still in use, warnings are issued.
+-- But disable warnings temporarily because the order of them is not stable.
+SET client_min_messages = 'ERROR';
+SELECT postgres_fdw_disconnect_all();
+ postgres_fdw_disconnect_all
+-----------------------------
+ f
+(1 row)
+
+RESET client_min_messages;
+COMMIT;
+-- Ensure that loopback2 connection is closed.
+SELECT 1 FROM postgres_fdw_disconnect('loopback2');
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT server_name FROM postgres_fdw_get_connections() WHERE server_name = 'loopback2';
+ server_name
+-------------
+(0 rows)
+
+-- Return false as loopback2 connection is closed already.
+SELECT postgres_fdw_disconnect('loopback2');
+ postgres_fdw_disconnect
+-------------------------
+ f
+(1 row)
+
+-- Return an error as there is no foreign server with given name.
+SELECT postgres_fdw_disconnect('unknownserver');
+ERROR: server "unknownserver" does not exist
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- =============================================================================
+-- test case for having multiple cached connections for a foreign server
+-- =============================================================================
+CREATE ROLE regress_multi_conn_user1 SUPERUSER;
+CREATE ROLE regress_multi_conn_user2 SUPERUSER;
+CREATE USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+CREATE USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+BEGIN;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user1
+SET ROLE regress_multi_conn_user1;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Will cache loopback connection with user mapping for regress_multi_conn_user2
+SET ROLE regress_multi_conn_user2;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+RESET ROLE;
+-- Should output two connections for loopback server
+SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name
+-------------
+ loopback
+ loopback
+(2 rows)
+
+COMMIT;
+-- Let's ensure to close all the existing cached connections.
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?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)
+
+-- Clean up
+DROP USER MAPPING FOR regress_multi_conn_user1 SERVER loopback;
+DROP USER MAPPING FOR regress_multi_conn_user2 SERVER loopback;
+DROP ROLE regress_multi_conn_user1;
+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
+-- ===================================================================
+BEGIN;
+CREATE SERVER batch10 FOREIGN DATA WRAPPER postgres_fdw OPTIONS( batch_size '10' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER SERVER batch10 OPTIONS( SET batch_size '20' );
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=10'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT count(*)
+FROM pg_foreign_server
+WHERE srvname = 'batch10'
+AND srvoptions @> array['batch_size=20'];
+ count
+-------
+ 1
+(1 row)
+
+CREATE FOREIGN TABLE table30 ( x int ) SERVER batch10 OPTIONS ( batch_size '30' );
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 1
+(1 row)
+
+ALTER FOREIGN TABLE table30 OPTIONS ( SET batch_size '40');
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=30'];
+ count
+-------
+ 0
+(1 row)
+
+SELECT COUNT(*)
+FROM pg_foreign_table
+WHERE ftrelid = 'table30'::regclass
+AND ftoptions @> array['batch_size=40'];
+ count
+-------
+ 1
+(1 row)
+
+ROLLBACK;
+CREATE TABLE batch_table ( x int );
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '10' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 10
+ -> Function Scan on pg_catalog.generate_series i
+ Output: i.i
+ Function Call: generate_series(1, 10)
+(6 rows)
+
+INSERT INTO ftable SELECT * FROM generate_series(1, 10) i;
+INSERT INTO ftable SELECT * FROM generate_series(11, 31) i;
+INSERT INTO ftable VALUES (32);
+INSERT INTO ftable VALUES (33), (34);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 34
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- try if large batches exceed max number of bind parameters
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '100000' );
+INSERT INTO ftable SELECT * FROM generate_series(1, 70000) i;
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 70000
+(1 row)
+
+TRUNCATE batch_table;
+DROP FOREIGN TABLE ftable;
+-- Disable batch insert
+CREATE FOREIGN TABLE ftable ( x int ) SERVER loopback OPTIONS ( table_name 'batch_table', batch_size '1' );
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (1), (2);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (1), (2);
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 2
+(1 row)
+
+-- Disable batch inserting into foreign tables with BEFORE ROW INSERT triggers
+-- even if the batch_size option is enabled.
+ALTER FOREIGN TABLE ftable OPTIONS ( SET batch_size '10' );
+CREATE TRIGGER trig_row_before BEFORE INSERT ON ftable
+FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
+EXPLAIN (VERBOSE, COSTS OFF) INSERT INTO ftable VALUES (3), (4);
+ QUERY PLAN
+-------------------------------------------------------------
+ Insert on public.ftable
+ Remote SQL: INSERT INTO public.batch_table(x) VALUES ($1)
+ Batch Size: 1
+ -> Values Scan on "*VALUES*"
+ Output: "*VALUES*".column1
+(5 rows)
+
+INSERT INTO ftable VALUES (3), (4);
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (3)
+NOTICE: trig_row_before(23, skidoo) BEFORE ROW INSERT ON ftable
+NOTICE: NEW: (4)
+SELECT COUNT(*) FROM ftable;
+ count
+-------
+ 4
+(1 row)
+
+-- Clean up
+DROP TRIGGER trig_row_before ON ftable;
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+-- Use partitioning
+CREATE TABLE batch_table ( x int ) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0', batch_size '10');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1', batch_size '1');
+CREATE TABLE batch_table_p2
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 3, REMAINDER 2);
+INSERT INTO batch_table SELECT * FROM generate_series(1, 66) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 66
+(1 row)
+
+-- Clean up
+DROP TABLE batch_table;
+DROP TABLE batch_table_p0;
+DROP TABLE batch_table_p1;
+-- Check that batched mode also works for some inserts made during
+-- cross-partition updates
+CREATE TABLE batch_cp_upd_test (a int) PARTITION BY LIST (a);
+CREATE TABLE batch_cp_upd_test1 (LIKE batch_cp_upd_test);
+CREATE FOREIGN TABLE batch_cp_upd_test1_f
+ PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_cp_upd_test1', batch_size '10');
+CREATE TABLE batch_cp_upd_test2 PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (2);
+CREATE TABLE batch_cp_upd_test3 (LIKE batch_cp_upd_test);
+CREATE FOREIGN TABLE batch_cp_upd_test3_f
+ PARTITION OF batch_cp_upd_test
+ FOR VALUES IN (3)
+ SERVER loopback
+ OPTIONS (table_name 'batch_cp_upd_test3', batch_size '1');
+-- Create statement triggers on remote tables that "log" any INSERTs
+-- performed on them.
+CREATE TABLE cmdlog (cmd text);
+CREATE FUNCTION log_stmt() RETURNS TRIGGER LANGUAGE plpgsql AS $$
+ BEGIN INSERT INTO public.cmdlog VALUES (TG_OP || ' on ' || TG_RELNAME); RETURN NULL; END;
+$$;
+CREATE TRIGGER stmt_trig AFTER INSERT ON batch_cp_upd_test1
+ FOR EACH STATEMENT EXECUTE FUNCTION log_stmt();
+CREATE TRIGGER stmt_trig AFTER INSERT ON batch_cp_upd_test3
+ FOR EACH STATEMENT EXECUTE FUNCTION log_stmt();
+-- This update moves rows from the local partition 'batch_cp_upd_test2' to the
+-- foreign partition 'batch_cp_upd_test1', one that has insert batching
+-- enabled, so a single INSERT for both rows.
+INSERT INTO batch_cp_upd_test VALUES (2), (2);
+UPDATE batch_cp_upd_test t SET a = 1 FROM (VALUES (1), (2)) s(a) WHERE t.a = s.a AND s.a = 2;
+-- This one moves rows from the local partition 'batch_cp_upd_test2' to the
+-- foreign partition 'batch_cp_upd_test2', one that has insert batching
+-- disabled, so separate INSERTs for the two rows.
+INSERT INTO batch_cp_upd_test VALUES (2), (2);
+UPDATE batch_cp_upd_test t SET a = 3 FROM (VALUES (1), (2)) s(a) WHERE t.a = s.a AND s.a = 2;
+SELECT tableoid::regclass, * FROM batch_cp_upd_test ORDER BY 1;
+ tableoid | a
+----------------------+---
+ batch_cp_upd_test1_f | 1
+ batch_cp_upd_test1_f | 1
+ batch_cp_upd_test3_f | 3
+ batch_cp_upd_test3_f | 3
+(4 rows)
+
+-- Should see 1 INSERT on batch_cp_upd_test1 and 2 on batch_cp_upd_test3 as
+-- described above.
+SELECT * FROM cmdlog ORDER BY 1;
+ cmd
+------------------------------
+ INSERT on batch_cp_upd_test1
+ INSERT on batch_cp_upd_test3
+ INSERT on batch_cp_upd_test3
+(3 rows)
+
+-- Clean up
+DROP TABLE batch_cp_upd_test;
+DROP TABLE batch_cp_upd_test1;
+DROP TABLE batch_cp_upd_test3;
+DROP TABLE cmdlog;
+DROP FUNCTION log_stmt();
+-- Use partitioning
+ALTER SERVER loopback OPTIONS (ADD batch_size '10');
+CREATE TABLE batch_table ( x int, field1 text, field2 text) PARTITION BY HASH (x);
+CREATE TABLE batch_table_p0 (LIKE batch_table);
+ALTER TABLE batch_table_p0 ADD CONSTRAINT p0_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p0f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 0)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p0');
+CREATE TABLE batch_table_p1 (LIKE batch_table);
+ALTER TABLE batch_table_p1 ADD CONSTRAINT p1_pkey PRIMARY KEY (x);
+CREATE FOREIGN TABLE batch_table_p1f
+ PARTITION OF batch_table
+ FOR VALUES WITH (MODULUS 2, REMAINDER 1)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table_p1');
+INSERT INTO batch_table SELECT i, 'test'||i, 'test'|| i FROM generate_series(1, 50) i;
+SELECT COUNT(*) FROM batch_table;
+ count
+-------
+ 50
+(1 row)
+
+SELECT * FROM batch_table ORDER BY x;
+ x | field1 | field2
+----+--------+--------
+ 1 | test1 | test1
+ 2 | test2 | test2
+ 3 | test3 | test3
+ 4 | test4 | test4
+ 5 | test5 | test5
+ 6 | test6 | test6
+ 7 | test7 | test7
+ 8 | test8 | test8
+ 9 | test9 | test9
+ 10 | test10 | test10
+ 11 | test11 | test11
+ 12 | test12 | test12
+ 13 | test13 | test13
+ 14 | test14 | test14
+ 15 | test15 | test15
+ 16 | test16 | test16
+ 17 | test17 | test17
+ 18 | test18 | test18
+ 19 | test19 | test19
+ 20 | test20 | test20
+ 21 | test21 | test21
+ 22 | test22 | test22
+ 23 | test23 | test23
+ 24 | test24 | test24
+ 25 | test25 | test25
+ 26 | test26 | test26
+ 27 | test27 | test27
+ 28 | test28 | test28
+ 29 | test29 | test29
+ 30 | test30 | test30
+ 31 | test31 | test31
+ 32 | test32 | test32
+ 33 | test33 | test33
+ 34 | test34 | test34
+ 35 | test35 | test35
+ 36 | test36 | test36
+ 37 | test37 | test37
+ 38 | test38 | test38
+ 39 | test39 | test39
+ 40 | test40 | test40
+ 41 | test41 | test41
+ 42 | test42 | test42
+ 43 | test43 | test43
+ 44 | test44 | test44
+ 45 | test45 | test45
+ 46 | test46 | test46
+ 47 | test47 | test47
+ 48 | test48 | test48
+ 49 | test49 | test49
+ 50 | test50 | test50
+(50 rows)
+
+-- Clean up
+DROP TABLE batch_table;
+DROP TABLE batch_table_p0;
+DROP TABLE batch_table_p1;
+ALTER SERVER loopback OPTIONS (DROP batch_size);
+-- Test that pending inserts are handled properly when needed
+CREATE TABLE batch_table (a text, b int);
+CREATE FOREIGN TABLE ftable (a text, b int)
+ SERVER loopback
+ OPTIONS (table_name 'batch_table', batch_size '2');
+CREATE TABLE ltable (a text, b int);
+CREATE FUNCTION ftable_rowcount_trigf() RETURNS trigger LANGUAGE plpgsql AS
+$$
+begin
+ raise notice '%: there are % rows in ftable',
+ TG_NAME, (SELECT count(*) FROM ftable);
+ if TG_OP = 'DELETE' then
+ return OLD;
+ else
+ return NEW;
+ end if;
+end;
+$$;
+CREATE TRIGGER ftable_rowcount_trigger
+BEFORE INSERT OR UPDATE OR DELETE ON ltable
+FOR EACH ROW EXECUTE PROCEDURE ftable_rowcount_trigf();
+WITH t AS (
+ INSERT INTO ltable VALUES ('AAA', 42), ('BBB', 42) RETURNING *
+)
+INSERT INTO ftable SELECT * FROM t;
+NOTICE: ftable_rowcount_trigger: there are 0 rows in ftable
+NOTICE: ftable_rowcount_trigger: there are 1 rows in ftable
+SELECT * FROM ltable;
+ a | b
+-----+----
+ AAA | 42
+ BBB | 42
+(2 rows)
+
+SELECT * FROM ftable;
+ a | b
+-----+----
+ AAA | 42
+ BBB | 42
+(2 rows)
+
+DELETE FROM ftable;
+WITH t AS (
+ UPDATE ltable SET b = b + 100 RETURNING *
+)
+INSERT INTO ftable SELECT * FROM t;
+NOTICE: ftable_rowcount_trigger: there are 0 rows in ftable
+NOTICE: ftable_rowcount_trigger: there are 1 rows in ftable
+SELECT * FROM ltable;
+ a | b
+-----+-----
+ AAA | 142
+ BBB | 142
+(2 rows)
+
+SELECT * FROM ftable;
+ a | b
+-----+-----
+ AAA | 142
+ BBB | 142
+(2 rows)
+
+DELETE FROM ftable;
+WITH t AS (
+ DELETE FROM ltable RETURNING *
+)
+INSERT INTO ftable SELECT * FROM t;
+NOTICE: ftable_rowcount_trigger: there are 0 rows in ftable
+NOTICE: ftable_rowcount_trigger: there are 1 rows in ftable
+SELECT * FROM ltable;
+ a | b
+---+---
+(0 rows)
+
+SELECT * FROM ftable;
+ a | b
+-----+-----
+ AAA | 142
+ BBB | 142
+(2 rows)
+
+DELETE FROM ftable;
+-- Clean up
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+DROP TRIGGER ftable_rowcount_trigger ON ltable;
+DROP TABLE ltable;
+CREATE TABLE parent (a text, b int) PARTITION BY LIST (a);
+CREATE TABLE batch_table (a text, b int);
+CREATE FOREIGN TABLE ftable
+ PARTITION OF parent
+ FOR VALUES IN ('AAA')
+ SERVER loopback
+ OPTIONS (table_name 'batch_table', batch_size '2');
+CREATE TABLE ltable
+ PARTITION OF parent
+ FOR VALUES IN ('BBB');
+CREATE TRIGGER ftable_rowcount_trigger
+BEFORE INSERT ON ltable
+FOR EACH ROW EXECUTE PROCEDURE ftable_rowcount_trigf();
+INSERT INTO parent VALUES ('AAA', 42), ('BBB', 42), ('AAA', 42), ('BBB', 42);
+NOTICE: ftable_rowcount_trigger: there are 1 rows in ftable
+NOTICE: ftable_rowcount_trigger: there are 2 rows in ftable
+SELECT tableoid::regclass, * FROM parent;
+ tableoid | a | b
+----------+-----+----
+ ftable | AAA | 42
+ ftable | AAA | 42
+ ltable | BBB | 42
+ ltable | BBB | 42
+(4 rows)
+
+-- Clean up
+DROP FOREIGN TABLE ftable;
+DROP TABLE batch_table;
+DROP TRIGGER ftable_rowcount_trigger ON ltable;
+DROP TABLE ltable;
+DROP TABLE parent;
+DROP FUNCTION ftable_rowcount_trigf;
+-- ===================================================================
+-- test asynchronous execution
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (DROP extensions);
+ALTER SERVER loopback OPTIONS (ADD async_capable 'true');
+ALTER SERVER loopback2 OPTIONS (ADD async_capable 'true');
+CREATE TABLE async_pt (a int, b int, c text) PARTITION BY RANGE (a);
+CREATE TABLE base_tbl1 (a int, b int, c text);
+CREATE TABLE base_tbl2 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p1 PARTITION OF async_pt FOR VALUES FROM (1000) TO (2000)
+ SERVER loopback OPTIONS (table_name 'base_tbl1');
+CREATE FOREIGN TABLE async_p2 PARTITION OF async_pt FOR VALUES FROM (2000) TO (3000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl2');
+INSERT INTO async_p1 SELECT 1000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+INSERT INTO async_p2 SELECT 2000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+-- simple queries
+CREATE TABLE result_tbl (a int, b int, c text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE (((b % 100) = 0))
+(8 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b % 100 = 0;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1000 | 0 | 0000
+ 1100 | 100 | 0100
+ 1200 | 200 | 0200
+ 1300 | 300 | 0300
+ 1400 | 400 | 0400
+ 1500 | 500 | 0500
+ 1600 | 600 | 0600
+ 1700 | 700 | 0700
+ 1800 | 800 | 0800
+ 1900 | 900 | 0900
+ 2000 | 0 | 0000
+ 2100 | 100 | 0100
+ 2200 | 200 | 0200
+ 2300 | 300 | 0300
+ 2400 | 400 | 0400
+ 2500 | 500 | 0500
+ 2600 | 600 | 0600
+ 2700 | 700 | 0700
+ 2800 | 800 | 0800
+ 2900 | 900 | 0900
+(20 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, ('AAA'::text || async_pt_1.c)
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, ('AAA'::text || async_pt_2.c)
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(10 rows)
+
+INSERT INTO result_tbl SELECT a, b, 'AAA' || c FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+---------
+ 1505 | 505 | AAA0505
+ 2505 | 505 | AAA0505
+(2 rows)
+
+DELETE FROM result_tbl;
+-- Check case where multiple partitions use the same connection
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000)
+ SERVER loopback2 OPTIONS (table_name 'base_tbl3');
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Async Foreign Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(14 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+DROP FOREIGN TABLE async_p3;
+DROP TABLE base_tbl3;
+-- Check case where the partitioned table has local/remote partitions
+CREATE TABLE async_p3 PARTITION OF async_pt FOR VALUES FROM (3000) TO (4000);
+INSERT INTO async_p3 SELECT 3000 + i, i, to_char(i, 'FM0000') FROM generate_series(0, 999, 5) i;
+ANALYZE async_pt;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+(13 rows)
+
+INSERT INTO result_tbl SELECT * FROM async_pt WHERE b === 505;
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+ 3505 | 505 | 0505
+(3 rows)
+
+DELETE FROM result_tbl;
+-- partitionwise joins
+SET enable_partitionwise_join TO true;
+CREATE TABLE join_tbl (a1 int, b1 int, c1 text, a2 int, b2 int, c2 text);
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, t1_1.c, t2_1.a, t2_1.b, t2_1.c
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, t1_2.c, t2_2.a, t2_2.b, t2_2.c
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, t1_3.c, t2_3.a, t2_3.b, t2_3.c
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+ 2000 | 0 | 0000 | 2000 | 0 | 0000
+ 2100 | 100 | 0100 | 2100 | 100 | 0100
+ 2200 | 200 | 0200 | 2200 | 200 | 0200
+ 2300 | 300 | 0300 | 2300 | 300 | 0300
+ 2400 | 400 | 0400 | 2400 | 400 | 0400
+ 2500 | 500 | 0500 | 2500 | 500 | 0500
+ 2600 | 600 | 0600 | 2600 | 600 | 0600
+ 2700 | 700 | 0700 | 2700 | 700 | 0700
+ 2800 | 800 | 0800 | 2800 | 800 | 0800
+ 2900 | 900 | 0900 | 2900 | 900 | 0900
+ 3000 | 0 | 0000 | 3000 | 0 | 0000
+ 3100 | 100 | 0100 | 3100 | 100 | 0100
+ 3200 | 200 | 0200 | 3200 | 200 | 0200
+ 3300 | 300 | 0300 | 3300 | 300 | 0300
+ 3400 | 400 | 0400 | 3400 | 400 | 0400
+ 3500 | 500 | 0500 | 3500 | 500 | 0500
+ 3600 | 600 | 0600 | 3600 | 600 | 0600
+ 3700 | 700 | 0700 | 3700 | 700 | 0700
+ 3800 | 800 | 0800 | 3800 | 800 | 0800
+ 3900 | 900 | 0900 | 3900 | 900 | 0900
+(30 rows)
+
+DELETE FROM join_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Append
+ -> Async Foreign Scan
+ Output: t1_1.a, t1_1.b, ('AAA'::text || t1_1.c), t2_1.a, t2_1.b, ('AAA'::text || t2_1.c)
+ Relations: (public.async_p1 t1_1) INNER JOIN (public.async_p1 t2_1)
+ Remote SQL: SELECT r5.a, r5.b, r5.c, r8.a, r8.b, r8.c FROM (public.base_tbl1 r5 INNER JOIN public.base_tbl1 r8 ON (((r5.a = r8.a)) AND ((r5.b = r8.b)) AND (((r5.b % 100) = 0))))
+ -> Async Foreign Scan
+ Output: t1_2.a, t1_2.b, ('AAA'::text || t1_2.c), t2_2.a, t2_2.b, ('AAA'::text || t2_2.c)
+ Relations: (public.async_p2 t1_2) INNER JOIN (public.async_p2 t2_2)
+ Remote SQL: SELECT r6.a, r6.b, r6.c, r9.a, r9.b, r9.c FROM (public.base_tbl2 r6 INNER JOIN public.base_tbl2 r9 ON (((r6.a = r9.a)) AND ((r6.b = r9.b)) AND (((r6.b % 100) = 0))))
+ -> Hash Join
+ Output: t1_3.a, t1_3.b, ('AAA'::text || t1_3.c), t2_3.a, t2_3.b, ('AAA'::text || t2_3.c)
+ Hash Cond: ((t2_3.a = t1_3.a) AND (t2_3.b = t1_3.b))
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+ -> Hash
+ Output: t1_3.a, t1_3.b, t1_3.c
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: ((t1_3.b % 100) = 0)
+(20 rows)
+
+INSERT INTO join_tbl SELECT t1.a, t1.b, 'AAA' || t1.c, t2.a, t2.b, 'AAA' || t2.c FROM async_pt t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+---------+------+-----+---------
+ 1000 | 0 | AAA0000 | 1000 | 0 | AAA0000
+ 1100 | 100 | AAA0100 | 1100 | 100 | AAA0100
+ 1200 | 200 | AAA0200 | 1200 | 200 | AAA0200
+ 1300 | 300 | AAA0300 | 1300 | 300 | AAA0300
+ 1400 | 400 | AAA0400 | 1400 | 400 | AAA0400
+ 1500 | 500 | AAA0500 | 1500 | 500 | AAA0500
+ 1600 | 600 | AAA0600 | 1600 | 600 | AAA0600
+ 1700 | 700 | AAA0700 | 1700 | 700 | AAA0700
+ 1800 | 800 | AAA0800 | 1800 | 800 | AAA0800
+ 1900 | 900 | AAA0900 | 1900 | 900 | AAA0900
+ 2000 | 0 | AAA0000 | 2000 | 0 | AAA0000
+ 2100 | 100 | AAA0100 | 2100 | 100 | AAA0100
+ 2200 | 200 | AAA0200 | 2200 | 200 | AAA0200
+ 2300 | 300 | AAA0300 | 2300 | 300 | AAA0300
+ 2400 | 400 | AAA0400 | 2400 | 400 | AAA0400
+ 2500 | 500 | AAA0500 | 2500 | 500 | AAA0500
+ 2600 | 600 | AAA0600 | 2600 | 600 | AAA0600
+ 2700 | 700 | AAA0700 | 2700 | 700 | AAA0700
+ 2800 | 800 | AAA0800 | 2800 | 800 | AAA0800
+ 2900 | 900 | AAA0900 | 2900 | 900 | AAA0900
+ 3000 | 0 | AAA0000 | 3000 | 0 | AAA0000
+ 3100 | 100 | AAA0100 | 3100 | 100 | AAA0100
+ 3200 | 200 | AAA0200 | 3200 | 200 | AAA0200
+ 3300 | 300 | AAA0300 | 3300 | 300 | AAA0300
+ 3400 | 400 | AAA0400 | 3400 | 400 | AAA0400
+ 3500 | 500 | AAA0500 | 3500 | 500 | AAA0500
+ 3600 | 600 | AAA0600 | 3600 | 600 | AAA0600
+ 3700 | 700 | AAA0700 | 3700 | 700 | AAA0700
+ 3800 | 800 | AAA0800 | 3800 | 800 | AAA0800
+ 3900 | 900 | AAA0900 | 3900 | 900 | AAA0900
+(30 rows)
+
+DELETE FROM join_tbl;
+RESET enable_partitionwise_join;
+-- Test rescan of an async Append node with do_exec_prune=false
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ -> Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: ((t1.a = t2.a) AND (t1.b = t2.b))
+ -> Foreign Scan on public.async_p1 t1
+ Output: t1.a, t1.b, t1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE (((b % 100) = 0))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t2_1
+ Output: t2_1.a, t2_1.b, t2_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t2_2
+ Output: t2_2.a, t2_2.b, t2_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t2_3
+ Output: t2_3.a, t2_3.b, t2_3.c
+(16 rows)
+
+INSERT INTO join_tbl SELECT * FROM async_p1 t1, async_pt t2 WHERE t1.a = t2.a AND t1.b = t2.b AND t1.b % 100 = 0;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+------
+ 1000 | 0 | 0000 | 1000 | 0 | 0000
+ 1100 | 100 | 0100 | 1100 | 100 | 0100
+ 1200 | 200 | 0200 | 1200 | 200 | 0200
+ 1300 | 300 | 0300 | 1300 | 300 | 0300
+ 1400 | 400 | 0400 | 1400 | 400 | 0400
+ 1500 | 500 | 0500 | 1500 | 500 | 0500
+ 1600 | 600 | 0600 | 1600 | 600 | 0600
+ 1700 | 700 | 0700 | 1700 | 700 | 0700
+ 1800 | 800 | 0800 | 1800 | 800 | 0800
+ 1900 | 900 | 0900 | 1900 | 900 | 0900
+(10 rows)
+
+DELETE FROM join_tbl;
+RESET enable_hashjoin;
+-- Test interaction of async execution with plan-time partition pruning
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 3000;
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(7 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE a < 2000;
+ QUERY PLAN
+-----------------------------------------------------------------------
+ Foreign Scan on public.async_p1 async_pt
+ Output: async_pt.a, async_pt.b, async_pt.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 2000))
+(3 rows)
+
+-- Test interaction of async execution with run-time partition pruning
+SET plan_cache_mode TO force_generic_plan;
+PREPARE async_pt_query (int, int) AS
+ INSERT INTO result_tbl SELECT * FROM async_pt WHERE a < $1 AND b === $2;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (3000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 1
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < $1::integer))
+(11 rows)
+
+EXECUTE async_pt_query (3000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+ 2505 | 505 | 0505
+(2 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+EXECUTE async_pt_query (2000, 505);
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ Subplans Removed: 2
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === $2)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < $1::integer))
+(7 rows)
+
+EXECUTE async_pt_query (2000, 505);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+-----+------
+ 1505 | 505 | 0505
+(1 row)
+
+DELETE FROM result_tbl;
+RESET plan_cache_mode;
+CREATE TABLE local_tbl(a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo'), (2505, 505, 'bar');
+ANALYZE local_tbl;
+CREATE INDEX base_tbl1_idx ON base_tbl1 (a);
+CREATE INDEX base_tbl2_idx ON base_tbl2 (a);
+CREATE INDEX async_p3_idx ON async_p3 (a);
+ANALYZE base_tbl1;
+ANALYZE base_tbl2;
+ANALYZE async_p3;
+ALTER FOREIGN TABLE async_p1 OPTIONS (use_remote_estimate 'true');
+ALTER FOREIGN TABLE async_p2 OPTIONS (use_remote_estimate 'true');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Nested Loop
+ Output: local_tbl.a, local_tbl.b, local_tbl.c, async_pt.a, async_pt.b, async_pt.c
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ Filter: (local_tbl.c = 'bar'::text)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a = $1::integer))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a = $1::integer))
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.a = local_tbl.a)
+(15 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ QUERY PLAN
+-------------------------------------------------------------------------------
+ Nested Loop (actual rows=1 loops=1)
+ -> Seq Scan on local_tbl (actual rows=1 loops=1)
+ Filter: (c = 'bar'::text)
+ Rows Removed by Filter: 1
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (never executed)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=1 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (never executed)
+ Filter: (a = local_tbl.a)
+(9 rows)
+
+SELECT * FROM local_tbl, async_pt WHERE local_tbl.a = async_pt.a AND local_tbl.c = 'bar';
+ a | b | c | a | b | c
+------+-----+-----+------+-----+------
+ 2505 | 505 | bar | 2505 | 505 | 0505
+(1 row)
+
+ALTER FOREIGN TABLE async_p1 OPTIONS (DROP use_remote_estimate);
+ALTER FOREIGN TABLE async_p2 OPTIONS (DROP use_remote_estimate);
+DROP TABLE local_tbl;
+DROP INDEX base_tbl1_idx;
+DROP INDEX base_tbl2_idx;
+DROP INDEX async_p3_idx;
+-- UNION queries
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> HashAggregate
+ Output: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ Group Key: async_p1.a, async_p1.b, (('AAA'::text || async_p1.c))
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(11 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+ QUERY PLAN
+-----------------------------------------------------------------------------------------------------------
+ Insert on public.result_tbl
+ -> Append
+ -> Async Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, ('AAA'::text || async_p1.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 ORDER BY a ASC NULLS LAST LIMIT 10::bigint
+ -> Async Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, ('AAA'::text || async_p2.c)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(8 rows)
+
+INSERT INTO result_tbl
+(SELECT a, b, 'AAA' || c FROM async_p1 ORDER BY a LIMIT 10)
+UNION ALL
+(SELECT a, b, 'AAA' || c FROM async_p2 WHERE b < 10);
+SELECT * FROM result_tbl ORDER BY a;
+ a | b | c
+------+----+---------
+ 1000 | 0 | AAA0000
+ 1005 | 5 | AAA0005
+ 1010 | 10 | AAA0010
+ 1015 | 15 | AAA0015
+ 1020 | 20 | AAA0020
+ 1025 | 25 | AAA0025
+ 1030 | 30 | AAA0030
+ 1035 | 35 | AAA0035
+ 1040 | 40 | AAA0040
+ 1045 | 45 | AAA0045
+ 2000 | 0 | AAA0000
+ 2005 | 5 | AAA0005
+(12 rows)
+
+DELETE FROM result_tbl;
+-- Disable async execution if we use gating Result nodes for pseudoconstant
+-- quals
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Result
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+(18 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+(SELECT * FROM async_p1 WHERE CURRENT_USER = SESSION_USER)
+UNION ALL
+(SELECT * FROM async_p2 WHERE CURRENT_USER = SESSION_USER);
+ QUERY PLAN
+----------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(13 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM ((SELECT * FROM async_p1 WHERE b < 10) UNION ALL (SELECT * FROM async_p2 WHERE b < 10)) s WHERE CURRENT_USER = SESSION_USER;
+ QUERY PLAN
+---------------------------------------------------------------------------------
+ Append
+ -> Result
+ Output: async_p1.a, async_p1.b, async_p1.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p1
+ Output: async_p1.a, async_p1.b, async_p1.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((b < 10))
+ -> Result
+ Output: async_p2.a, async_p2.b, async_p2.c
+ One-Time Filter: (CURRENT_USER = SESSION_USER)
+ -> Foreign Scan on public.async_p2
+ Output: async_p2.a, async_p2.b, async_p2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((b < 10))
+(13 rows)
+
+-- Test that pending requests are processed properly
+SET enable_mergejoin TO false;
+SET enable_hashjoin TO false;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------
+ Nested Loop
+ Output: t1.a, t1.b, t1.c, t2.a, t2.b, t2.c
+ Join Filter: (t1.a = t2.a)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+ -> Materialize
+ Output: t2.a, t2.b, t2.c
+ -> Foreign Scan on public.async_p2 t2
+ Output: t2.a, t2.b, t2.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+(20 rows)
+
+SELECT * FROM async_pt t1, async_p2 t2 WHERE t1.a = t2.a AND t1.b === 505;
+ a | b | c | a | b | c
+------+-----+------+------+-----+------
+ 2505 | 505 | 0505 | 2505 | 505 | 0505
+(1 row)
+
+CREATE TABLE local_tbl (a int, b int, c text);
+INSERT INTO local_tbl VALUES (1505, 505, 'foo');
+ANALYZE local_tbl;
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Nested Loop Left Join
+ Output: t1.a, t1.b, t1.c, async_pt.a, async_pt.b, async_pt.c, ($0)
+ Join Filter: (t1.a = async_pt.a)
+ InitPlan 1 (returns $0)
+ -> Aggregate
+ Output: count(*)
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_4
+ Remote SQL: SELECT NULL FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_5
+ Remote SQL: SELECT NULL FROM public.base_tbl2 WHERE ((a < 3000))
+ -> Seq Scan on public.local_tbl t1
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1 WHERE ((a < 3000))
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c, $0
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2 WHERE ((a < 3000))
+(20 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ QUERY PLAN
+-----------------------------------------------------------------------------------------
+ Nested Loop Left Join (actual rows=1 loops=1)
+ Join Filter: (t1.a = async_pt.a)
+ Rows Removed by Join Filter: 399
+ InitPlan 1 (returns $0)
+ -> Aggregate (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_4 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_5 (actual rows=200 loops=1)
+ -> Seq Scan on local_tbl t1 (actual rows=1 loops=1)
+ -> Append (actual rows=400 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=200 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=200 loops=1)
+(12 rows)
+
+SELECT * FROM local_tbl t1 LEFT JOIN (SELECT *, (SELECT count(*) FROM async_pt WHERE a < 3000) FROM async_pt WHERE a < 3000) t2 ON t1.a = t2.a;
+ a | b | c | a | b | c | count
+------+-----+-----+------+-----+------+-------
+ 1505 | 505 | foo | 1505 | 505 | 0505 | 400
+(1 row)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+----------------------------------------------------------------
+ Limit
+ Output: t1.a, t1.b, t1.c
+ -> Append
+ -> Async Foreign Scan on public.async_p1 t1_1
+ Output: t1_1.a, t1_1.b, t1_1.c
+ Filter: (t1_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 t1_2
+ Output: t1_2.a, t1_2.b, t1_2.c
+ Filter: (t1_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 t1_3
+ Output: t1_3.a, t1_3.b, t1_3.c
+ Filter: (t1_3.b === 505)
+(14 rows)
+
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Limit (actual rows=1 loops=1)
+ -> Append (actual rows=1 loops=1)
+ -> Async Foreign Scan on async_p1 t1_1 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Async Foreign Scan on async_p2 t1_2 (actual rows=0 loops=1)
+ Filter: (b === 505)
+ -> Seq Scan on async_p3 t1_3 (actual rows=1 loops=1)
+ Filter: (b === 505)
+ Rows Removed by Filter: 101
+(9 rows)
+
+SELECT * FROM async_pt t1 WHERE t1.b === 505 LIMIT 1;
+ a | b | c
+------+-----+------
+ 3505 | 505 | 0505
+(1 row)
+
+-- Check with foreign modify
+CREATE TABLE base_tbl3 (a int, b int, c text);
+CREATE FOREIGN TABLE remote_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl3');
+INSERT INTO remote_tbl VALUES (2505, 505, 'bar');
+CREATE TABLE base_tbl4 (a int, b int, c text);
+CREATE FOREIGN TABLE insert_tbl (a int, b int, c text)
+ SERVER loopback OPTIONS (table_name 'base_tbl4');
+EXPLAIN (VERBOSE, COSTS OFF)
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Insert on public.insert_tbl
+ Remote SQL: INSERT INTO public.base_tbl4(a, b, c) VALUES ($1, $2, $3)
+ Batch Size: 1
+ -> Append
+ -> Seq Scan on public.local_tbl
+ Output: local_tbl.a, local_tbl.b, local_tbl.c
+ -> Async Foreign Scan on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ Remote SQL: SELECT a, b, c FROM public.base_tbl3
+(9 rows)
+
+INSERT INTO insert_tbl (SELECT * FROM local_tbl UNION ALL SELECT * FROM remote_tbl);
+SELECT * FROM insert_tbl ORDER BY a;
+ a | b | c
+------+-----+-----
+ 1505 | 505 | foo
+ 2505 | 505 | bar
+(2 rows)
+
+-- Check with direct modify
+EXPLAIN (VERBOSE, COSTS OFF)
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+ QUERY PLAN
+----------------------------------------------------------------------------------------
+ Insert on public.join_tbl
+ CTE t
+ -> Update on public.remote_tbl
+ Output: remote_tbl.a, remote_tbl.b, remote_tbl.c
+ -> Foreign Update on public.remote_tbl
+ Remote SQL: UPDATE public.base_tbl3 SET c = (c || c) RETURNING a, b, c
+ -> Nested Loop Left Join
+ Output: async_pt.a, async_pt.b, async_pt.c, t.a, t.b, t.c
+ Join Filter: ((async_pt.a = t.a) AND (async_pt.b = t.b))
+ -> Append
+ -> Async Foreign Scan on public.async_p1 async_pt_1
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Filter: (async_pt_1.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl1
+ -> Async Foreign Scan on public.async_p2 async_pt_2
+ Output: async_pt_2.a, async_pt_2.b, async_pt_2.c
+ Filter: (async_pt_2.b === 505)
+ Remote SQL: SELECT a, b, c FROM public.base_tbl2
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.a, async_pt_3.b, async_pt_3.c
+ Filter: (async_pt_3.b === 505)
+ -> CTE Scan on t
+ Output: t.a, t.b, t.c
+(23 rows)
+
+WITH t AS (UPDATE remote_tbl SET c = c || c RETURNING *)
+INSERT INTO join_tbl SELECT * FROM async_pt LEFT JOIN t ON (async_pt.a = t.a AND async_pt.b = t.b) WHERE async_pt.b === 505;
+SELECT * FROM join_tbl ORDER BY a1;
+ a1 | b1 | c1 | a2 | b2 | c2
+------+-----+------+------+-----+--------
+ 1505 | 505 | 0505 | | |
+ 2505 | 505 | 0505 | 2505 | 505 | barbar
+ 3505 | 505 | 0505 | | |
+(3 rows)
+
+DELETE FROM join_tbl;
+DROP TABLE local_tbl;
+DROP FOREIGN TABLE remote_tbl;
+DROP FOREIGN TABLE insert_tbl;
+DROP TABLE base_tbl3;
+DROP TABLE base_tbl4;
+RESET enable_mergejoin;
+RESET enable_hashjoin;
+-- Test that UPDATE/DELETE with inherited target works with async_capable enabled
+EXPLAIN (VERBOSE, COSTS OFF)
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ QUERY PLAN
+----------------------------------------------------------------------------------------------------------
+ Update on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Update on public.async_p1 async_pt_1
+ Foreign Update on public.async_p2 async_pt_2
+ Update on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Update on public.async_p1 async_pt_1
+ Remote SQL: UPDATE public.base_tbl1 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Update on public.async_p2 async_pt_2
+ Remote SQL: UPDATE public.base_tbl2 SET c = (c || c) WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: (async_pt_3.c || async_pt_3.c), async_pt_3.tableoid, async_pt_3.ctid, NULL::record
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+UPDATE async_pt SET c = c || c WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+EXPLAIN (VERBOSE, COSTS OFF)
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ QUERY PLAN
+------------------------------------------------------------------------------------------
+ Delete on public.async_pt
+ Output: async_pt_1.a, async_pt_1.b, async_pt_1.c
+ Foreign Delete on public.async_p1 async_pt_1
+ Foreign Delete on public.async_p2 async_pt_2
+ Delete on public.async_p3 async_pt_3
+ -> Append
+ -> Foreign Delete on public.async_p1 async_pt_1
+ Remote SQL: DELETE FROM public.base_tbl1 WHERE ((b = 0)) RETURNING a, b, c
+ -> Foreign Delete on public.async_p2 async_pt_2
+ Remote SQL: DELETE FROM public.base_tbl2 WHERE ((b = 0)) RETURNING a, b, c
+ -> Seq Scan on public.async_p3 async_pt_3
+ Output: async_pt_3.tableoid, async_pt_3.ctid
+ Filter: (async_pt_3.b = 0)
+(13 rows)
+
+DELETE FROM async_pt WHERE b = 0 RETURNING *;
+ a | b | c
+------+---+----------
+ 1000 | 0 | 00000000
+ 2000 | 0 | 00000000
+ 3000 | 0 | 00000000
+(3 rows)
+
+-- Check EXPLAIN ANALYZE for a query that scans empty partitions asynchronously
+DELETE FROM async_p1;
+DELETE FROM async_p2;
+DELETE FROM async_p3;
+EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF)
+SELECT * FROM async_pt;
+ QUERY PLAN
+-------------------------------------------------------------------------
+ Append (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p1 async_pt_1 (actual rows=0 loops=1)
+ -> Async Foreign Scan on async_p2 async_pt_2 (actual rows=0 loops=1)
+ -> Seq Scan on async_p3 async_pt_3 (actual rows=0 loops=1)
+(4 rows)
+
+-- Clean up
+DROP TABLE async_pt;
+DROP TABLE base_tbl1;
+DROP TABLE base_tbl2;
+DROP TABLE result_tbl;
+DROP TABLE join_tbl;
+-- Test that an asynchronous fetch is processed before restarting the scan in
+-- ReScanForeignScan
+CREATE TABLE base_tbl (a int, b int);
+INSERT INTO base_tbl VALUES (1, 11), (2, 22), (3, 33);
+CREATE FOREIGN TABLE foreign_tbl (b int)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+CREATE FOREIGN TABLE foreign_tbl2 () INHERITS (foreign_tbl)
+ SERVER loopback OPTIONS (table_name 'base_tbl');
+EXPLAIN (VERBOSE, COSTS OFF)
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ QUERY PLAN
+-----------------------------------------------------------------------------
+ Seq Scan on public.base_tbl
+ Output: base_tbl.a
+ Filter: (SubPlan 1)
+ SubPlan 1
+ -> Result
+ Output: base_tbl.a
+ -> Append
+ -> Async Foreign Scan on public.foreign_tbl foreign_tbl_1
+ Remote SQL: SELECT NULL FROM public.base_tbl
+ -> Async Foreign Scan on public.foreign_tbl2 foreign_tbl_2
+ Remote SQL: SELECT NULL FROM public.base_tbl
+(11 rows)
+
+SELECT a FROM base_tbl WHERE a IN (SELECT a FROM foreign_tbl);
+ a
+---
+ 1
+ 2
+ 3
+(3 rows)
+
+-- Clean up
+DROP FOREIGN TABLE foreign_tbl CASCADE;
+NOTICE: drop cascades to foreign table foreign_tbl2
+DROP TABLE base_tbl;
+ALTER SERVER loopback OPTIONS (DROP async_capable);
+ALTER SERVER loopback2 OPTIONS (DROP async_capable);
+-- ===================================================================
+-- test invalid server, foreign table and foreign data wrapper options
+-- ===================================================================
+-- Invalid fdw_startup_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_startup_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_startup_cost": 100$%$#$#
+-- Invalid fdw_tuple_cost option
+CREATE SERVER inv_scst FOREIGN DATA WRAPPER postgres_fdw
+ OPTIONS(fdw_tuple_cost '100$%$#$#');
+ERROR: invalid value for floating point option "fdw_tuple_cost": 100$%$#$#
+-- Invalid fetch_size option
+CREATE FOREIGN TABLE inv_fsz (c1 int )
+ SERVER loopback OPTIONS (fetch_size '100$%$#$#');
+ERROR: invalid value for integer option "fetch_size": 100$%$#$#
+-- Invalid batch_size option
+CREATE FOREIGN TABLE inv_bsz (c1 int )
+ SERVER loopback OPTIONS (batch_size '100$%$#$#');
+ERROR: invalid value for integer option "batch_size": 100$%$#$#
+-- No option is allowed to be specified at foreign data wrapper level
+ALTER FOREIGN DATA WRAPPER postgres_fdw OPTIONS (nonexistent 'fdw');
+ERROR: invalid option "nonexistent"
+HINT: There are no valid options in this context.
+-- ===================================================================
+-- test postgres_fdw.application_name GUC
+-- ===================================================================
+--- Turn debug_discard_caches off for this test to make sure that
+--- the remote connection is alive when checking its application_name.
+SET debug_discard_caches = 0;
+-- Specify escape sequences in application_name option of a server
+-- object so as to test that they are replaced with status information
+-- expectedly.
+--
+-- Since pg_stat_activity.application_name may be truncated to less than
+-- NAMEDATALEN characters, note that substring() needs to be used
+-- at the condition of test query to make sure that the string consisting
+-- of database name and process ID is also less than that.
+ALTER SERVER loopback2 OPTIONS (application_name 'fdw_%d%p');
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_database() || pg_backend_pid() for
+ current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- postgres_fdw.application_name overrides application_name option
+-- of a server object if both settings are present.
+SET postgres_fdw.application_name TO 'fdw_%a%u%%';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('application_name') ||
+ CURRENT_USER || '%' for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- Test %c (session ID) and %C (cluster name) escape sequences.
+SET postgres_fdw.application_name TO 'fdw_%C%c';
+SELECT 1 FROM ft6 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name =
+ substring('fdw_' || current_setting('cluster_name') ||
+ to_hex(trunc(EXTRACT(EPOCH FROM (SELECT backend_start FROM
+ pg_stat_get_activity(pg_backend_pid()))))::integer) || '.' ||
+ to_hex(pg_backend_pid())
+ for current_setting('max_identifier_length')::int);
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+--Clean up
+RESET postgres_fdw.application_name;
+RESET debug_discard_caches;
+-- ===================================================================
+-- test parallel commit
+-- ===================================================================
+ALTER SERVER loopback OPTIONS (ADD parallel_commit 'true');
+ALTER SERVER loopback2 OPTIONS (ADD parallel_commit 'true');
+CREATE TABLE ploc1 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem1 (f1 int, f2 text)
+ SERVER loopback OPTIONS (table_name 'ploc1');
+CREATE TABLE ploc2 (f1 int, f2 text);
+CREATE FOREIGN TABLE prem2 (f1 int, f2 text)
+ SERVER loopback2 OPTIONS (table_name 'ploc2');
+BEGIN;
+INSERT INTO prem1 VALUES (101, 'foo');
+INSERT INTO prem2 VALUES (201, 'bar');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+-----
+ 101 | foo
+(1 row)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+-----
+ 201 | bar
+(1 row)
+
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (102, 'foofoo');
+INSERT INTO prem2 VALUES (202, 'barbar');
+RELEASE SAVEPOINT s;
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+(2 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+(2 rows)
+
+-- This tests executing DEALLOCATE ALL against foreign servers in parallel
+-- during pre-commit
+BEGIN;
+SAVEPOINT s;
+INSERT INTO prem1 VALUES (103, 'baz');
+INSERT INTO prem2 VALUES (203, 'qux');
+ROLLBACK TO SAVEPOINT s;
+RELEASE SAVEPOINT s;
+INSERT INTO prem1 VALUES (104, 'bazbaz');
+INSERT INTO prem2 VALUES (204, 'quxqux');
+COMMIT;
+SELECT * FROM prem1;
+ f1 | f2
+-----+--------
+ 101 | foo
+ 102 | foofoo
+ 104 | bazbaz
+(3 rows)
+
+SELECT * FROM prem2;
+ f1 | f2
+-----+--------
+ 201 | bar
+ 202 | barbar
+ 204 | quxqux
+(3 rows)
+
+ALTER SERVER loopback OPTIONS (DROP parallel_commit);
+ALTER SERVER loopback2 OPTIONS (DROP parallel_commit);
+-- ===================================================================
+-- test for ANALYZE sampling
+-- ===================================================================
+CREATE TABLE analyze_table (id int, a text, b bigint);
+CREATE FOREIGN TABLE analyze_ftable (id int, a text, b bigint)
+ SERVER loopback OPTIONS (table_name 'analyze_rtable1');
+INSERT INTO analyze_table (SELECT x FROM generate_series(1,1000) x);
+ANALYZE analyze_table;
+SET default_statistics_target = 10;
+ANALYZE analyze_table;
+ALTER SERVER loopback OPTIONS (analyze_sampling 'invalid');
+ERROR: invalid value for string option "analyze_sampling": invalid
+ALTER SERVER loopback OPTIONS (analyze_sampling 'auto');
+ANALYZE analyze_table;
+ALTER SERVER loopback OPTIONS (SET analyze_sampling 'system');
+ANALYZE analyze_table;
+ALTER SERVER loopback OPTIONS (SET analyze_sampling 'bernoulli');
+ANALYZE analyze_table;
+ALTER SERVER loopback OPTIONS (SET analyze_sampling 'random');
+ANALYZE analyze_table;
+ALTER SERVER loopback OPTIONS (SET analyze_sampling 'off');
+ANALYZE analyze_table;
+-- cleanup
+DROP FOREIGN TABLE analyze_ftable;
+DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+ pg_terminate_backend
+----------------------
+ t
+(1 row)
+
+-- execute check function. This should return false on supported platforms,
+-- otherwise return true.
+SELECT postgres_fdw_verify_connection_states('loopback');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+(1 row)
+
+ABORT;
+WARNING: 08006
+\set VERBOSITY default
+-- Clean up
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index c37aa80383..287155ab32 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3974,3 +3974,33 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+BEGIN;
+SELECT 1 FROM ft1 LIMIT 1;
+-- Terminate the remote backend process
+SELECT pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+-- execute check function. This should return false on supported platforms,
+-- otherwise return true.
+SELECT postgres_fdw_verify_connection_states('loopback');
+ABORT;
+
+\set VERBOSITY default
+
+-- Clean up
+RESET debug_discard_caches;
--
2.27.0
"Hayato Kuroda (Fujitsu)" <kuroda.hayato@fujitsu.com> writes:
Thanks for reporting. PSA rebased version.
These can be applied work well on my HEAD(bd8d45).
I think that it's a really bad idea to require postgres_fdw.sql
to have two expected-files: that will be a maintenance nightmare.
Please put whatever it is that needs a variant expected-file
into its own, hopefully very small and seldom-changed, test script.
Or rethink whether you really need a test case that has
platform-dependent output.
regards, tom lane
Dear tom,
I think that it's a really bad idea to require postgres_fdw.sql
to have two expected-files: that will be a maintenance nightmare.
Please put whatever it is that needs a variant expected-file
into its own, hopefully very small and seldom-changed, test script.
Or rethink whether you really need a test case that has
platform-dependent output.
Thank you for giving the suggestion. I agreed your saying and modifed that.
I added new functions on the libpq and postgres-fdw layer that check whether the
checking works well or not. In the test, at first, the platform is checked and
the checking function is called only when it is supported.
An alternative approach is that PQCanConncheck() can be combined with PQConncheck().
This can reduce the libpq function, but we must define another returned value to
the function like -2. I was not sure which approach was better.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v23-0001-Add-PQConncheck-to-libpq.patchapplication/octet-stream; name=v23-0001-Add-PQConncheck-to-libpq.patchDownload
From 23a71fe4818f45d86b6b8931f9ca6cd915291a82 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:20 +0000
Subject: [PATCH v23 1/3] Add PQConncheck to libpq
This new libpq function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
---
doc/src/sgml/libpq.sgml | 44 ++++++++++++++++++++++++
src/interfaces/libpq/exports.txt | 2 ++
src/interfaces/libpq/fe-misc.c | 57 ++++++++++++++++++++++++++++++++
src/interfaces/libpq/libpq-fe.h | 4 +++
4 files changed, 107 insertions(+)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 0e7ae70c70..f7cff16f7f 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,50 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQConncheck">
+ <term><function>PQConncheck</function><indexterm><primary>PQConncheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQConncheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQConncheck"/> returns <literal>1</literal>
+ if the remote peer seems to be closed, returns <literal>0</literal> if
+ the socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQCanConncheck">
+ <term><function>PQCanConncheck</function><indexterm><primary>PQCanConncheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQCanConncheck(void);
+</synopsis>
+ </para>
+
+ <para>
+ This function checks whether <xref linkend="libpq-PQConncheck"/> is
+ available or not on this platform. <xref linkend="libpq-PQCanConncheck"/>
+ returns <literal>0</literal> if the function is supported, otherwise
+ returns <literal>-1</literal>.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..b90d178047 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQConncheck 187
+PQCanConncheck 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..2888b94c0d 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -1218,6 +1218,63 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Helper function for PQconncheck().
+ *
+ * Return >0 if opposite side seems to be disconnected.
+ */
+static int
+pqConncheck_internal(int sock)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ struct pollfd input_fd;
+ int errflags = POLLHUP | POLLERR | POLLNVAL;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP | errflags;
+ input_fd.revents = 0;
+
+ poll(&input_fd, 1, 0);
+
+ return input_fd.revents;
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad.
+ */
+int
+PQConncheck(PGconn *conn)
+{
+ /* quick exit if invalid connection has come */
+ if (conn == NULL ||
+ conn->sock == PGINVALID_SOCKET ||
+ conn->status != CONNECTION_OK)
+ return -1;
+
+ return pqConncheck_internal(conn->sock);
+}
+
+/*
+ * Check whether PQConncheck() can work well on this platform.
+ *
+ * Returns 0 if this can use PQConncheck(), otherwise -1.
+ */
+int
+PQCanConncheck(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return 0;
+#else
+ return -1;
+#endif
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..4771ee1124 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQConncheck(PGconn *conn);
+extern int PQCanConncheck(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v23-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v23-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From 6323b6ab8918929a7fa87b27de760ed262f63cbc Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:42 +0000
Subject: [PATCH v23 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQConncheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if checked connection is still valid, or the checking is
not supported on this platform. False is returned if the connection seems
to be closed.
---
contrib/postgres_fdw/connection.c | 107 ++++++++++++++++++
.../postgres_fdw/postgres_fdw--1.0--1.1.sql | 15 +++
doc/src/sgml/postgres-fdw.sgml | 68 +++++++++++
3 files changed, 190 insertions(+)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index ed75ce3f79..b2691139b2 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -86,6 +86,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -116,6 +119,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1862,3 +1866,106 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+
+ /* quick exit if connection cache has been not initialized yet. */
+ if (!ConnectionHash)
+ return true;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQConncheck(entry->conn))
+ {
+ /*
+ * Foreign server might be down, so throw ereport(WARNING).
+ */
+ ForeignServer *server;
+
+ server = GetForeignServer(entry->serverid);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("could not connect to server \"%s\"",
+ server->servername),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of the server.")));
+
+ result = false;
+ }
+ }
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found, and this returns
+ * false only when the verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
+
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(!PQCanConncheck());
+}
diff --git a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
index ed4ca378d4..b337760bfa 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
@@ -18,3 +18,18 @@ CREATE FUNCTION postgres_fdw_disconnect_all ()
RETURNS bool
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 78f2d7d8d5..bfd1dbae93 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -825,6 +825,74 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if a checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports that
+ the connection is closed. This function is currently available only on
+ systems that support the non-standard <symbol>POLLRDHUP</symbol> extension
+ to the <symbol>poll</symbol> system call, including Linux. This returns
+ <literal>true</literal> if a lastly checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether functions the health of remote connectio
+ work well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the function:
+
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v23-0003-add-test.patchapplication/octet-stream; name=v23-0003-add-test.patchDownload
From 8e004ecf5c1972d0caab445485d7d5db0ed663c0 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v23 3/3] add test
Note that this test has two comparison files. Alternative comparison file is needed
because some platforms like Windows cannot check the status of the socket.
---
.../postgres_fdw/expected/postgres_fdw.out | 54 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 53 ++++++++++++++++++
2 files changed, 107 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index c0267a99d2..5359ae6f0f 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11804,3 +11804,57 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index c37aa80383..4e99360a31 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3974,3 +3974,56 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
On Tue, Jan 10, 2023 at 8:26 AM Hayato Kuroda (Fujitsu) <
kuroda.hayato@fujitsu.com> wrote:
Dear tom,
I think that it's a really bad idea to require postgres_fdw.sql
to have two expected-files: that will be a maintenance nightmare.
Please put whatever it is that needs a variant expected-file
into its own, hopefully very small and seldom-changed, test script.
Or rethink whether you really need a test case that has
platform-dependent output.Thank you for giving the suggestion. I agreed your saying and modifed that.
I added new functions on the libpq and postgres-fdw layer that check
whether the
checking works well or not. In the test, at first, the platform is checked
and
the checking function is called only when it is supported.An alternative approach is that PQCanConncheck() can be combined with
PQConncheck().
This can reduce the libpq function, but we must define another returned
value to
the function like -2. I was not sure which approach was better.Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Hi,
+ /* quick exit if connection cache has been not initialized yet. */
been not initialized -> not been initialized
+
(errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("could not connect
to server \"%s\"",
Currently each server which is not connected would log a warning.
Is it better to concatenate names for such servers and log one line ? This
would be cleaner when there are multiple such servers.
Cheers
Dear Ted,
Thank you for reviewing! PSA new version.
+ /* quick exit if connection cache has been not initialized yet. */
been not initialized -> not been initialized
Fixed.
+ (errcode(ERRCODE_CONNECTION_FAILURE), + errmsg("could not connect to server \"%s\"",Currently each server which is not connected would log a warning.
Is it better to concatenate names for such servers and log one line ? This would be cleaner when there are multiple such servers.
Sounds good, fixed as you said. The following shows the case that two disconnections
are detected by postgres_fdw_verify_connection_states_all().
```
postgres=*# select postgres_fdw_verify_connection_states_all ();
WARNING: could not connect to server "my_external_server2", "my_external_server"
DETAIL: Socket close is detected.
HINT: Plsease check the health of server.
postgres_fdw_verify_connection_states_all
-------------------------------------------
f
(1 row)
```
Currently, the name of servers is concatenated without doing unique checks. IIUC
a backend process cannot connect to the same foreign server by using different
user mapping, so there is no possibility that the same name appears twice.
If the user mapping is altered in the transaction, the cache entry is invalidated
and will not be checked.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v24-0001-Add-PQConncheck-and-PQCanConncheck-to-libpq.patchapplication/octet-stream; name=v24-0001-Add-PQConncheck-and-PQCanConncheck-to-libpq.patchDownload
From 600d450274a2f4aa3f3e29c4eb0e1d0e128de2ff Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:20 +0000
Subject: [PATCH v24 1/3] Add PQConncheck and PQCanConncheck to libpq
PQConncheck() function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQCanConncheck() checks whether above function is available or not.
---
doc/src/sgml/libpq.sgml | 44 ++++++++++++++++++++++++
src/interfaces/libpq/exports.txt | 2 ++
src/interfaces/libpq/fe-misc.c | 57 ++++++++++++++++++++++++++++++++
src/interfaces/libpq/libpq-fe.h | 4 +++
4 files changed, 107 insertions(+)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 0e7ae70c70..f7cff16f7f 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,50 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQConncheck">
+ <term><function>PQConncheck</function><indexterm><primary>PQConncheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQConncheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQConncheck"/> returns <literal>1</literal>
+ if the remote peer seems to be closed, returns <literal>0</literal> if
+ the socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQCanConncheck">
+ <term><function>PQCanConncheck</function><indexterm><primary>PQCanConncheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQCanConncheck(void);
+</synopsis>
+ </para>
+
+ <para>
+ This function checks whether <xref linkend="libpq-PQConncheck"/> is
+ available or not on this platform. <xref linkend="libpq-PQCanConncheck"/>
+ returns <literal>0</literal> if the function is supported, otherwise
+ returns <literal>-1</literal>.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..b90d178047 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQConncheck 187
+PQCanConncheck 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..2888b94c0d 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -1218,6 +1218,63 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Helper function for PQconncheck().
+ *
+ * Return >0 if opposite side seems to be disconnected.
+ */
+static int
+pqConncheck_internal(int sock)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ struct pollfd input_fd;
+ int errflags = POLLHUP | POLLERR | POLLNVAL;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP | errflags;
+ input_fd.revents = 0;
+
+ poll(&input_fd, 1, 0);
+
+ return input_fd.revents;
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad.
+ */
+int
+PQConncheck(PGconn *conn)
+{
+ /* quick exit if invalid connection has come */
+ if (conn == NULL ||
+ conn->sock == PGINVALID_SOCKET ||
+ conn->status != CONNECTION_OK)
+ return -1;
+
+ return pqConncheck_internal(conn->sock);
+}
+
+/*
+ * Check whether PQConncheck() can work well on this platform.
+ *
+ * Returns 0 if this can use PQConncheck(), otherwise -1.
+ */
+int
+PQCanConncheck(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return 0;
+#else
+ return -1;
+#endif
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..4771ee1124 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQConncheck(PGconn *conn);
+extern int PQCanConncheck(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v24-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v24-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From 3005525d67175deec5cbb01af7565cc7690a5097 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:42 +0000
Subject: [PATCH v24 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQConncheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if checked connection is still valid, or the checking is
not supported on this platform. False is returned if the connection seems
to be closed.
fdw: concat string
---
contrib/postgres_fdw/connection.c | 124 ++++++++++++++++++
.../postgres_fdw/postgres_fdw--1.0--1.1.sql | 15 +++
doc/src/sgml/postgres-fdw.sgml | 68 ++++++++++
3 files changed, 207 insertions(+)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index ed75ce3f79..5f345ca170 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -86,6 +86,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -116,6 +119,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1862,3 +1866,123 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ /* quick exit if connection cache has not been initialized yet. */
+ if (!ConnectionHash)
+ return true;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQConncheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message. */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+ }
+ }
+
+ /* Raise a warning if disconnections are found. */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of server.")));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found, and this returns
+ * false only when the verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
+
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(!PQCanConncheck());
+}
diff --git a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
index ed4ca378d4..b337760bfa 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
@@ -18,3 +18,18 @@ CREATE FUNCTION postgres_fdw_disconnect_all ()
RETURNS bool
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 78f2d7d8d5..bfd1dbae93 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -825,6 +825,74 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if a checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports that
+ the connection is closed. This function is currently available only on
+ systems that support the non-standard <symbol>POLLRDHUP</symbol> extension
+ to the <symbol>poll</symbol> system call, including Linux. This returns
+ <literal>true</literal> if a lastly checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether functions the health of remote connectio
+ work well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the function:
+
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v24-0003-add-test.patchapplication/octet-stream; name=v24-0003-add-test.patchDownload
From 4a2178608b9cce47fe2c90649e40d004ffdb34b0 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v24 3/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 54 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 53 ++++++++++++++++++
2 files changed, 107 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index c0267a99d2..ee1c0eb96b 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11804,3 +11804,57 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index c37aa80383..49042eb8c1 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3974,3 +3974,56 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
Dear hackers,
I was not sure, but the cfbot could not be accepted the previous version.
I made the patch again from HEAD(5f6401) without any changes,
so I did not count up the version number.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v24-0001-Add-PQConncheck-and-PQCanConncheck-to-libpq.patchapplication/octet-stream; name=v24-0001-Add-PQConncheck-and-PQCanConncheck-to-libpq.patchDownload
From 24dfa629d2f7682fd80278d86d87f7a92f0c0687 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:20 +0000
Subject: [PATCH v24 1/3] Add PQConncheck and PQCanConncheck to libpq
PQConncheck() function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQCanConncheck() checks whether above function is available or not.
---
doc/src/sgml/libpq.sgml | 44 ++++++++++++++++++++++++
src/interfaces/libpq/exports.txt | 2 ++
src/interfaces/libpq/fe-misc.c | 57 ++++++++++++++++++++++++++++++++
src/interfaces/libpq/libpq-fe.h | 4 +++
4 files changed, 107 insertions(+)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 0e7ae70c70..f7cff16f7f 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,50 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQConncheck">
+ <term><function>PQConncheck</function><indexterm><primary>PQConncheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQConncheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQConncheck"/> returns <literal>1</literal>
+ if the remote peer seems to be closed, returns <literal>0</literal> if
+ the socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQCanConncheck">
+ <term><function>PQCanConncheck</function><indexterm><primary>PQCanConncheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQCanConncheck(void);
+</synopsis>
+ </para>
+
+ <para>
+ This function checks whether <xref linkend="libpq-PQConncheck"/> is
+ available or not on this platform. <xref linkend="libpq-PQCanConncheck"/>
+ returns <literal>0</literal> if the function is supported, otherwise
+ returns <literal>-1</literal>.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..b90d178047 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQConncheck 187
+PQCanConncheck 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..2888b94c0d 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -1218,6 +1218,63 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Helper function for PQconncheck().
+ *
+ * Return >0 if opposite side seems to be disconnected.
+ */
+static int
+pqConncheck_internal(int sock)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ struct pollfd input_fd;
+ int errflags = POLLHUP | POLLERR | POLLNVAL;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP | errflags;
+ input_fd.revents = 0;
+
+ poll(&input_fd, 1, 0);
+
+ return input_fd.revents;
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad.
+ */
+int
+PQConncheck(PGconn *conn)
+{
+ /* quick exit if invalid connection has come */
+ if (conn == NULL ||
+ conn->sock == PGINVALID_SOCKET ||
+ conn->status != CONNECTION_OK)
+ return -1;
+
+ return pqConncheck_internal(conn->sock);
+}
+
+/*
+ * Check whether PQConncheck() can work well on this platform.
+ *
+ * Returns 0 if this can use PQConncheck(), otherwise -1.
+ */
+int
+PQCanConncheck(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return 0;
+#else
+ return -1;
+#endif
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..4771ee1124 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQConncheck(PGconn *conn);
+extern int PQCanConncheck(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v24-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v24-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From f1e93bdee4be01b58623cddfc94c4f383d5ec98e Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:42 +0000
Subject: [PATCH v24 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQConncheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if checked connection is still valid, or the checking is
not supported on this platform. False is returned if the connection seems
to be closed.
---
contrib/postgres_fdw/connection.c | 124 ++++++++++++++++++
.../postgres_fdw/postgres_fdw--1.0--1.1.sql | 15 +++
doc/src/sgml/postgres-fdw.sgml | 68 ++++++++++
3 files changed, 207 insertions(+)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index ed75ce3f79..5f345ca170 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -86,6 +86,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -116,6 +119,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1862,3 +1866,123 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ /* quick exit if connection cache has not been initialized yet. */
+ if (!ConnectionHash)
+ return true;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQConncheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message. */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+ }
+ }
+
+ /* Raise a warning if disconnections are found. */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of server.")));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found, and this returns
+ * false only when the verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
+
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(!PQCanConncheck());
+}
diff --git a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
index ed4ca378d4..b337760bfa 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.0--1.1.sql
@@ -18,3 +18,18 @@ CREATE FUNCTION postgres_fdw_disconnect_all ()
RETURNS bool
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 78f2d7d8d5..bfd1dbae93 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -825,6 +825,74 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if a checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are established
+ by <filename>postgres_fdw</filename> from the local session to the foreign
+ servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports that
+ the connection is closed. This function is currently available only on
+ systems that support the non-standard <symbol>POLLRDHUP</symbol> extension
+ to the <symbol>poll</symbol> system call, including Linux. This returns
+ <literal>true</literal> if a lastly checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_foreign_servers(false);
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether functions the health of remote connectio
+ work well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the function:
+
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v24-0003-add-test.patchapplication/octet-stream; name=v24-0003-add-test.patchDownload
From 615ffeac27733039aff876548d9b370285bc25b7 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v24 3/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 54 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 53 ++++++++++++++++++
2 files changed, 107 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index c0267a99d2..ee1c0eb96b 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11804,3 +11804,57 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index c37aa80383..49042eb8c1 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3974,3 +3974,56 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
On 2023-01-11 19:04, Hayato Kuroda (Fujitsu) wrote:
Dear hackers,
I was not sure, but the cfbot could not be accepted the previous
version.
I made the patch again from HEAD(5f6401) without any changes,
so I did not count up the version number.Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Hi,
Thanks for the patch!
I read the patch v24. These are my comments. Please check.
## v24-0001-Add-PQConncheck-and-PQCanConncheck-to-libpq.patch
+ <varlistentry id="libpq-PQCanConncheck">
+
<term><function>PQCanConncheck</function><indexterm><primary>PQCanConncheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
Is this description right? I think this description is for
PQConncheck. Something like "Checks whether PQConncheck is
available on this platform." seems better.
+/* Check whether the postgres server is still alive or not */
+extern int PQConncheck(PGconn *conn);
+extern int PQCanConncheck(void);
Should the names of these functions be in the form of PQconnCheck?
Not PQConncheck (c.f. The section of fe-misc.c in libpq-fe.h).
## v24-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patch
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
This patch adds new functions to postgres_fdw for PostgreSQL 16.
So, I think it is necessary to update the version of postgres_fdw (v1.1
to v1.2).
+ <term><function>postgres_fdw_verify_connection_states_all() returns
boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections that are
established
+ by <filename>postgres_fdw</filename> from the local session to
the foreign
+ servers. This check is performed by polling the socket and allows
It seems better to add a description that states this function
checks all the connections. Like the description of
postgres_fdw_disconnect_all(). For example, "This function
checks the status of 'all the' remote connections..."?
regards,
--
Katsuragi Yuta
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Katsuragi-san,
Thank you for reviewing! PSA new patch set.
## v24-0001-Add-PQConncheck-and-PQCanConncheck-to-libpq.patch + <varlistentry id="libpq-PQCanConncheck"> + <term><function>PQCanConncheck</function><indexterm><primary>PQCan Conncheck</primary></indexterm></term> + <listitem> + <para> + Returns the status of the socket.Is this description right? I think this description is for
PQConncheck. Something like "Checks whether PQConncheck is
available on this platform." seems better.
It might be copy-and-paste error. Thanks for reporting.
According to other parts, the sentence should be started like "Returns ...".
So I followed the style and did cosmetic change.
+/* Check whether the postgres server is still alive or not */ +extern int PQConncheck(PGconn *conn); +extern int PQCanConncheck(void);Should the names of these functions be in the form of PQconnCheck?
Not PQConncheck (c.f. The section of fe-misc.c in libpq-fe.h).
Agreed, fixed.
## v24-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patch +PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states); +PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all); +PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);This patch adds new functions to postgres_fdw for PostgreSQL 16.
So, I think it is necessary to update the version of postgres_fdw (v1.1
to v1.2).
I checked postgres_fdw commit log, and it seemed that the version was
updated when SQL functions are added. Fixed.
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term> + <listitem> + <para> + This function checks the status of remote connections that are established + by <filename>postgres_fdw</filename> from the local session to the foreign + servers. This check is performed by polling the socket and allowsIt seems better to add a description that states this function
checks all the connections. Like the description of
postgres_fdw_disconnect_all(). For example, "This function
checks the status of 'all the' remote connections..."?
I checked the docs and fixed. Moreover, some inconsistent statements were
also fixed.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v25-0001-Add-PQConnCheck-and-PQCanConnCheck-to-libpq.patchapplication/octet-stream; name=v25-0001-Add-PQConnCheck-and-PQCanConnCheck-to-libpq.patchDownload
From 257217ac713c4a695a2f7d2b6384ee9e4c29da5d Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:20 +0000
Subject: [PATCH v25 1/3] Add PQConnCheck and PQCanConnCheck to libpq
PQConnCheck() function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQCanConnCheck() checks whether above function is available or not.
---
doc/src/sgml/libpq.sgml | 40 ++++++++++++++++++++++
src/interfaces/libpq/exports.txt | 2 ++
src/interfaces/libpq/fe-misc.c | 57 ++++++++++++++++++++++++++++++++
src/interfaces/libpq/libpq-fe.h | 4 +++
4 files changed, 103 insertions(+)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 0e7ae70c70..4821898f84 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,46 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQConnCheck">
+ <term><function>PQConnCheck</function><indexterm><primary>PQConnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQConnCeck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQConnCheck"/> returns <literal>1</literal>
+ if the remote peer seems to be closed, returns <literal>0</literal> if
+ the socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQCanConnCheck">
+ <term><function>PQCanConnCheck</function><indexterm><primary>PQCanConnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns whether <xref linkend="libpq-PQConnCheck"/> is available on this
+ platform. <xref linkend="libpq-PQCanConnCheck"/> returns
+ <literal>0</literal> if the function is supported, otherwise returns
+ <literal>-1</literal>.
+
+<synopsis>
+int PQCanConnCheck(void);
+</synopsis>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..267cfdcb48 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQConnCheck 187
+PQCanConnCheck 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..184fda90d3 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -1218,6 +1218,63 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Helper function for PQconnCheck().
+ *
+ * Return >0 if opposite side seems to be disconnected.
+ */
+static int
+pqConnCheck_internal(int sock)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ struct pollfd input_fd;
+ int errflags = POLLHUP | POLLERR | POLLNVAL;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP | errflags;
+ input_fd.revents = 0;
+
+ poll(&input_fd, 1, 0);
+
+ return input_fd.revents;
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad.
+ */
+int
+PQConnCheck(PGconn *conn)
+{
+ /* quick exit if invalid connection has come */
+ if (conn == NULL ||
+ conn->sock == PGINVALID_SOCKET ||
+ conn->status != CONNECTION_OK)
+ return -1;
+
+ return pqConnCheck_internal(conn->sock);
+}
+
+/*
+ * Check whether PQConnCheck() can work well on this platform.
+ *
+ * Returns 0 if this can use PQConnCheck(), otherwise -1.
+ */
+int
+PQCanConnCheck(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return 0;
+#else
+ return -1;
+#endif
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..053fad0760 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQConnCheck(PGconn *conn);
+extern int PQCanConnCheck(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v25-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v25-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From 4ad0426668fcc73988878b1d2217365cd8c9d22c Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:42 +0000
Subject: [PATCH v25 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQConnCheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if checked connection is still valid, or the checking is
not supported on this platform. False is returned if the connection seems
to be closed.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 124 ++++++++++++++++++
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 19 +++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 69 ++++++++++
5 files changed, 214 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index ed75ce3f79..a6702169d4 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -86,6 +86,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -116,6 +119,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1862,3 +1866,123 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ /* quick exit if connection cache has not been initialized yet. */
+ if (!ConnectionHash)
+ return true;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQConnCheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message. */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+ }
+ }
+
+ /* Raise a warning if disconnections are found. */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of server.")));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found, and this returns
+ * false only when the verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
+
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(!PQCanConnCheck());
+}
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..a8556b4c9f
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,19 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 644f51835b..05265a1ef8 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -826,6 +826,75 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if all the remote connections are still
+ valid, or the checking is not supported on this platform.
+ <literal>false</literal> is returned if the local session seems to be
+ disconnected from at least one remote server. Example usage of the
+ function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether functions the health of remote connectio
+ work well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v25-0003-add-test.patchapplication/octet-stream; name=v25-0003-add-test.patchDownload
From eceaeabbb8faa319f2f3b5589e994214e04a4663 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v25 3/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 54 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 53 ++++++++++++++++++
2 files changed, 107 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 2350cfe148..28b5af8d78 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11798,3 +11798,57 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index c37aa80383..49042eb8c1 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3974,3 +3974,56 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
On Sat, Jan 21, 2023 at 4:03 AM Hayato Kuroda (Fujitsu) <
kuroda.hayato@fujitsu.com> wrote:
Dear Katsuragi-san,
Thank you for reviewing! PSA new patch set.
## v24-0001-Add-PQConncheck-and-PQCanConncheck-to-libpq.patch + <varlistentry id="libpq-PQCanConncheck"> + <term><function>PQCanConncheck</function><indexterm><primary>PQCan Conncheck</primary></indexterm></term> + <listitem> + <para> + Returns the status of the socket.Is this description right? I think this description is for
PQConncheck. Something like "Checks whether PQConncheck is
available on this platform." seems better.It might be copy-and-paste error. Thanks for reporting.
According to other parts, the sentence should be started like "Returns
...".
So I followed the style and did cosmetic change.+/* Check whether the postgres server is still alive or not */ +extern int PQConncheck(PGconn *conn); +extern int PQCanConncheck(void);Should the names of these functions be in the form of PQconnCheck?
Not PQConncheck (c.f. The section of fe-misc.c in libpq-fe.h).Agreed, fixed.
## v24-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patch +PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states); +PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all); +PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);This patch adds new functions to postgres_fdw for PostgreSQL 16.
So, I think it is necessary to update the version of postgres_fdw (v1.1
to v1.2).I checked postgres_fdw commit log, and it seemed that the version was
updated when SQL functions are added. Fixed.+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term> + <listitem> + <para> + This function checks the status of remote connections that are established + by <filename>postgres_fdw</filename> from the local session to the foreign + servers. This check is performed by polling the socket and allowsIt seems better to add a description that states this function
checks all the connections. Like the description of
postgres_fdw_disconnect_all(). For example, "This function
checks the status of 'all the' remote connections..."?I checked the docs and fixed. Moreover, some inconsistent statements were
also fixed.Best Regards,
Hayato Kuroda
FUJITSU LIMITEDHi,
For v25-0001-Add-PQConnCheck-and-PQCanConnCheck-to-libpq.patch ,
`pqConnCheck_internal` only has one caller which is quite short.
Can pqConnCheck_internal and PQConnCheck be merged into one func ?
+int
+PQCanConnCheck(void)
It seems the return value should be of bool type.
Cheers
Thank you for reviewing! PSA new patch set.
Sorry, I missed the updated file in the patch. New version will be posted soon.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Dear Ted,
Thanks for reviewing! PSA new version.
For v25-0001-Add-PQConnCheck-and-PQCanConnCheck-to-libpq.patch , `pqConnCheck_internal` only has one caller which is quite short.
Can pqConnCheck_internal and PQConnCheck be merged into one func ?
I divided the function for feature expandability. Currently it works on linux platform,
but the limitation should be removed in future and internal function will be longer.
Therefore I want to keep this style.
+int
+PQCanConnCheck(void)It seems the return value should be of bool type.
I slightly changed the returned value like true/false. But IIUC libpq functions
cannot define as "bool" datatype. E.g. PQconnectionNeedsPassword() returns true/false,
but the function is defined as int.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v26-0001-Add-PQConnCheck-and-PQCanConnCheck-to-libpq.patchapplication/octet-stream; name=v26-0001-Add-PQConnCheck-and-PQCanConnCheck-to-libpq.patchDownload
From 3ad9df1e9c3a6a21268e9599b5b941b047843c72 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:20 +0000
Subject: [PATCH v26 1/3] Add PQConnCheck and PQCanConnCheck to libpq
PQConnCheck() function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQCanConnCheck() checks whether above function is available or not.
---
doc/src/sgml/libpq.sgml | 40 ++++++++++++++++++++++
src/interfaces/libpq/exports.txt | 2 ++
src/interfaces/libpq/fe-misc.c | 57 ++++++++++++++++++++++++++++++++
src/interfaces/libpq/libpq-fe.h | 4 +++
4 files changed, 103 insertions(+)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 0e7ae70c70..086b97340d 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,46 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQConnCheck">
+ <term><function>PQConnCheck</function><indexterm><primary>PQConnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQConnCheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQConnCheck"/> returns <literal>1</literal>
+ if the remote peer seems to be closed, returns <literal>0</literal> if
+ the socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQCanConnCheck">
+ <term><function>PQCanConnCheck</function><indexterm><primary>PQCanConnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns whether <xref linkend="libpq-PQConnCheck"/> is available on this
+ platform. <xref linkend="libpq-PQCanConnCheck"/> returns
+ <literal>1</literal> if the function is supported, otherwise returns
+ <literal>0</literal>.
+
+<synopsis>
+int PQCanConnCheck(void);
+</synopsis>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..267cfdcb48 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQConnCheck 187
+PQCanConnCheck 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..445a1da721 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -1218,6 +1218,63 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Helper function for PQconnCheck().
+ *
+ * Return >0 if opposite side seems to be disconnected.
+ */
+static int
+pqConnCheck_internal(int sock)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ struct pollfd input_fd;
+ int errflags = POLLHUP | POLLERR | POLLNVAL;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP | errflags;
+ input_fd.revents = 0;
+
+ poll(&input_fd, 1, 0);
+
+ return input_fd.revents;
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad.
+ */
+int
+PQConnCheck(PGconn *conn)
+{
+ /* quick exit if invalid connection has come */
+ if (conn == NULL ||
+ conn->sock == PGINVALID_SOCKET ||
+ conn->status != CONNECTION_OK)
+ return -1;
+
+ return pqConnCheck_internal(conn->sock);
+}
+
+/*
+ * Check whether PQConnCheck() can work well on this platform.
+ *
+ * Returns 1 if this can use PQConnCheck(), otherwise 0.
+ */
+int
+PQCanConnCheck(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..053fad0760 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQConnCheck(PGconn *conn);
+extern int PQCanConnCheck(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v26-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v26-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From c97328f7c6ca16ed4fb5437abd2e2ce8d2d7c27d Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:42 +0000
Subject: [PATCH v26 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQConnCheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if checked connection is still valid, or the checking is
not supported on this platform. False is returned if the connection seems
to be closed.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 124 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 19 +++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 69 ++++++++++
6 files changed, 215 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index ed75ce3f79..4dc26f48bf 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -86,6 +86,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -116,6 +119,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1862,3 +1866,123 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ /* quick exit if connection cache has not been initialized yet. */
+ if (!ConnectionHash)
+ return true;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQConnCheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message. */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+ }
+ }
+
+ /* Raise a warning if disconnections are found. */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of server.")));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found, and this returns
+ * false only when the verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
+
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(PQCanConnCheck());
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..a8556b4c9f
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,19 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 644f51835b..05265a1ef8 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -826,6 +826,75 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if all the remote connections are still
+ valid, or the checking is not supported on this platform.
+ <literal>false</literal> is returned if the local session seems to be
+ disconnected from at least one remote server. Example usage of the
+ function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether functions the health of remote connectio
+ work well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v26-0003-add-test.patchapplication/octet-stream; name=v26-0003-add-test.patchDownload
From e772dff2ea94ce696c26754f18bd27ef49ab4862 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v26 3/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 54 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 53 ++++++++++++++++++
2 files changed, 107 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 2350cfe148..28b5af8d78 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11798,3 +11798,57 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index c37aa80383..49042eb8c1 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3974,3 +3974,56 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
On 2023-01-23 14:40, Hayato Kuroda (Fujitsu) wrote:
Dear Ted,
Thanks for reviewing! PSA new version.
For v25-0001-Add-PQConnCheck-and-PQCanConnCheck-to-libpq.patch ,
`pqConnCheck_internal` only has one caller which is quite short.
Can pqConnCheck_internal and PQConnCheck be merged into one func ?I divided the function for feature expandability. Currently it works
on linux platform,
but the limitation should be removed in future and internal function
will be longer.
Therefore I want to keep this style.+int
+PQCanConnCheck(void)It seems the return value should be of bool type.
I slightly changed the returned value like true/false. But IIUC libpq
functions
cannot define as "bool" datatype. E.g. PQconnectionNeedsPassword()
returns true/false,
but the function is defined as int.Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Thank you for updating the patch!
+/* Check whether the postgres server is still alive or not */
+extern int PQConnCheck(PGconn *conn);
+extern int PQCanConnCheck(void);
Aren't these PQconnCheck and PQcanConnCheck? I think the first letter
following 'PQ' should be lower case.
regards.
--
Katsuragi Yuta
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Katsuragi-san,
Thank you for reading the patch! PSA new version.
Thank you for updating the patch!
+/* Check whether the postgres server is still alive or not */ +extern int PQConnCheck(PGconn *conn); +extern int PQCanConnCheck(void);Aren't these PQconnCheck and PQcanConnCheck? I think the first letter
following 'PQ' should be lower case.
I cannot find any rules about it, but seems right. Fixed.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v27-0001-Add-PQconnCheck-and-PQcanConnCheck-to-libpq.patchapplication/octet-stream; name=v27-0001-Add-PQconnCheck-and-PQcanConnCheck-to-libpq.patchDownload
From 0ddb539dacbdf58448f527ef63cbb748dcf390d8 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:20 +0000
Subject: [PATCH v27 1/3] Add PQconnCheck and PQcanConnCheck to libpq
PQconnCheck() function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQcanConnCheck() checks whether above function is available or not.
---
doc/src/sgml/libpq.sgml | 40 ++++++++++++++++++++++
src/interfaces/libpq/exports.txt | 2 ++
src/interfaces/libpq/fe-misc.c | 57 ++++++++++++++++++++++++++++++++
src/interfaces/libpq/libpq-fe.h | 4 +++
4 files changed, 103 insertions(+)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 0e7ae70c70..c8789ecd95 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,46 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQConnCheck">
+ <term><function>PQConnCheck</function><indexterm><primary>PQConnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQConnCheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQConnCheck"/> returns <literal>1</literal>
+ if the remote peer seems to be closed, returns <literal>0</literal> if
+ the socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQcanConnCheck">
+ <term><function>PQcanConnCheck</function><indexterm><primary>PQcanConnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns whether <xref linkend="libpq-PQConnCheck"/> is available on this
+ platform. <xref linkend="libpq-PQcanConnCheck"/> returns
+ <literal>1</literal> if the function is supported, otherwise returns
+ <literal>0</literal>.
+
+<synopsis>
+int PQcanConnCheck(void);
+</synopsis>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..5c908bfe6e 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQconnCheck 187
+PQcanConnCheck 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..49f5ca3479 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -1218,6 +1218,63 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Helper function for PQconnCheck().
+ *
+ * Return >0 if opposite side seems to be disconnected.
+ */
+static int
+pqconnCheck_internal(int sock)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ struct pollfd input_fd;
+ int errflags = POLLHUP | POLLERR | POLLNVAL;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP | errflags;
+ input_fd.revents = 0;
+
+ poll(&input_fd, 1, 0);
+
+ return input_fd.revents;
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad.
+ */
+int
+PQconnCheck(PGconn *conn)
+{
+ /* quick exit if invalid connection has come */
+ if (conn == NULL ||
+ conn->sock == PGINVALID_SOCKET ||
+ conn->status != CONNECTION_OK)
+ return -1;
+
+ return pqconnCheck_internal(conn->sock);
+}
+
+/*
+ * Check whether PQconnCheck() can work well on this platform.
+ *
+ * Returns 1 if this can use PQconnCheck(), otherwise 0.
+ */
+int
+PQcanConnCheck(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..04a0395efb 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQconnCheck(PGconn *conn);
+extern int PQcanConnCheck(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v27-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v27-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From 4d28e091ae033fd5ae58ee26af9073f01ed3d059 Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Tue, 1 Nov 2022 09:13:42 +0000
Subject: [PATCH v27 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQconnCheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if checked connection is still valid, or the checking is
not supported on this platform. False is returned if the connection seems
to be closed.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 124 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 19 +++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 69 ++++++++++
6 files changed, 215 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index ed75ce3f79..35a11c22e7 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -86,6 +86,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -116,6 +119,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1862,3 +1866,123 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ /* quick exit if connection cache has not been initialized yet. */
+ if (!ConnectionHash)
+ return true;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQconnCheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message. */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+ }
+ }
+
+ /* Raise a warning if disconnections are found. */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of server.")));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found, and this returns
+ * false only when the verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
+
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(PQcanConnCheck());
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..a8556b4c9f
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,19 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 644f51835b..05265a1ef8 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -826,6 +826,75 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if all the remote connections are still
+ valid, or the checking is not supported on this platform.
+ <literal>false</literal> is returned if the local session seems to be
+ disconnected from at least one remote server. Example usage of the
+ function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether functions the health of remote connectio
+ work well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v27-0003-add-test.patchapplication/octet-stream; name=v27-0003-add-test.patchDownload
From b338eeecc5f3810fdf551dd873851e065b5314dd Mon Sep 17 00:00:00 2001
From: "kuroda.hayato%40jp.fujitsu.com" <kuroda.hayato@jp.fujitsu.com>
Date: Wed, 21 Sep 2022 06:52:23 +0000
Subject: [PATCH v27 3/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 54 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 53 ++++++++++++++++++
2 files changed, 107 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 2350cfe148..28b5af8d78 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11798,3 +11798,57 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index c37aa80383..49042eb8c1 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3974,3 +3974,56 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
Dear hackers,
I have updated my patch for error handling and kqueue() support.
Actually I do not have BSD-like machine, but I developed by using github CICD.
I think at first we should focus on 0001-0003, and then work for 0004.
Followings are change notes and my analysis.
0001
* Fix missed replacements from PQConnCheck() to PQconnCheck().
* Error handling was improved. Now we can detect the failure of poll() and return -1 at that time.
* I thought we don't have to add select(2) in PQconnCheck(). According to man page [1]https://man7.org/linux/man-pages/man2/select.2.html,
select(2) can be only used for watch whether the status is readable, writable, or exceptional condition.
It means that select() does not have an event corresponding to POLLRDHUP.
0002, 0003
Not changed
0004
* Add kqueue(2) support() for BSD family.
* I did not add epoll() support, because it can be used only on linux and such systems have POLLRDHUP instead.
checked other codes in libpq, and they do not use epoll(). We can see that such an event does not specified in POSIX [2]https://pubs.opengroup.org/onlinepubs/9699919799/functions/poll.html
and it can be used for linux only. I decided to use poll() as much as possible to keep the policy.
* While coding, I found that there are no good timing to close the kernel event queue.
It means that the lifetime of kqueue becomes same as the client program and occupy the small memory forever.
I'm not sure it can be accepted.
[1]: https://man7.org/linux/man-pages/man2/select.2.html
[2]: https://pubs.opengroup.org/onlinepubs/9699919799/functions/poll.html
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v28-0001-Add-PQconnCheck-and-PQcanConnCheck-to-libpq.patchapplication/octet-stream; name=v28-0001-Add-PQconnCheck-and-PQcanConnCheck-to-libpq.patchDownload
From 2f17e7ce900c17dd06b03aa891890b345917d303 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:18 +0000
Subject: [PATCH v28 1/4] Add PQconnCheck and PQcanConnCheck to libpq
PQconnCheck() function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQcanConnCheck() checks whether above function is available or not.
---
doc/src/sgml/libpq.sgml | 40 ++++++++++++++++++
src/interfaces/libpq/exports.txt | 2 +
src/interfaces/libpq/fe-misc.c | 69 ++++++++++++++++++++++++++++++++
src/interfaces/libpq/libpq-fe.h | 4 ++
4 files changed, 115 insertions(+)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 0e7ae70c70..5e07a252ce 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,46 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQconnCheck">
+ <term><function>PQconnCheck</function><indexterm><primary>PQconnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQconnCheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQconnCheck"/> returns <literal>1</literal>
+ if the remote peer seems to be closed, returns <literal>0</literal> if
+ the socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid or an error is error occurred.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQcanConnCheck">
+ <term><function>PQcanConnCheck</function><indexterm><primary>PQcanConnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns whether <xref linkend="libpq-PQconnCheck"/> is available on this
+ platform. <xref linkend="libpq-PQcanConnCheck"/> returns
+ <literal>1</literal> if the function is supported, otherwise returns
+ <literal>0</literal>.
+
+<synopsis>
+int PQcanConnCheck(void);
+</synopsis>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..5c908bfe6e 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQconnCheck 187
+PQcanConnCheck 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..6e807e7c6a 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -1218,6 +1218,75 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Helper function for PQconnCheck().
+ *
+ * Return >0 if opposite side seems to be disconnected, 0 the socket is valid,
+ * and -1 if an error occurred.
+ */
+static int
+pqconnCheck_internal(int sock)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ struct pollfd input_fd;
+ int errflags = POLLHUP | POLLERR | POLLNVAL;
+ int result;
+
+ /* Prepare pollfd entry */
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP | errflags;
+ input_fd.revents = 0;
+
+ /*
+ * Check the status of socket. Note that we will retry as long as we get
+ * EINTR.
+ */
+ do
+ result = poll(&input_fd, 1, 0);
+ while (result < 0 && errno == EINTR);
+
+ if (result < 0)
+ return -1;
+
+ return input_fd.revents;
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad or an error occurred.
+ */
+int
+PQconnCheck(PGconn *conn)
+{
+ /* quick exit if invalid connection has come */
+ if (conn == NULL ||
+ conn->sock == PGINVALID_SOCKET ||
+ conn->status != CONNECTION_OK)
+ return -1;
+
+ return pqconnCheck_internal(conn->sock);
+}
+
+/*
+ * Check whether PQconnCheck() can work well on this platform.
+ *
+ * Returns 1 if this can use PQconnCheck(), otherwise 0.
+ */
+int
+PQcanConnCheck(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..04a0395efb 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQconnCheck(PGconn *conn);
+extern int PQcanConnCheck(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v28-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v28-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From f36effa4eb0045682249c2113afa354b3733a309 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v28 2/4] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQconnCheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if checked connection is still valid, or the checking is
not supported on this platform. False is returned if the connection seems
to be closed.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 124 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 19 +++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 69 ++++++++++
6 files changed, 215 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 7760380f00..1d7e350b33 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -87,6 +87,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -117,6 +120,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1832,3 +1836,123 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ /* quick exit if connection cache has not been initialized yet. */
+ if (!ConnectionHash)
+ return true;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQconnCheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message. */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+ }
+ }
+
+ /* Raise a warning if disconnections are found. */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of server.")));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found, and this returns
+ * false only when the verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
+
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(PQcanConnCheck());
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..a8556b4c9f
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,19 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 644f51835b..05265a1ef8 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -826,6 +826,75 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if all the remote connections are still
+ valid, or the checking is not supported on this platform.
+ <literal>false</literal> is returned if the local session seems to be
+ disconnected from at least one remote server. Example usage of the
+ function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether functions the health of remote connectio
+ work well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v28-0003-add-test.patchapplication/octet-stream; name=v28-0003-add-test.patchDownload
From 7d74923f454f0e5e0bd2a6ff47818efa9d4a5614 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:36 +0000
Subject: [PATCH v28 3/4] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 54 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 53 ++++++++++++++++++
2 files changed, 107 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 2350cfe148..28b5af8d78 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11798,3 +11798,57 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index c37aa80383..49042eb8c1 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3974,3 +3974,56 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
v28-0004-add-kqueue-support-for-PQconnCheck-and-PQcanConn.patchapplication/octet-stream; name=v28-0004-add-kqueue-support-for-PQconnCheck-and-PQcanConn.patchDownload
From cbb2d8208e0afce89e8110126c5d745c3e947c92 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:41 +0000
Subject: [PATCH v28 4/4] add kqueue support for PQconnCheck and PQcanConnCheck
---
doc/src/sgml/libpq.sgml | 15 ++++++------
doc/src/sgml/postgres-fdw.sgml | 10 ++++----
src/interfaces/libpq/fe-misc.c | 43 +++++++++++++++++++++++++++++++++-
3 files changed, 55 insertions(+), 13 deletions(-)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 5e07a252ce..56e495b3f1 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2692,13 +2692,14 @@ int PQconnCheck(PGconn *conn);
<para>
Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
- health. This check is performed by polling the socket. This function is
- currently available only on systems that support the non-standard
- <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
- call, including Linux. <xref linkend="libpq-PQconnCheck"/> returns <literal>1</literal>
- if the remote peer seems to be closed, returns <literal>0</literal> if
- the socket is valid, and returns <literal>-1</literal> if the connection
- has been already invalid or an error is error occurred.
+ health. This check is performed by polling the socket. This option
+ relies on kernel events exposed by Linux, macOS, illumos and the BSD
+ family of operating systems, and is not currently available on other
+ systems. <xref linkend="libpq-PQconnCheck"/> returns
+ <literal>1</literal> if the remote peer seems to be closed, returns
+ <literal>0</literal> if the socket is valid, and returns
+ <literal>-1</literal> if the connection has been already invalid or
+ an error is error occurred.
</para>
</listitem>
</varlistentry>
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 05265a1ef8..b6912f4d94 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -859,11 +859,11 @@ postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
by <filename>postgres_fdw</filename> from the local session to the
foreign servers. This check is performed by polling the socket and allows
long-running transactions to be aborted sooner if the kernel reports
- that the connection is closed. This function is currently available only
- on systems that support the non-standard <symbol>POLLRDHUP</symbol>
- extension to the <symbol>poll</symbol> system call, including Linux. This
- returns <literal>true</literal> if all the remote connections are still
- valid, or the checking is not supported on this platform.
+ that the connection is closed. This option relies on kernel events
+ exposed by Linux, macOS, illumos and the BSD family of operating systems,
+ and is not currently available on other systems. This returns
+ <literal>true</literal> if all the remote connections are still valid,
+ or the checking is not supported on this platform.
<literal>false</literal> is returned if the local session seems to be
disconnected from at least one remote server. Example usage of the
function:
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 6e807e7c6a..9578f905f9 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -43,6 +43,10 @@
#ifdef HAVE_POLL_H
#include <poll.h>
+#elif HAVE_KQUEUE
+#include <sys/types.h>
+#include <sys/event.h>
+#include <sys/time.h>
#endif
#include "libpq-fe.h"
@@ -1227,6 +1231,7 @@ PQenv2encoding(void)
static int
pqconnCheck_internal(int sock)
{
+ /* We use poll(2) if available, otherwise kqueue(2) */
#if (defined(HAVE_POLL) && defined(POLLRDHUP))
struct pollfd input_fd;
int errflags = POLLHUP | POLLERR | POLLNVAL;
@@ -1249,6 +1254,41 @@ pqconnCheck_internal(int sock)
return -1;
return input_fd.revents;
+#elif defined(HAVE_KQUEUE)
+ struct kevent kev, ret;
+ struct timespec timeout = {};
+ static int kq = -1;
+ int result;
+
+ /* If this function has never called yet, create a kernel event queue */
+ if (kq < 0)
+ {
+ kq = kqueue();
+ if (kq < 0)
+ return -1;
+ }
+
+ /* Prepare kevent structure */
+ EV_SET(&kev, sock, EVFILT_READ, EV_ADD, 0, 0, NULL);
+ if (kevent(kq, &kev, 1, NULL, 0, NULL))
+ return -1;
+
+ /*
+ * Check the status of socket. Note that we will retry as long as we get
+ * EINTR.
+ */
+ do
+ result = kevent(kq, NULL, 0, &ret, 1, &timeout);
+ while (result < 0 && errno == EINTR);
+
+ /* Clean up the queue */
+ EV_SET(&kev, sock, EVFILT_READ, EV_DELETE, 0, 0, NULL);
+ kevent(kq, &kev, 1, NULL, 0, NULL);
+
+ if (result < 0)
+ return -1;
+
+ return ret.flags & EV_EOF;
#else
/* Do not support socket checking on this platform, return 0 */
return 0;
@@ -1281,7 +1321,8 @@ PQconnCheck(PGconn *conn)
int
PQcanConnCheck(void)
{
-#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+#if ((defined(HAVE_POLL) && defined(POLLRDHUP)) || \
+ defined(HAVE_KQUEUE))
return true;
#else
return false;
--
2.27.0
I found cfbot failure, PSA fixed version.
Sorry for noise.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v29-0003-add-test.patchapplication/octet-stream; name=v29-0003-add-test.patchDownload
From 7d74923f454f0e5e0bd2a6ff47818efa9d4a5614 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:36 +0000
Subject: [PATCH v29 3/4] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 54 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 53 ++++++++++++++++++
2 files changed, 107 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 2350cfe148..28b5af8d78 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11798,3 +11798,57 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index c37aa80383..49042eb8c1 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3974,3 +3974,56 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+DO $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$;
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
v29-0004-add-kqueue-support-for-PQconnCheck-and-PQcanConn.patchapplication/octet-stream; name=v29-0004-add-kqueue-support-for-PQconnCheck-and-PQcanConn.patchDownload
From bc44376b0045a5d718b80079a6ee882c7c7f05e2 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:41 +0000
Subject: [PATCH v29 4/4] add kqueue support for PQconnCheck and PQcanConnCheck
---
doc/src/sgml/libpq.sgml | 15 ++++++-----
doc/src/sgml/postgres-fdw.sgml | 10 ++++----
src/interfaces/libpq/fe-misc.c | 47 +++++++++++++++++++++++++++++++++-
3 files changed, 59 insertions(+), 13 deletions(-)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 5e07a252ce..56e495b3f1 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2692,13 +2692,14 @@ int PQconnCheck(PGconn *conn);
<para>
Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
- health. This check is performed by polling the socket. This function is
- currently available only on systems that support the non-standard
- <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
- call, including Linux. <xref linkend="libpq-PQconnCheck"/> returns <literal>1</literal>
- if the remote peer seems to be closed, returns <literal>0</literal> if
- the socket is valid, and returns <literal>-1</literal> if the connection
- has been already invalid or an error is error occurred.
+ health. This check is performed by polling the socket. This option
+ relies on kernel events exposed by Linux, macOS, illumos and the BSD
+ family of operating systems, and is not currently available on other
+ systems. <xref linkend="libpq-PQconnCheck"/> returns
+ <literal>1</literal> if the remote peer seems to be closed, returns
+ <literal>0</literal> if the socket is valid, and returns
+ <literal>-1</literal> if the connection has been already invalid or
+ an error is error occurred.
</para>
</listitem>
</varlistentry>
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 05265a1ef8..b6912f4d94 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -859,11 +859,11 @@ postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
by <filename>postgres_fdw</filename> from the local session to the
foreign servers. This check is performed by polling the socket and allows
long-running transactions to be aborted sooner if the kernel reports
- that the connection is closed. This function is currently available only
- on systems that support the non-standard <symbol>POLLRDHUP</symbol>
- extension to the <symbol>poll</symbol> system call, including Linux. This
- returns <literal>true</literal> if all the remote connections are still
- valid, or the checking is not supported on this platform.
+ that the connection is closed. This option relies on kernel events
+ exposed by Linux, macOS, illumos and the BSD family of operating systems,
+ and is not currently available on other systems. This returns
+ <literal>true</literal> if all the remote connections are still valid,
+ or the checking is not supported on this platform.
<literal>false</literal> is returned if the local session seems to be
disconnected from at least one remote server. Example usage of the
function:
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 6e807e7c6a..4d493b7091 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -45,6 +45,14 @@
#include <poll.h>
#endif
+/* We use poll(2) if it has POLLRDHUP event, otherwise kqueue(2) */
+#if (!(defined(HAVE_POLL) && defined(POLLRDHUP)) && \
+ defined(HAVE_KQUEUE))
+#include <sys/types.h>
+#include <sys/event.h>
+#include <sys/time.h>
+#endif
+
#include "libpq-fe.h"
#include "libpq-int.h"
#include "mb/pg_wchar.h"
@@ -1227,6 +1235,7 @@ PQenv2encoding(void)
static int
pqconnCheck_internal(int sock)
{
+ /* We use poll(2) if it has POLLRDHUP event, otherwise kqueue(2) */
#if (defined(HAVE_POLL) && defined(POLLRDHUP))
struct pollfd input_fd;
int errflags = POLLHUP | POLLERR | POLLNVAL;
@@ -1249,6 +1258,41 @@ pqconnCheck_internal(int sock)
return -1;
return input_fd.revents;
+#elif defined(HAVE_KQUEUE)
+ struct kevent kev, ret;
+ struct timespec timeout = {};
+ static int kq = -1;
+ int result;
+
+ /* If this function has never called yet, create a kernel event queue */
+ if (kq < 0)
+ {
+ kq = kqueue();
+ if (kq < 0)
+ return -1;
+ }
+
+ /* Prepare kevent structure */
+ EV_SET(&kev, sock, EVFILT_READ, EV_ADD, 0, 0, NULL);
+ if (kevent(kq, &kev, 1, NULL, 0, NULL))
+ return -1;
+
+ /*
+ * Check the status of socket. Note that we will retry as long as we get
+ * EINTR.
+ */
+ do
+ result = kevent(kq, NULL, 0, &ret, 1, &timeout);
+ while (result < 0 && errno == EINTR);
+
+ /* Clean up the queue */
+ EV_SET(&kev, sock, EVFILT_READ, EV_DELETE, 0, 0, NULL);
+ kevent(kq, &kev, 1, NULL, 0, NULL);
+
+ if (result < 0)
+ return -1;
+
+ return ret.flags & EV_EOF;
#else
/* Do not support socket checking on this platform, return 0 */
return 0;
@@ -1281,7 +1325,8 @@ PQconnCheck(PGconn *conn)
int
PQcanConnCheck(void)
{
-#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+#if ((defined(HAVE_POLL) && defined(POLLRDHUP)) || \
+ defined(HAVE_KQUEUE))
return true;
#else
return false;
--
2.27.0
v29-0001-Add-PQconnCheck-and-PQcanConnCheck-to-libpq.patchapplication/octet-stream; name=v29-0001-Add-PQconnCheck-and-PQcanConnCheck-to-libpq.patchDownload
From 2f17e7ce900c17dd06b03aa891890b345917d303 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:18 +0000
Subject: [PATCH v29 1/4] Add PQconnCheck and PQcanConnCheck to libpq
PQconnCheck() function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQcanConnCheck() checks whether above function is available or not.
---
doc/src/sgml/libpq.sgml | 40 ++++++++++++++++++
src/interfaces/libpq/exports.txt | 2 +
src/interfaces/libpq/fe-misc.c | 69 ++++++++++++++++++++++++++++++++
src/interfaces/libpq/libpq-fe.h | 4 ++
4 files changed, 115 insertions(+)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 0e7ae70c70..5e07a252ce 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,46 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQconnCheck">
+ <term><function>PQconnCheck</function><indexterm><primary>PQconnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the status of the socket.
+
+<synopsis>
+int PQconnCheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQconnCheck"/> returns <literal>1</literal>
+ if the remote peer seems to be closed, returns <literal>0</literal> if
+ the socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid or an error is error occurred.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQcanConnCheck">
+ <term><function>PQcanConnCheck</function><indexterm><primary>PQcanConnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns whether <xref linkend="libpq-PQconnCheck"/> is available on this
+ platform. <xref linkend="libpq-PQcanConnCheck"/> returns
+ <literal>1</literal> if the function is supported, otherwise returns
+ <literal>0</literal>.
+
+<synopsis>
+int PQcanConnCheck(void);
+</synopsis>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..5c908bfe6e 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQconnCheck 187
+PQcanConnCheck 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..6e807e7c6a 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -1218,6 +1218,75 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Helper function for PQconnCheck().
+ *
+ * Return >0 if opposite side seems to be disconnected, 0 the socket is valid,
+ * and -1 if an error occurred.
+ */
+static int
+pqconnCheck_internal(int sock)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ struct pollfd input_fd;
+ int errflags = POLLHUP | POLLERR | POLLNVAL;
+ int result;
+
+ /* Prepare pollfd entry */
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP | errflags;
+ input_fd.revents = 0;
+
+ /*
+ * Check the status of socket. Note that we will retry as long as we get
+ * EINTR.
+ */
+ do
+ result = poll(&input_fd, 1, 0);
+ while (result < 0 && errno == EINTR);
+
+ if (result < 0)
+ return -1;
+
+ return input_fd.revents;
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad or an error occurred.
+ */
+int
+PQconnCheck(PGconn *conn)
+{
+ /* quick exit if invalid connection has come */
+ if (conn == NULL ||
+ conn->sock == PGINVALID_SOCKET ||
+ conn->status != CONNECTION_OK)
+ return -1;
+
+ return pqconnCheck_internal(conn->sock);
+}
+
+/*
+ * Check whether PQconnCheck() can work well on this platform.
+ *
+ * Returns 1 if this can use PQconnCheck(), otherwise 0.
+ */
+int
+PQcanConnCheck(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..04a0395efb 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQconnCheck(PGconn *conn);
+extern int PQcanConnCheck(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v29-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v29-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From f36effa4eb0045682249c2113afa354b3733a309 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v29 2/4] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQconnCheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if checked connection is still valid, or the checking is
not supported on this platform. False is returned if the connection seems
to be closed.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 124 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 19 +++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 69 ++++++++++
6 files changed, 215 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 7760380f00..1d7e350b33 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -87,6 +87,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -117,6 +120,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1832,3 +1836,123 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ /* quick exit if connection cache has not been initialized yet. */
+ if (!ConnectionHash)
+ return true;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQconnCheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message. */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+ }
+ }
+
+ /* Raise a warning if disconnections are found. */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of server.")));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found, and this returns
+ * false only when the verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
+
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(PQcanConnCheck());
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..a8556b4c9f
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,19 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 644f51835b..05265a1ef8 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -826,6 +826,75 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if checked connections are still valid,
+ or the checking is not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if all the remote connections are still
+ valid, or the checking is not supported on this platform.
+ <literal>false</literal> is returned if the local session seems to be
+ disconnected from at least one remote server. Example usage of the
+ function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether functions the health of remote connectio
+ work well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
On 2023-01-27 15:57, Hayato Kuroda (Fujitsu) wrote:
I found cfbot failure, PSA fixed version.
Sorry for noise.Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Hi Kuroda-san,
Thank you for updating the patch! Sorry for the late reply.
0001:
+ while (result < 0 && errno == EINTR);
+
+ if (result < 0)
+ return -1;
this `return -1` is not indented properly.
0002:
+ <term><function>postgres_fdw_verify_connection_states(server_name
text) returns boolean</function></term>
...
+ extension to the <symbol>poll</symbol> system call, including
Linux. This
+ returns <literal>true</literal> if checked connections are still
valid,
+ or the checking is not supported on this platform.
<literal>false</literal>
+ is returned if the local session seems to be disconnected from
other
+ servers. Example usage of the function:
Here, 'still valid' seems a little bit confusing because this 'valid' is
not
the same as postgres_fdw_get_connections's 'valid' [1]https://github.com/postgres/postgres/blob/master/doc/src/sgml/postgres-fdw.sgml#L764-L765.
Should 'still valid' be 'existing connection is not closed by the remote
peer'?
But this description does not cover all the cases where this function
returns true...
I think one choice is to write all the cases like 'returns true if any
of the
following condition is satisfied. 1) existing connection is not closed
by the
remote peer 2) there is no connection for specified server yet 3) the
checking
is not supported...'. If my understanding is not correct, please point
it out.
BTW, is it reasonable to return true if ConnectionHash is not
initialized or
there is no ConnCacheEntry for specified remote server? What do you
think
about returning NULL in that case?
0003:
I think it is better that the test covers all the new functions.
How about adding a test for postgres_fdw_verify_connection_states_all?
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
Writing all the functions' name like 'test for
postgres_fdw_verify_connection_states
and postgres_fdw_can_verify_connection_states' looks straightforward.
What do you think about this?
0004:
Sorry, I have not read 0004. I will read.
[1]: https://github.com/postgres/postgres/blob/master/doc/src/sgml/postgres-fdw.sgml#L764-L765
https://github.com/postgres/postgres/blob/master/doc/src/sgml/postgres-fdw.sgml#L764-L765
regards,
--
Katsuragi Yuta
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
At Fri, 27 Jan 2023 06:57:01 +0000, "Hayato Kuroda (Fujitsu)" <kuroda.hayato@fujitsu.com> wrote in
I found cfbot failure, PSA fixed version.
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
I find it quite confusing that we have pqSocketCheck and PQconnCheck,
that does almost the same thing.. Since pqSocketCheck is a static
function, we can modify the function as we like.
I still don't understand why we need pqconnCheck_internal separate
from pqSocketPoll(), and PQconnCheck from pqSocketCheck.
/messages/by-id/TYAPR01MB58665BF23D38EDF10028DE2AF5299@TYAPR01MB5866.jpnprd01.prod.outlook.com
IIUC, pqSocketCheck () calls pqSocketPoll(),
and in the pqSocketPoll() we poll()'d the POLLIN or POLLOUT event.
But according to [1], we must wait POLLRDHUP event,
so we cannot reuse it straightforward.
Yeah, I didn't suggest to use the function as-is. Couldn't we extend
the fucntion by letting it accept end_time = 0 && !forRead &&
!forWrite, not causing side effects?
regards.
--
Kyotaro Horiguchi
NTT Open Source Software Center
Dear Horiguchi-san,
Thank you for checking! The patch will be attached to another mail.
At Fri, 27 Jan 2023 06:57:01 +0000, "Hayato Kuroda (Fujitsu)"
<kuroda.hayato@fujitsu.com> wrote inI found cfbot failure, PSA fixed version.
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket + health. This check is performed by polling the socket. This function is + currently available only on systems that support the non-standard + <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> systemI find it quite confusing that we have pqSocketCheck and PQconnCheck,
that does almost the same thing.. Since pqSocketCheck is a static
function, we can modify the function as we like.
Renamed to pqSocketIsReadableOrWritableOrValid(), but seemed very bad...
I still don't understand why we need pqconnCheck_internal separate
from pqSocketPoll(), and PQconnCheck from pqSocketCheck.
pqconnCheck_internal() was combined into pqSocketPoll(), but PQconnCheck() still
exists. libpq-fe.h, did not include standard header files except stdio.h. I'm not
sure whether we can add an inclusion of time.h, because it may break the compatibility
that some platform may not have the header. If there are not such a system, we may
able to export pqSocketCheck() and remove PQconnCheck().
The side effect of this changes is that codes become dirty when we add kqueue() support...
/messages/by-id/TYAPR01MB58665BF23D38EDF1
0028DE2AF5299%40TYAPR01MB5866.jpnprd01.prod.outlook.com#47d21431bf9
fa94f763c824f6e81fa54IIUC, pqSocketCheck () calls pqSocketPoll(),
and in the pqSocketPoll() we poll()'d the POLLIN or POLLOUT event.
But according to [1], we must wait POLLRDHUP event,
so we cannot reuse it straightforward.Yeah, I didn't suggest to use the function as-is. Couldn't we extend
the fucntion by letting it accept end_time = 0 && !forRead &&
!forWrite, not causing side effects?
Modified accordingly. Is it what you expected?
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Dear Katsuragi-san,
Thank you for reviewing! PSA new version patches.
0001: + while (result < 0 && errno == EINTR); + + if (result < 0) + return -1;this `return -1` is not indented properly.
This part is no longer needed. Please see another discussion[1]/messages/by-id/TYAPR01MB58664E039F45959AB321FA1FF5D99@TYAPR01MB5866.jpnprd01.prod.outlook.com.
0002: + <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term> ... + extension to the <symbol>poll</symbol> system call, including Linux. This + returns <literal>true</literal> if checked connections are still valid, + or the checking is not supported on this platform. <literal>false</literal> + is returned if the local session seems to be disconnected from other + servers. Example usage of the function:Here, 'still valid' seems a little bit confusing because this 'valid' is
not
the same as postgres_fdw_get_connections's 'valid' [1].Should 'still valid' be 'existing connection is not closed by the remote
peer'?
But this description does not cover all the cases where this function
returns true...
I think one choice is to write all the cases like 'returns true if any
of the
following condition is satisfied. 1) existing connection is not closed
by the
remote peer 2) there is no connection for specified server yet 3) the
checking
is not supported...'. If my understanding is not correct, please point
it out.
Modified like you pointed out.
BTW, is it reasonable to return true if ConnectionHash is not
initialized or
there is no ConnCacheEntry for specified remote server? What do you
think
about returning NULL in that case?
I'm not sure which one is better, but modified accordingly.
0003:
I think it is better that the test covers all the new functions.
How about adding a test for postgres_fdw_verify_connection_states_all?+-- =================================================== ================ +-- test for postgres_fdw_verify_foreign_servers function +-- =================================================== ================Writing all the functions' name like 'test for
postgres_fdw_verify_connection_states
and postgres_fdw_can_verify_connection_states' looks straightforward.
What do you think about this?
Added.
0004:
Sorry, I have not read 0004. I will read.
No problem:-).
[1]: /messages/by-id/TYAPR01MB58664E039F45959AB321FA1FF5D99@TYAPR01MB5866.jpnprd01.prod.outlook.com
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v31-0001-Add-PQconnCheck-and-PQcanConnCheck-to-libpq.patchapplication/octet-stream; name=v31-0001-Add-PQconnCheck-and-PQcanConnCheck-to-libpq.patchDownload
From f363393138f78d087d8e319d0eccdf04adc2bc00 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:18 +0000
Subject: [PATCH v31 1/4] Add PQconnCheck and PQcanConnCheck to libpq
PQconnCheck() function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQcanConnCheck() checks whether above function is available or not.
---
doc/src/sgml/libpq.sgml | 41 +++++++++++++++++++++
src/interfaces/libpq/exports.txt | 2 ++
src/interfaces/libpq/fe-misc.c | 61 +++++++++++++++++++++++++++-----
src/interfaces/libpq/libpq-fe.h | 4 +++
4 files changed, 99 insertions(+), 9 deletions(-)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 0e7ae70c70..f49b6e7452 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,47 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQconnCheck">
+ <term><function>PQconnCheck</function><indexterm><primary>PQconnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the health of the socket.
+
+<synopsis>
+int PQconnCheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
+ health. This check is performed by polling the socket. This function is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <xref linkend="libpq-PQconnCheck"/> returns
+ greater than zero if the remote peer seems to be closed, returns
+ <literal>0</literal> if the socket is valid, and returns
+ <literal>-1</literal> if the connection has been already invalid or
+ an error is error occurred.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQcanConnCheck">
+ <term><function>PQcanConnCheck</function><indexterm><primary>PQcanConnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns whether <xref linkend="libpq-PQconnCheck"/> is available on
+ this platform. <xref linkend="libpq-PQcanConnCheck"/> returns
+ <literal>1</literal> if the function is supported, otherwise returns
+ <literal>0</literal>.
+
+<synopsis>
+int PQcanConnCheck(void);
+</synopsis>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..5c908bfe6e 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQconnCheck 187
+PQcanConnCheck 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..3bcd760cd7 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -53,8 +53,8 @@
static int pqPutMsgBytes(const void *buf, size_t len, PGconn *conn);
static int pqSendSome(PGconn *conn, int len);
-static int pqSocketCheck(PGconn *conn, int forRead, int forWrite,
- time_t end_time);
+static int pqSocketIsReadableOrWritableOrValid(PGconn *conn, int forRead,
+ int forWrite, time_t end_time);
static int pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time);
/*
@@ -993,7 +993,7 @@ pqWaitTimed(int forRead, int forWrite, PGconn *conn, time_t finish_time)
{
int result;
- result = pqSocketCheck(conn, forRead, forWrite, finish_time);
+ result = pqSocketIsReadableOrWritableOrValid(conn, forRead, forWrite, finish_time);
if (result < 0)
return -1; /* errorMessage is already set */
@@ -1014,7 +1014,7 @@ pqWaitTimed(int forRead, int forWrite, PGconn *conn, time_t finish_time)
int
pqReadReady(PGconn *conn)
{
- return pqSocketCheck(conn, 1, 0, (time_t) 0);
+ return pqSocketIsReadableOrWritableOrValid(conn, 1, 0, (time_t) 0);
}
/*
@@ -1024,7 +1024,7 @@ pqReadReady(PGconn *conn)
int
pqWriteReady(PGconn *conn)
{
- return pqSocketCheck(conn, 0, 1, (time_t) 0);
+ return pqSocketIsReadableOrWritableOrValid(conn, 0, 1, (time_t) 0);
}
/*
@@ -1034,9 +1034,13 @@ pqWriteReady(PGconn *conn)
*
* If SSL is in use, the SSL buffer is checked prior to checking the socket
* for read data directly.
+ *
+ * Moreover, when neither forRead nor forWrite is requested and timeout is
+ * disabled, try to check the health of socket.
*/
static int
-pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
+pqSocketIsReadableOrWritableOrValid(PGconn *conn, int forRead, int forWrite,
+ time_t end_time)
{
int result;
@@ -1082,20 +1086,33 @@ pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
*
* Timeout is infinite if end_time is -1. Timeout is immediate (no blocking)
* if end_time is 0 (or indeed, any time before now).
+ *
+ * Moreover, when neither forRead nor forWrite is requested and timeout is
+ * disabled, try to check the health of socket.
*/
static int
pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
{
/* We use poll(2) if available, otherwise select(2) */
#ifdef HAVE_POLL
- struct pollfd input_fd;
+ struct pollfd input_fd = {0};
int timeout_ms;
if (!forRead && !forWrite)
- return 0;
+ {
+ /* Try to check the health if requested */
+ if (end_time == 0)
+#if defined(POLLRDHUP)
+ input_fd.events = POLLRDHUP | POLLHUP | POLLNVAL;
+#else
+ return 0;
+#endif /* defined(POLLRDHUP) */
+ else
+ return 0;
+ }
input_fd.fd = sock;
- input_fd.events = POLLERR;
+ input_fd.events |= POLLERR;
input_fd.revents = 0;
if (forRead)
@@ -1218,6 +1235,32 @@ PQenv2encoding(void)
return encoding;
}
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad or an error occurred.
+ */
+int
+PQconnCheck(PGconn *conn)
+{
+ return pqSocketIsReadableOrWritableOrValid(conn, 0, 0, (time_t) 0);
+}
+
+/*
+ * Check whether PQconnCheck() can work well on this platform.
+ *
+ * Returns 1 if this can use PQconnCheck(), otherwise 0.
+ */
+int
+PQcanConnCheck(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
#ifdef ENABLE_NLS
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..04a0395efb 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQconnCheck(PGconn *conn);
+extern int PQcanConnCheck(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v31-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v31-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From afc83105b6d734e93d54504df9be7734386a57b1 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v31 2/4] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQconnCheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if any of the following condition is satisfied: 1) existing
connection is not closed by the remote peer, 2) there is no connection for specified
server yet, and 3) the checking is not supported on this platform.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 131 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 19 +++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 74 ++++++++++
6 files changed, 227 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 7760380f00..602d810c08 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -87,6 +87,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -117,6 +120,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1832,3 +1836,130 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ Assert(ConnectionHash);
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQconnCheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message. */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+ }
+ }
+
+ /* Raise a warning if disconnections are found. */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of server.")));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found. This returns
+ * false only when the verified server seems to be disconnected, and reutrns
+ * NULL if the connection cache has not been initialized yet.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ /* quick exit if connection cache has not been initialized yet. */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ /* quick exit if connection cache has not been initialized yet. */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
+
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(PQcanConnCheck());
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..a8556b4c9f
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,19 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 644f51835b..e1abdb38cb 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -826,6 +826,80 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if any of the following condition is
+ satisfied: 1) existing connection is not closed by the remote peer, 2)
+ there is no connection for specified server yet, and 3) the checking is
+ not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. <literal>NULL</literal> is returned if the local session does
+ not have a connection cache. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if any of the following condition is
+ satisfied: 1) all connections are not closed by the remote peer, 2)
+ there are no connections yet, and 3) the checking is
+ not supported on this platform. <literal>false</literal> is returned if
+ the local session seems to be disconnected from at least one remote
+ server. <literal>NULL</literal> is returned if the local session does
+ not have a connection cache. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether functions the health of remote connectio
+ work well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v31-0003-add-test.patchapplication/octet-stream; name=v31-0003-add-test.patchDownload
From 3ed051dd7e6c75194a043eaa643f70f2fd6f514d Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:36 +0000
Subject: [PATCH v31 3/4] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 64 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 62 ++++++++++++++++++
2 files changed, 126 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index d5fc61446a..d9926b3857 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11798,3 +11798,67 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+-- ..And call above function
+CALL test_verify_function(false);
+INFO: 00000
+ERROR: 08006
+CALL test_verify_function(true);
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 1e50be137b..81c03d0869 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3974,3 +3974,65 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+-- ..And call above function
+CALL test_verify_function(false);
+CALL test_verify_function(true);
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
v31-0004-add-kqueue-support-for-PQconnCheck-and-PQcanConn.patchapplication/octet-stream; name=v31-0004-add-kqueue-support-for-PQconnCheck-and-PQcanConn.patchDownload
From f87cf8bfbcf943b21fd84c8b12b00d92f5367b1d Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Thu, 9 Feb 2023 11:58:35 +0000
Subject: [PATCH v31 4/4] add kqueue support for PQconnCheck and PQcanConnCheck
---
doc/src/sgml/libpq.sgml | 16 +++----
doc/src/sgml/postgres-fdw.sgml | 34 +++++++-------
src/interfaces/libpq/fe-misc.c | 84 ++++++++++++++++++++++++++++++++--
3 files changed, 106 insertions(+), 28 deletions(-)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index f49b6e7452..2abc2ed508 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2692,14 +2692,14 @@ int PQconnCheck(PGconn *conn);
<para>
Unlike <xref linkend="libpq-PQstatus"/>, this function checks socket
- health. This check is performed by polling the socket. This function is
- currently available only on systems that support the non-standard
- <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
- call, including Linux. <xref linkend="libpq-PQconnCheck"/> returns
- greater than zero if the remote peer seems to be closed, returns
- <literal>0</literal> if the socket is valid, and returns
- <literal>-1</literal> if the connection has been already invalid or
- an error is error occurred.
+ health. This check is performed by polling the socket. This check is
+ performed by polling the socket. This option relies on kernel events
+ exposed by Linux, macOS, illumos and the BSD family of operating
+ systems, and is not currently available on other systems
+ <xref linkend="libpq-PQconnCheck"/> returns greater than zero if the
+ remote peer seems to be closed, returns <literal>0</literal> if the
+ socket is valid, and returns <literal>-1</literal> if the connection
+ has been already invalid or an error is error occurred.
</para>
</listitem>
</varlistentry>
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index e1abdb38cb..75ca74a16e 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -835,13 +835,13 @@ postgres=# SELECT postgres_fdw_disconnect_all();
<filename>postgres_fdw</filename> from the local session to the foreign
server with the given name. This check is performed by polling the socket
and allows long-running transactions to be aborted sooner if the kernel
- reports that the connection is closed. This function is currently
- available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
- extension to the <symbol>poll</symbol> system call, including Linux. This
- returns <literal>true</literal> if any of the following condition is
- satisfied: 1) existing connection is not closed by the remote peer, 2)
- there is no connection for specified server yet, and 3) the checking is
- not supported on this platform. <literal>false</literal>
+ reports that the connection is closed. This check is performed by polling
+ the socket. This option relies on kernel events exposed by Linux, macOS,
+ illumos and the BSD family of operating systems, and is not currently
+ available on other systems. This returns <literal>true</literal> if any
+ of the following condition is satisfied: 1) existing connection is not
+ closed by the remote peer, 2) there is no connection for specified server
+ yet, and 3) the checking is not supported on this platform. <literal>false</literal>
is returned if the local session seems to be disconnected from other
servers. <literal>NULL</literal> is returned if the local session does
not have a connection cache. Example usage of the function:
@@ -862,16 +862,16 @@ postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
by <filename>postgres_fdw</filename> from the local session to the
foreign servers. This check is performed by polling the socket and allows
long-running transactions to be aborted sooner if the kernel reports
- that the connection is closed. This function is currently available only
- on systems that support the non-standard <symbol>POLLRDHUP</symbol>
- extension to the <symbol>poll</symbol> system call, including Linux. This
- returns <literal>true</literal> if any of the following condition is
- satisfied: 1) all connections are not closed by the remote peer, 2)
- there are no connections yet, and 3) the checking is
- not supported on this platform. <literal>false</literal> is returned if
- the local session seems to be disconnected from at least one remote
- server. <literal>NULL</literal> is returned if the local session does
- not have a connection cache. Example usage of the function:
+ that the connection is closed. This check is performed by polling the
+ socket. This option relies on kernel events exposed by Linux, macOS,
+ illumos and the BSD family of operating systems, and is not currently
+ available on other systems. This returns <literal>true</literal> if any
+ of the following condition is satisfied: 1) all connections are not
+ closed by the remote peer, 2) there are no connections yet, and 3) the
+ checking is not supported on this platform. <literal>false</literal> is
+ returned if the local session seems to be disconnected from at least one
+ remote server. <literal>NULL</literal> is returned if the local session
+ does not have a connection cache. Example usage of the function:
<screen>
postgres=# SELECT postgres_fdw_verify_connection_states_all();
postgres_fdw_verify_connection_states_all
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3bcd760cd7..caa33cd2e4 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -45,6 +45,18 @@
#include <poll.h>
#endif
+/* We use poll(2) for checking the health of a socket, otherwise kqueue(2) */
+#if (!(defined(HAVE_POLL) && defined(POLLRDHUP)) && \
+ defined(HAVE_KQUEUE))
+#define CHECK_USE_KQUEUE
+#endif
+
+#if defined(CHECK_USE_KQUEUE)
+#include <sys/types.h>
+#include <sys/event.h>
+#include <sys/time.h>
+#endif
+
#include "libpq-fe.h"
#include "libpq-int.h"
#include "mb/pg_wchar.h"
@@ -57,6 +69,10 @@ static int pqSocketIsReadableOrWritableOrValid(PGconn *conn, int forRead,
int forWrite, time_t end_time);
static int pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time);
+#if defined(CHECK_USE_KQUEUE)
+static int pqSocketKqueue(int sock);
+#endif
+
/*
* PQlibVersion: return the libpq version number
*/
@@ -1104,9 +1120,12 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
if (end_time == 0)
#if defined(POLLRDHUP)
input_fd.events = POLLRDHUP | POLLHUP | POLLNVAL;
+#elif defined(CHECK_USE_KQUEUE)
+ /* Use kqueue(2) instead */
+ return pqSocketKqueue(sock);
#else
return 0;
-#endif /* defined(POLLRDHUP) */
+#endif
else
return 0;
}
@@ -1143,7 +1162,22 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
struct timeval *ptr_timeout;
if (!forRead && !forWrite)
- return 0;
+ {
+ /*
+ * Try to check the health if requested
+ *
+ * XXX: Is there any systems that cannot use poll(2) but have
+ * kqueue(2) system call?
+ */
+ if (end_time == 0)
+#if defined(CHECK_USE_KQUEUE)
+ return pqSocketKqueue(sock);
+#else
+ return 0;
+#endif /* defined(CHECK_USE_KQUEUE) */
+ else
+ return 0;
+ }
FD_ZERO(&input_mask);
FD_ZERO(&output_mask);
@@ -1175,6 +1209,49 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
#endif /* HAVE_POLL */
}
+#if defined(CHECK_USE_KQUEUE)
+static int
+pqSocketKqueue(int sock)
+{
+ struct kevent kev,
+ ret;
+ struct timespec timeout = {0};
+ static int kq = -1;
+ int result;
+
+ /* If this function has never called yet, create a kernel event queue */
+ if (kq < 0)
+ {
+ kq = kqueue();
+ if (kq < 0)
+ return -1;
+ }
+
+ /* Prepare kevent structure */
+ EV_SET(&kev, sock, EVFILT_READ, EV_ADD, 0, 0, NULL);
+ if (kevent(kq, &kev, 1, NULL, 0, NULL))
+ return -1;
+
+ /*
+ * Check the status of socket. Note that we will retry as long as we get
+ * EINTR.
+ */
+ do
+ result = kevent(kq, NULL, 0, &ret, 1, &timeout);
+ while (result < 0 && errno == EINTR);
+
+ /* Clean up the queue */
+ EV_SET(&kev, sock, EVFILT_READ, EV_DELETE, 0, 0, NULL);
+ kevent(kq, &kev, 1, NULL, 0, NULL);
+
+ if (result < 0)
+ return -1;
+
+ printf("debug print");
+
+ return ret.flags & EV_EOF;
+}
+#endif /* defined(CHECK_USE_KQUEUE) */
/*
* A couple of "miscellaneous" multibyte related functions. They used
@@ -1255,7 +1332,8 @@ PQconnCheck(PGconn *conn)
int
PQcanConnCheck(void)
{
-#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+#if ((defined(HAVE_POLL) && defined(POLLRDHUP)) || \
+ defined(CHECK_USE_KQUEUE))
return true;
#else
return false;
--
2.27.0
On 2023-02-09 23:39, Hayato Kuroda (Fujitsu) wrote:
Dear Katsuragi-san,
Thank you for reviewing! PSA new version patches.
Thank you for updating the patch! These are my comments,
please check.
0001:
Extending pqSocketPoll seems to be a better way because we can
avoid having multiple similar functions. I also would like to hear
horiguchi-san's opinion whether this matches his expectation.
Improvements of pqSocketPoll/pqSocketCheck is discussed in this
thread[1]/messages/by-id/20230209.115009.2229702014236187289.horikyota.ntt@gmail.com. I'm concerned with the discussion.
As for the function's name, what do you think about keeping
current name (pqSocketCheck)? pqSocketIsReadable... describes
the functionality very well though.
pqConnCheck seems to be a family of pqReadReady or pqWriteRedy,
so how about placing pqConnCheck below them?
+ * Moreover, when neither forRead nor forWrite is requested and timeout
is
+ * disabled, try to check the health of socket.
Isn't it better to put the comment on how the arguments are
interpreted before the description of return value?
+#if defined(POLLRDHUP)
+ input_fd.events = POLLRDHUP | POLLHUP | POLLNVAL;
...
+ input_fd.events |= POLLERR;
To my understanding, POLLHUP, POLLNVAL and POLLERR are ignored
in event. Are they necessary?
0002:
As for the return value of postgres_fdw_verify_connection_states,
what do you think about returning NULL when connection-checking
is not performed? I think there are two cases 1) ConnectionHash
is not initialized or 2) connection is not found for specified
server name, That is, no entry passes the first if statement below
(case 2)).
```
if (all || entry->serverid == serverid)
{
if (PQconnCheck(entry->conn))
{
```
0004:
I'm wondering if we should add kqueue support in this version,
because adding kqueue support introduces additional things to
be considered. What do you think about focusing on the main
functionality using poll in this patch and going for kqueue
support after this patch?
[1]: /messages/by-id/20230209.115009.2229702014236187289.horikyota.ntt@gmail.com
/messages/by-id/20230209.115009.2229702014236187289.horikyota.ntt@gmail.com
regards,
--
Katsuragi Yuta
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Here is a code review only for patch v31-0001.
======
General Comment
1.
PQcanConnCheck seemed like a strange API name. Maybe it can have the
same prefix as the other?
e.g.
- PQconnCheck()
- PGconnCheckSupported()
or
- PQconnCheck()
- PGconnCheckable()
======
Commit Message
2.
PqconnCheck() function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PqcanConnCheck() checks whether above function is available or not.
~
2a.
"status of socket" --> "status of the connection"
~
2b.
"above function" --> "the above function"
======
doc/src/sgml/libpq.sgml
3. PQconnCheck
Returns the health of the socket.
int PQconnCheck(PGconn *conn);
Unlike PQstatus, this function checks socket health. This check is
performed by polling the socket. This function is currently available
only on systems that support the non-standard POLLRDHUP extension to
the poll system call, including Linux. PQconnCheck returns greater
than zero if the remote peer seems to be closed, returns 0 if the
socket is valid, and returns -1 if the connection has been already
invalid or an error is error occurred.
~
3a.
Should these descriptions be referring to the health of the
*connection* rather than the health of the socket?
~
3b.
"has been already invalid" ?? wording
~~~
4. PQcanConnCheck
Returns whether PQconnCheck is available on this platform.
PQcanConnCheck returns 1 if the function is supported, otherwise
returns 0.
~
I thought this should be worded using "true" and "false" same as other
boolean functions on this page.
SUGGESTION
Returns true (1) or false (0) to indicate if the PQconnCheck function
is supported on this platform.
======
src/interfaces/libpq/fe-misc.c
5.
-static int pqSocketCheck(PGconn *conn, int forRead, int forWrite,
- time_t end_time);
+static int pqSocketIsReadableOrWritableOrValid(PGconn *conn, int forRead,
+ int forWrite, time_t end_time);
I was not 100% sure overloading this API is the right thing to do.
Doesn't this introduce a subtle side-effect on some of the existing
callers? e.g. Previously pqWaitTimed would ALWAYS return 0 if
forRead/forWrite were both false. But now other return values like
errors will be possible. Is that OK?
~~~
6. pqSocketPoll
/*
* Check a file descriptor for read and/or write data, possibly waiting.
* If neither forRead nor forWrite are set, immediately return a timeout
* condition (without waiting). Return >0 if condition is met, 0
* if a timeout occurred, -1 if an error or interrupt occurred.
*
* Timeout is infinite if end_time is -1. Timeout is immediate (no blocking)
* if end_time is 0 (or indeed, any time before now).
*
* Moreover, when neither forRead nor forWrite is requested and timeout is
* disabled, try to check the health of socket.
*/
The new comment "Moreover..." is contrary to the earlier part of the
same comment which already said, "If neither forRead nor forWrite are
set, immediately return a timeout condition (without waiting)."
There might be side-effects to previous/existing callers of this
function (e.g. pqWaitTimed via pqSocketCheck)
~~~
7.
if (!forRead && !forWrite)
- return 0;
+ {
+ /* Try to check the health if requested */
+ if (end_time == 0)
+#if defined(POLLRDHUP)
+ input_fd.events = POLLRDHUP | POLLHUP | POLLNVAL;
+#else
+ return 0;
+#endif /* defined(POLLRDHUP) */
+ else
+ return 0;
+ }
FYI - I think the new code can be simpler without needing #else by
calling your other new function.
SUGGESTION
if (!forRead && !forWrite)
{
if (!PQcanConnCheck() || end_time != 0)
return 0;
/* Check the connection health when end_time is 0 */
Assert(PQcanConnCheck() && end_time == 0);
#if defined(POLLRDHUP)
input_fd.events = POLLRDHUP | POLLHUP | POLLNVAL;
#endif
}
~~~
8. PQconnCheck
+/*
+ * Check whether PQconnCheck() can work well on this platform.
+ *
+ * Returns 1 if this can use PQconnCheck(), otherwise 0.
+ */
+int
+PQcanConnCheck(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
~
8a.
"can work well" --> "works"
~
8b.
Maybe better to say "true (1)" and "otherwise false (0)"
------
Kind Regards,
Peter Smith.
Fujitsu Australia
Dear Katsuragi-san,
Thank you for reviewing! PSA new version.
0001:
Extending pqSocketPoll seems to be a better way because we can
avoid having multiple similar functions. I also would like to hear
horiguchi-san's opinion whether this matches his expectation.
Improvements of pqSocketPoll/pqSocketCheck is discussed in this
thread[1]. I'm concerned with the discussion.
I checked the thread and seems correct. I can post +1 to the thread.
And the modification will be automatically reflected to the feature
if we use the same function, I thought.
As for the function's name, what do you think about keeping
current name (pqSocketCheck)? pqSocketIsReadable... describes
the functionality very well though.
No objection, I can keep the shorter name.
pqConnCheck seems to be a family of pqReadReady or pqWriteRedy,
so how about placing pqConnCheck below them?
Moved.
+ * Moreover, when neither forRead nor forWrite is requested and timeout is + * disabled, try to check the health of socket. Isn't it better to put the comment on how the arguments are interpreted before the description of return value?+#if defined(POLLRDHUP) + input_fd.events = POLLRDHUP | POLLHUP | POLLNVAL; ... + input_fd.events |= POLLERR; To my understanding, POLLHUP, POLLNVAL and POLLERR are ignored in event. Are they necessary?
I read man poll(3) again, and I found that these event is ignored when
it sets to the events attribute. So removed.
0002:
As for the return value of postgres_fdw_verify_connection_states,
what do you think about returning NULL when connection-checking
is not performed? I think there are two cases 1) ConnectionHash
is not initialized or 2) connection is not found for specified
server name, That is, no entry passes the first if statement below
(case 2)).```
if (all || entry->serverid == serverid)
{
if (PQconnCheck(entry->conn))
{
```
I think in that case we can follow postgres_fdw_disconnect().
About postgres_fdw_disconnect(), if the given server_name does not exist,
an error is reported. This is a current behavior so I want to keep it.
Besides, I added the description to document.
0004:
I'm wondering if we should add kqueue support in this version,
because adding kqueue support introduces additional things to
be considered. What do you think about focusing on the main
functionality using poll in this patch and going for kqueue
support after this patch?
I think it is better because it can keep patches smaller. So I stopped attaching 0004.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v32-0001-Add-PQconnCheck-and-PQconnCheckable-to-libpq.patchapplication/octet-stream; name=v32-0001-Add-PQconnCheck-and-PQconnCheckable-to-libpq.patchDownload
From 9d8dbbf978cf681daf13f6c3bc7768709d6fa5d9 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:18 +0000
Subject: [PATCH v32 1/3] Add PQconnCheck and PQconnCheckable to libpq
PQconnCheck() function allows to check the status of the socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQconnCheckable() checks whether the above function is available or not.
---
doc/src/sgml/libpq.sgml | 38 ++++++++++++++++++++
src/interfaces/libpq/exports.txt | 2 ++
src/interfaces/libpq/fe-misc.c | 62 ++++++++++++++++++++++++++------
src/interfaces/libpq/libpq-fe.h | 4 +++
4 files changed, 96 insertions(+), 10 deletions(-)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 0e7ae70c70..e5e2662996 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,44 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQconnCheck">
+ <term><function>PQconnCheck</function><indexterm><primary>PQconnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the health of the connection.
+
+<synopsis>
+int PQconnCheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ This function check the health of the connection. Unlike <xref linkend="libpq-PQstatus"/>,
+ this check is performed by polling the corresponding socket. This
+ function is currently available only on systems that support the
+ non-standard <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol>
+ system call, including Linux. <xref linkend="libpq-PQconnCheck"/>
+ returns greater than zero if the remote peer seems to be closed, returns
+ <literal>0</literal> if the socket is valid, and returns <literal>-1</literal>
+ if the connection has already been closed or an error has occurred.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQconnCheckable">
+ <term><function>PQconnCheckable</function><indexterm><primary>PQconnCheckable</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns true (1) or false (0) to indicate if the PQconnCheck function
+ is supported on this platform.
+
+<synopsis>
+int PQconnCheckable(void);
+</synopsis>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..a06dea9acd 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQconnCheck 187
+PQconnCheckable 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..4311d1d21c 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -53,8 +53,8 @@
static int pqPutMsgBytes(const void *buf, size_t len, PGconn *conn);
static int pqSendSome(PGconn *conn, int len);
-static int pqSocketCheck(PGconn *conn, int forRead, int forWrite,
- time_t end_time);
+static int pqSocketCheck(PGconn *conn, int forRead,
+ int forWrite, time_t end_time);
static int pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time);
/*
@@ -1027,9 +1027,39 @@ pqWriteReady(PGconn *conn)
return pqSocketCheck(conn, 0, 1, (time_t) 0);
}
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad or an error occurred.
+ */
+int
+PQconnCheck(PGconn *conn)
+{
+ return pqSocketCheck(conn, 0, 0, (time_t) 0);
+}
+
+/*
+ * Check whether PQconnCheck() works well on this platform.
+ *
+ * Returns true (1) if this can use PQconnCheck(), otherwise false (0).
+ */
+int
+PQconnCheckable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
+
/*
* Checks a socket, using poll or select, for data to be read, written,
- * or both. Returns >0 if one or more conditions are met, 0 if it timed
+ * or both. Moreover, when neither forRead nor forWrite is requested and
+ * timeout is disabled, try to check the health of socket.
+ *
+ * Returns >0 if one or more conditions are met, 0 if it timed
* out, -1 if an error occurred.
*
* If SSL is in use, the SSL buffer is checked prior to checking the socket
@@ -1076,9 +1106,13 @@ pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
/*
* Check a file descriptor for read and/or write data, possibly waiting.
- * If neither forRead nor forWrite are set, immediately return a timeout
- * condition (without waiting). Return >0 if condition is met, 0
- * if a timeout occurred, -1 if an error or interrupt occurred.
+ * When neither forRead nor forWrite are set and timeout is disabled,
+ *
+ * - If the timeout is disabled, try to check the health of the socket
+ * - Otherwise this immediately returns 0
+ *
+ * Return >0 if condition is met, 0 if a timeout occurred, -1 if an error
+ * or interrupt occurred.
*
* Timeout is infinite if end_time is -1. Timeout is immediate (no blocking)
* if end_time is 0 (or indeed, any time before now).
@@ -1088,14 +1122,23 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
{
/* We use poll(2) if available, otherwise select(2) */
#ifdef HAVE_POLL
- struct pollfd input_fd;
+ struct pollfd input_fd = {0};
int timeout_ms;
if (!forRead && !forWrite)
- return 0;
+ {
+ if (!PQconnCheckable() || end_time != 0)
+ return 0;
+
+ /* Check the connection health when end_time is 0 */
+ Assert(PQconnCheckable() && end_time == 0);
+#if defined(POLLRDHUP)
+ input_fd.events = POLLRDHUP;
+#endif
+ }
input_fd.fd = sock;
- input_fd.events = POLLERR;
+ input_fd.events |= POLLERR;
input_fd.revents = 0;
if (forRead)
@@ -1218,7 +1261,6 @@ PQenv2encoding(void)
return encoding;
}
-
#ifdef ENABLE_NLS
static void
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..e1bd0cd7b7 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQconnCheck(PGconn *conn);
+extern int PQconnCheckable(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v32-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v32-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From 53136332097686c28b09455165ff1cfc0d4f9c43 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v32 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQconnCheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if any of the following condition is satisfied: 1) existing
connection is not closed by the remote peer, 2) there is no connection for specified
server yet, and 3) the checking is not supported on this platform.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 131 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 19 +++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 75 ++++++++++
6 files changed, 228 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 7760380f00..36801fd978 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -87,6 +87,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -117,6 +120,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1832,3 +1836,130 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ Assert(ConnectionHash);
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQconnCheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message. */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+ }
+ }
+
+ /* Raise a warning if disconnections are found. */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of server.")));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found. This returns
+ * false only when the verified server seems to be disconnected, and reutrns
+ * NULL if the connection cache has not been initialized yet.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+
+ /* quick exit if connection cache has not been initialized yet. */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ PG_RETURN_BOOL(verify_cached_connections(server->serverid));
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ /* quick exit if connection cache has not been initialized yet. */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ PG_RETURN_BOOL(verify_cached_connections(InvalidOid));
+}
+
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(PQconnCheckable());
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..a8556b4c9f
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,19 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 644f51835b..e2b3d63422 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -826,6 +826,81 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if any of the following condition is
+ satisfied: 1) existing connection is not closed by the remote peer, 2)
+ there is no connection for specified server yet, and 3) the checking is
+ not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. <literal>NULL</literal> is returned if the local session does
+ not have a connection cache. If no foreign server with the given name is
+ found, an error is reported. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if any of the following condition is
+ satisfied: 1) all connections are not closed by the remote peer, 2)
+ there are no connections yet, and 3) the checking is
+ not supported on this platform. <literal>false</literal> is returned if
+ the local session seems to be disconnected from at least one remote
+ server. <literal>NULL</literal> is returned if the local session does
+ not have a connection cache. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether functions the health of remote connectio
+ work well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v32-0003-add-test.patchapplication/octet-stream; name=v32-0003-add-test.patchDownload
From ddd7cae776b041310b7abaced3975ffa1f24c017 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:36 +0000
Subject: [PATCH v32 3/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 64 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 62 ++++++++++++++++++
2 files changed, 126 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index d5fc61446a..d9926b3857 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11798,3 +11798,67 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+-- ..And call above function
+CALL test_verify_function(false);
+INFO: 00000
+ERROR: 08006
+CALL test_verify_function(true);
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 1e50be137b..81c03d0869 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3974,3 +3974,65 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+-- ..And call above function
+CALL test_verify_function(false);
+CALL test_verify_function(true);
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
Dear Peter,
Thank you for reviewing! Latest version can be seen in [1]/messages/by-id/TYAPR01MB58669C95604A0EB7BCC1B58CF5A49@TYAPR01MB5866.jpnprd01.prod.outlook.com.
1.
PQcanConnCheck seemed like a strange API name. Maybe it can have the
same prefix as the other?e.g.
- PQconnCheck()
- PGconnCheckSupported()or
- PQconnCheck()
- PGconnCheckable()
I choose PQconnCheckable().
2.
PqconnCheck() function allows to check the status of socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.PqcanConnCheck() checks whether above function is available or not.
~
2a.
"status of socket" --> "status of the connection"~
2b.
"above function" --> "the above function"
Fixed.
doc/src/sgml/libpq.sgml
3. PQconnCheck
Returns the health of the socket.
int PQconnCheck(PGconn *conn);
Unlike PQstatus, this function checks socket health. This check is
performed by polling the socket. This function is currently available
only on systems that support the non-standard POLLRDHUP extension to
the poll system call, including Linux. PQconnCheck returns greater
than zero if the remote peer seems to be closed, returns 0 if the
socket is valid, and returns -1 if the connection has been already
invalid or an error is error occurred.~
3a.
Should these descriptions be referring to the health of the
*connection* rather than the health of the socket?
Reworded.
3b.
"has been already invalid" ?? wording
I checked codes and found that the socket becomes PGINVALID_SOCKET
after being closed. So I clarified that.
4. PQcanConnCheck
Returns whether PQconnCheck is available on this platform.
PQcanConnCheck returns 1 if the function is supported, otherwise
returns 0.~
I thought this should be worded using "true" and "false" same as other
boolean functions on this page.SUGGESTION
Returns true (1) or false (0) to indicate if the PQconnCheck function
is supported on this platform.
Fixed.
======
src/interfaces/libpq/fe-misc.c5. -static int pqSocketCheck(PGconn *conn, int forRead, int forWrite, - time_t end_time); +static int pqSocketIsReadableOrWritableOrValid(PGconn *conn, int forRead, + int forWrite, time_t end_time);I was not 100% sure overloading this API is the right thing to do.
Doesn't this introduce a subtle side-effect on some of the existing
callers? e.g. Previously pqWaitTimed would ALWAYS return 0 if
forRead/forWrite were both false. But now other return values like
errors will be possible. Is that OK?
I checked pqWaitTimed() and seems not to affect other parts.
As the first place, it is an internal function and will be never called from clients.
There are 2 functions that call that - connectDBComplete() and pqWait(), and both of
them are not set finish_time to zero. In connectDBComplete(), basically finish_time
is set to -1, and set to time(NULL) + connect_timeout if the timeout is enabled.
6. pqSocketPoll
/*
* Check a file descriptor for read and/or write data, possibly waiting.
* If neither forRead nor forWrite are set, immediately return a timeout
* condition (without waiting). Return >0 if condition is met, 0
* if a timeout occurred, -1 if an error or interrupt occurred.
*
* Timeout is infinite if end_time is -1. Timeout is immediate (no blocking)
* if end_time is 0 (or indeed, any time before now).
*
* Moreover, when neither forRead nor forWrite is requested and timeout is
* disabled, try to check the health of socket.
*/The new comment "Moreover..." is contrary to the earlier part of the
same comment which already said, "If neither forRead nor forWrite are
set, immediately return a timeout condition (without waiting)."There might be side-effects to previous/existing callers of this
function (e.g. pqWaitTimed via pqSocketCheck)
Comments were fixed. About the side-effect, please see previous discussion.
7. if (!forRead && !forWrite) - return 0; + { + /* Try to check the health if requested */ + if (end_time == 0) +#if defined(POLLRDHUP) + input_fd.events = POLLRDHUP | POLLHUP | POLLNVAL; +#else + return 0; +#endif /* defined(POLLRDHUP) */ + else + return 0; + }FYI - I think the new code can be simpler without needing #else by
calling your other new function.SUGGESTION
if (!forRead && !forWrite)
{
if (!PQcanConnCheck() || end_time != 0)
return 0;/* Check the connection health when end_time is 0 */
Assert(PQcanConnCheck() && end_time == 0);
#if defined(POLLRDHUP)
input_fd.events = POLLRDHUP | POLLHUP | POLLNVAL;
#endif
}
Fixed.
8. PQconnCheck +/* + * Check whether PQconnCheck() can work well on this platform. + * + * Returns 1 if this can use PQconnCheck(), otherwise 0. + */ +int +PQcanConnCheck(void) +{ +#if (defined(HAVE_POLL) && defined(POLLRDHUP)) + return true; +#else + return false; +#endif +}~
8a.
"can work well" --> "works"~
8b.
Maybe better to say "true (1)" and "otherwise false (0)"
Fixed.
[1]: /messages/by-id/TYAPR01MB58669C95604A0EB7BCC1B58CF5A49@TYAPR01MB5866.jpnprd01.prod.outlook.com
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Here are some review comments for v32-0001.
======
Commit message
1.
PQconnCheck() function allows to check the status of the socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
~
(missed fix from previous review)
"status of the socket" --> "status of the connection"
====
doc/src/sgml/libpq.sgml
2. PQconnCheck
+ <para>
+ This function check the health of the connection. Unlike <xref
linkend="libpq-PQstatus"/>,
+ this check is performed by polling the corresponding socket. This
+ function is currently available only on systems that support the
+ non-standard <symbol>POLLRDHUP</symbol> extension to the
<symbol>poll</symbol>
+ system call, including Linux. <xref linkend="libpq-PQconnCheck"/>
+ returns greater than zero if the remote peer seems to be closed, returns
+ <literal>0</literal> if the socket is valid, and returns
<literal>-1</literal>
+ if the connection has already been closed or an error has occurred.
+ </para>
"check the health" --> "checks the health"
~~~
3. PQcanConnCheck
+ <para>
+ Returns true (1) or false (0) to indicate if the PQconnCheck function
+ is supported on this platform.
Should the reference to PQconnCheck be a link as it previously was?
======
src/interfaces/libpq/fe-misc.c
4. PQconnCheck
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad or an error occurred.
+ */
+int
+PQconnCheck(PGconn *conn)
+{
+ return pqSocketCheck(conn, 0, 0, (time_t) 0);
+}
I'm confused. This comment says =0 means connection is valid. But the
pqSocketCheck comment says =0 means it timed out.
So those two function comments don't seem compatible
~~~
5. PQconnCheckable
+/*
+ * Check whether PQconnCheck() works well on this platform.
+ *
+ * Returns true (1) if this can use PQconnCheck(), otherwise false (0).
+ */
+int
+PQconnCheckable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
Why say "works well"? IMO it either works or doesn't work – there is no "well".
SUGGESTION1
Check whether PQconnCheck() works on this platform.
SUGGESTION2
Check whether PQconnCheck() can work on this platform.
~~~
6. pqSocketCheck
/*
* Checks a socket, using poll or select, for data to be read, written,
- * or both. Returns >0 if one or more conditions are met, 0 if it timed
+ * or both. Moreover, when neither forRead nor forWrite is requested and
+ * timeout is disabled, try to check the health of socket.
+ *
+ * Returns >0 if one or more conditions are met, 0 if it timed
* out, -1 if an error occurred.
*
* If SSL is in use, the SSL buffer is checked prior to checking the socket
~
See review comment #4. (e.g. This says =0 if it timed out).
~~~
7. pqSocketPoll
+ * When neither forRead nor forWrite are set and timeout is disabled,
+ *
+ * - If the timeout is disabled, try to check the health of the socket
+ * - Otherwise this immediately returns 0
+ *
+ * Return >0 if condition is met, 0 if a timeout occurred, -1 if an error
+ * or interrupt occurred.
Don't say "and timeout is disabled," because it clashes with the 1st
bullet which also says "- If the timeout is disabled,".
------
Kind Regards,
Peter Smith.
Fujitsu Australia
Hi Kuroda-san,
Thank you for updating the patch!
On 2023-02-20 15:42, Hayato Kuroda (Fujitsu) wrote:
Dear Katsuragi-san,
Thank you for reviewing! PSA new version.
I rethought the pqSocketPoll part. Current interpretation of
arguments seems a little bit confusing because a specific pattern
of arguments has a different meaning. What do you think about
introducing a new argument like `int forConnCheck`? This seems
straightforward and readable.
0002:
As for the return value of postgres_fdw_verify_connection_states,
what do you think about returning NULL when connection-checking
is not performed? I think there are two cases 1) ConnectionHash
is not initialized or 2) connection is not found for specified
server name, That is, no entry passes the first if statement below
(case 2)).```
if (all || entry->serverid == serverid)
{
if (PQconnCheck(entry->conn))
{
```I think in that case we can follow postgres_fdw_disconnect().
About postgres_fdw_disconnect(), if the given server_name does not
exist,
an error is reported.
Yes, I think this error is fine.
I think there are cases where the given server name does exist,
however the connection check is not performed (does not pass the
first if statement above). 1) a case where the server name exist,
however an open connection to the specified server is not found.
2) case where connection for specified server is invalidated.
3) case where there is not ConnectionHash entry for the specified
server. Current implementation returns true in that case, however
the check is not performed. Suppose the checking mechanism is
supported on the platform, it does not seem reasonable to return
true or false when the check is not performed. What do you think?
regards,
--
Katsuragi Yuta
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Peter,
Thank you for reviewing! PSA new version.
1.
PQconnCheck() function allows to check the status of the socket by polling
the socket. This function is currently available only on systems that
support the non-standard POLLRDHUP extension to the poll system call,
including Linux.~
(missed fix from previous review)
"status of the socket" --> "status of the connection"
Sorry, fixed.
====
doc/src/sgml/libpq.sgml2. PQconnCheck + <para> + This function check the health of the connection. Unlike <xref linkend="libpq-PQstatus"/>, + this check is performed by polling the corresponding socket. This + function is currently available only on systems that support the + non-standard <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> + system call, including Linux. <xref linkend="libpq-PQconnCheck"/> + returns greater than zero if the remote peer seems to be closed, returns + <literal>0</literal> if the socket is valid, and returns <literal>-1</literal> + if the connection has already been closed or an error has occurred. + </para>"check the health" --> "checks the health"
Fixed.
3. PQcanConnCheck
+ <para> + Returns true (1) or false (0) to indicate if the PQconnCheck function + is supported on this platform.Should the reference to PQconnCheck be a link as it previously was?
Right, fixed.
src/interfaces/libpq/fe-misc.c
4. PQconnCheck
+/* + * Check whether the socket peer closed connection or not. + * + * Returns >0 if remote peer seems to be closed, 0 if it is valid, + * -1 if the input connection is bad or an error occurred. + */ +int +PQconnCheck(PGconn *conn) +{ + return pqSocketCheck(conn, 0, 0, (time_t) 0); +}I'm confused. This comment says =0 means connection is valid. But the
pqSocketCheck comment says =0 means it timed out.So those two function comments don't seem compatible
Added further descriptions atop pqSocketCheck() and pqSocketPoll().
Is it helpful to understand?
5. PQconnCheckable
+/* + * Check whether PQconnCheck() works well on this platform. + * + * Returns true (1) if this can use PQconnCheck(), otherwise false (0). + */ +int +PQconnCheckable(void) +{ +#if (defined(HAVE_POLL) && defined(POLLRDHUP)) + return true; +#else + return false; +#endif +}Why say "works well"? IMO it either works or doesn't work – there is no "well".
SUGGESTION1
Check whether PQconnCheck() works on this platform.SUGGESTION2
Check whether PQconnCheck() can work on this platform.
I choose 2.
6. pqSocketCheck
/* * Checks a socket, using poll or select, for data to be read, written, - * or both. Returns >0 if one or more conditions are met, 0 if it timed + * or both. Moreover, when neither forRead nor forWrite is requested and + * timeout is disabled, try to check the health of socket. + * + * Returns >0 if one or more conditions are met, 0 if it timed * out, -1 if an error occurred. * * If SSL is in use, the SSL buffer is checked prior to checking the socket~
See review comment #4. (e.g. This says =0 if it timed out).
Descriptions were added.
7. pqSocketPoll
+ * When neither forRead nor forWrite are set and timeout is disabled, + * + * - If the timeout is disabled, try to check the health of the socket + * - Otherwise this immediately returns 0 + * + * Return >0 if condition is met, 0 if a timeout occurred, -1 if an error + * or interrupt occurred.Don't say "and timeout is disabled," because it clashes with the 1st
bullet which also says "- If the timeout is disabled,".
This comments were reworded.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v33-0001-Add-PQconnCheck-and-PQconnCheckable-to-libpq.patchapplication/octet-stream; name=v33-0001-Add-PQconnCheck-and-PQconnCheckable-to-libpq.patchDownload
From 234b238343cb7e155f57128ee3e3a0ae46e836b9 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:18 +0000
Subject: [PATCH v33 1/3] Add PQconnCheck and PQconnCheckable to libpq
PQconnCheck() function allows to check the status of the connection by
polling the socket. This function is currently available only on systems
that support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQconnCheckable() checks whether the above function is available or not.
---
doc/src/sgml/libpq.sgml | 38 ++++++++++++++++
src/interfaces/libpq/exports.txt | 2 +
src/interfaces/libpq/fe-misc.c | 78 +++++++++++++++++++++++++-------
src/interfaces/libpq/libpq-fe.h | 4 ++
4 files changed, 106 insertions(+), 16 deletions(-)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 0e7ae70c70..afa1fe6731 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,44 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQconnCheck">
+ <term><function>PQconnCheck</function><indexterm><primary>PQconnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the health of the connection.
+
+<synopsis>
+int PQconnCheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ This function checks the health of the connection. Unlike <xref linkend="libpq-PQstatus"/>,
+ this check is performed by polling the corresponding socket. This
+ function is currently available only on systems that support the
+ non-standard <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol>
+ system call, including Linux. <xref linkend="libpq-PQconnCheck"/>
+ returns greater than zero if the remote peer seems to be closed, returns
+ <literal>0</literal> if the socket is valid, and returns <literal>-1</literal>
+ if the connection has already been closed or an error has occurred.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQconnCheckable">
+ <term><function>PQconnCheckable</function><indexterm><primary>PQconnCheckable</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns true (1) or false (0) to indicate if the <xref linkend="libpq-PQconnCheck"/>
+ function is supported on this platform.
+
+<synopsis>
+int PQconnCheckable(void);
+</synopsis>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..a06dea9acd 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQconnCheck 187
+PQconnCheckable 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..1a3478dc7e 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -53,9 +53,10 @@
static int pqPutMsgBytes(const void *buf, size_t len, PGconn *conn);
static int pqSendSome(PGconn *conn, int len);
-static int pqSocketCheck(PGconn *conn, int forRead, int forWrite,
- time_t end_time);
-static int pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time);
+static int pqSocketCheck(PGconn *conn, int forRead,
+ int forWrite, int forConnCheck, time_t end_time);
+static int pqSocketPoll(int sock, int forRead,
+ int forWrite, int forConnCheck, time_t end_time);
/*
* PQlibVersion: return the libpq version number
@@ -993,7 +994,7 @@ pqWaitTimed(int forRead, int forWrite, PGconn *conn, time_t finish_time)
{
int result;
- result = pqSocketCheck(conn, forRead, forWrite, finish_time);
+ result = pqSocketCheck(conn, forRead, forWrite, 0, finish_time);
if (result < 0)
return -1; /* errorMessage is already set */
@@ -1014,7 +1015,7 @@ pqWaitTimed(int forRead, int forWrite, PGconn *conn, time_t finish_time)
int
pqReadReady(PGconn *conn)
{
- return pqSocketCheck(conn, 1, 0, (time_t) 0);
+ return pqSocketCheck(conn, 1, 0, 0, (time_t) 0);
}
/*
@@ -1024,19 +1025,52 @@ pqReadReady(PGconn *conn)
int
pqWriteReady(PGconn *conn)
{
- return pqSocketCheck(conn, 0, 1, (time_t) 0);
+ return pqSocketCheck(conn, 0, 1, 0, (time_t) 0);
+}
+
+/*
+ * Check whether the socket peer closed connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad or an error occurred.
+ */
+int
+PQconnCheck(PGconn *conn)
+{
+ return pqSocketCheck(conn, 0, 0, 1, (time_t) 0);
+}
+
+/*
+ * Check whether PQconnCheck() can work on this platform.
+ *
+ * Returns true (1) if this can use PQconnCheck(), otherwise false (0).
+ */
+int
+PQconnCheckable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
}
/*
* Checks a socket, using poll or select, for data to be read, written,
- * or both. Returns >0 if one or more conditions are met, 0 if it timed
- * out, -1 if an error occurred.
+ * or both. Moreover, this function can check the health of socket on some
+ * limited platforms if end_time is 0.
+ *
+ * Returns >0 if one or more conditions are met, 0 if it timed out, -1 if an
+ * error occurred. Note that if 0 is returned and forConnCheck is requested, it
+ * means that the socket has not matched POLLRDHUP event and the socket has
+ * still survived.
*
* If SSL is in use, the SSL buffer is checked prior to checking the socket
* for read data directly.
*/
static int
-pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
+pqSocketCheck(PGconn *conn, int forRead,
+ int forWrite, int forConnCheck, time_t end_time)
{
int result;
@@ -1059,7 +1093,7 @@ pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
/* We will retry as long as we get EINTR */
do
- result = pqSocketPoll(conn->sock, forRead, forWrite, end_time);
+ result = pqSocketPoll(conn->sock, forRead, forWrite, forConnCheck, end_time);
while (result < 0 && SOCK_ERRNO == EINTR);
if (result < 0)
@@ -1076,15 +1110,20 @@ pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
/*
* Check a file descriptor for read and/or write data, possibly waiting.
- * If neither forRead nor forWrite are set, immediately return a timeout
- * condition (without waiting). Return >0 if condition is met, 0
- * if a timeout occurred, -1 if an error or interrupt occurred.
+ * Moreover, this function can check the health of socket on some limited
+ * platforms if end_time is 0.
+ *
+ * If neither forRead, forWrite nor forConnCheck are set, immediately return a
+ * timeout condition (without waiting). Return >0 if condition is met, 0 if a
+ * timeout occurred, -1 if an error or interrupt occurred. Note that if 0 is
+ * returned and forConnCheck is requested, it means that the socket has not
+ * matched POLLRDHUP event and the socket has still survived.
*
* Timeout is infinite if end_time is -1. Timeout is immediate (no blocking)
* if end_time is 0 (or indeed, any time before now).
*/
static int
-pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
+pqSocketPoll(int sock, int forRead, int forWrite, int forConnCheck, time_t end_time)
{
/* We use poll(2) if available, otherwise select(2) */
#ifdef HAVE_POLL
@@ -1092,7 +1131,10 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
int timeout_ms;
if (!forRead && !forWrite)
- return 0;
+ {
+ if (!forConnCheck || !PQconnCheckable() || end_time != 0)
+ return 0;
+ }
input_fd.fd = sock;
input_fd.events = POLLERR;
@@ -1102,6 +1144,11 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
input_fd.events |= POLLIN;
if (forWrite)
input_fd.events |= POLLOUT;
+#if defined(POLLRDHUP)
+ if (forConnCheck)
+ input_fd.events |= POLLRDHUP;
+#endif
+
/* Compute appropriate timeout interval */
if (end_time == ((time_t) -1))
@@ -1218,7 +1265,6 @@ PQenv2encoding(void)
return encoding;
}
-
#ifdef ENABLE_NLS
static void
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..e1bd0cd7b7 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQconnCheck(PGconn *conn);
+extern int PQconnCheckable(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v33-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v33-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From 74b77d9d0ce0ca04db8381a96b9a78ecc617c447 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v33 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQconnCheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if any of the following condition is satisfied: 1) existing
connection is not closed by the remote peer, 2) there is no connection for specified
server yet, and 3) the checking is not supported on this platform.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 155 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 19 +++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 76 +++++++++
6 files changed, 253 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 7760380f00..0231d23968 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -87,6 +87,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -117,6 +120,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid, bool *checked);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1832,3 +1836,154 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found, and this returns
+ * false only when the lastly verified server seems to be disconnected.
+ *
+ * checked will be set to true if PQconnCheck() is called at least once.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+static bool
+verify_cached_connections(Oid serverid, bool *checked)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ *checked = false;
+
+ Assert(ConnectionHash);
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now. */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated. */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQconnCheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message. */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+
+ /* Set a flag to notify the caller */
+ *checked = true;
+ }
+ }
+
+ /* Raise a warning if disconnections are found. */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of server.")));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found. This returns
+ * false only when the verified server seems to be disconnected, and reutrns
+ * NULL if the connection check had not been done.
+ *
+ * Note that the verification can be used on some limited platforms. If this
+ * server does not support it, this function alwayse returns true.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+ bool result,
+ checked = false;
+
+ /* quick exit if connection cache has not been initialized yet. */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ result = verify_cached_connections(server->serverid, &checked);
+
+ /* Return the result if checking function was called, otherwise NULL */
+ if (checked)
+ PG_RETURN_BOOL(result);
+ else
+ PG_RETURN_NULL();
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ bool result,
+ checked = false;
+
+ /* quick exit if connection cache has not been initialized yet. */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ result = verify_cached_connections(InvalidOid, &checked);
+
+ /* Return the result if checking function was called, otherwise NULL */
+ if (checked)
+ PG_RETURN_BOOL(result);
+ else
+ PG_RETURN_NULL();
+}
+
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(PQconnCheckable());
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..a8556b4c9f
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,19 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 644f51835b..d598228b62 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -826,6 +826,82 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if any of the following condition is
+ satisfied: 1) existing connection is not closed by the remote peer, 2)
+ there is no connection for specified server yet, and 3) the checking is
+ not supported on this platform. <literal>false</literal>
+ is returned if the local session seems to be disconnected from other
+ servers. <literal>NULL</literal> is returned if a connection to the
+ specified foreign server has not been established yet. If no foreign
+ server with the given name is found, an error is reported. Example usage
+ of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if any of the following condition is
+ satisfied: 1) all connections are not closed by the remote peer, 2)
+ there are no connections yet, and 3) the checking is
+ not supported on this platform. <literal>false</literal> is returned if
+ the local session seems to be disconnected from at least one remote
+ server. <literal>NULL</literal> is returned if the local session does
+ not have a connection cache. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether functions the health of remote connectio
+ work well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v33-0003-add-test.patchapplication/octet-stream; name=v33-0003-add-test.patchDownload
From 6a04df56995cfa4a7e586e5cf29569fd42c87f3e Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:36 +0000
Subject: [PATCH v33 3/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 64 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 62 ++++++++++++++++++
2 files changed, 126 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index d5fc61446a..d9926b3857 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11798,3 +11798,67 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+-- ..And call above function
+CALL test_verify_function(false);
+INFO: 00000
+ERROR: 08006
+CALL test_verify_function(true);
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 1e50be137b..81c03d0869 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3974,3 +3974,65 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+-- ..And call above function
+CALL test_verify_function(false);
+CALL test_verify_function(true);
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
Dear Katsuragi-san,
Thank you for reviewing! New patch set can be available on [1]/messages/by-id/TYAPR01MB586664F5ED2128E572EA95B0F5AA9@TYAPR01MB5866.jpnprd01.prod.outlook.com.
I rethought the pqSocketPoll part. Current interpretation of
arguments seems a little bit confusing because a specific pattern
of arguments has a different meaning. What do you think about
introducing a new argument like `int forConnCheck`? This seems
straightforward and readable.
I think it may be better, so fixed.
But now we must consider another thing - will we support combination of conncheck
and {read|write} or timeout? Especially about timeout, if someone calls pqSocketPoll()
with forConnCheck = 1 and end_time = -1, the process may be stuck because it waits
till socket peer closed connection.
Currently the forConnCheck can be specified with other request, but timeout must be zero.
I think there are cases where the given server name does exist,
however the connection check is not performed (does not pass the
first if statement above). 1) a case where the server name exist,
however an open connection to the specified server is not found.
2) case where connection for specified server is invalidated.
3) case where there is not ConnectionHash entry for the specified
server. Current implementation returns true in that case, however
the check is not performed. Suppose the checking mechanism is
supported on the platform, it does not seem reasonable to return
true or false when the check is not performed. What do you think?
Thank you for detailed explanation. I agreed your opinion and modified like that.
While making the patch, I come up with idea that postgres_fdw_verify_connection_states*
returns NULL if PQconnCheck() cannot work on this platform. This can be done by
adding PQconnCheckable(). It may be reasonable because the checking is not really
done on this environment. How do you think?
[1]: /messages/by-id/TYAPR01MB586664F5ED2128E572EA95B0F5AA9@TYAPR01MB5866.jpnprd01.prod.outlook.com
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Hi Kuroda-san,
Thank you for updating the patch!
I rethought the pqSocketPoll part. Current interpretation of
arguments seems a little bit confusing because a specific pattern
of arguments has a different meaning. What do you think about
introducing a new argument like `int forConnCheck`? This seems
straightforward and readable.I think it may be better, so fixed.
But now we must consider another thing - will we support combination
of conncheck
and {read|write} or timeout? Especially about timeout, if someone
calls pqSocketPoll()
with forConnCheck = 1 and end_time = -1, the process may be stuck
because it waits
till socket peer closed connection.
Currently the forConnCheck can be specified with other request, but
timeout must be zero.
Yes, we need to consider these.
I'm wondering whether we need a special care for the combination
of event and timeout. Surely, if forConnCheck is set and end_time = -1,
pqSocketPoll blocks until the connection close. However, the
behavior matches the meaning of the arguments and does not seem
confusing (also not an error state). Do we need to restrict this
kind of usage in the pqSocketPoll side? I think like the following
might be fine.
```
if (!forRead && !forWrite)
{
if (!(forConnCheck && PQconnCheckable()))
return 0;
}
```
While making the patch, I come up with idea that
postgres_fdw_verify_connection_states*
returns NULL if PQconnCheck() cannot work on this platform. This can be
done by
adding PQconnCheckable(). It may be reasonable because the checking is
not really
done on this environment. How do you think?
I agree with you.
Followings are comments for v33. Please check.
0001:
1. the comment of PQconnCheck
+/*
+ * Check whether the socket peer closed connection or not.
+ *
Check whether the socket peer closed 'the' connection or not?
2. the comment of pqSocketCheck
- * or both. Returns >0 if one or more conditions are met, 0 if it
timed
- * out, -1 if an error occurred.
+ * or both. Moreover, this function can check the health of socket on
some
+ * limited platforms if end_time is 0.
the health of socket -> the health of the connection?
if end_time is 0 -> if forConnCehck is specified?
3. the comment of pqSocketPoll
- * If neither forRead nor forWrite are set, immediately return a
timeout
- * condition (without waiting). Return >0 if condition is met, 0
- * if a timeout occurred, -1 if an error or interrupt occurred.
+ * Moreover, this function can check the health of socket on some
limited
+ * platforms if end_time is 0.
the health of socket -> the health of the connection?
if end_time is 0 -> if forConnCehck is specified?
4. the code of pqSocketPoll
+#if defined(POLLRDHUP)
+ if (forConnCheck)
+ input_fd.events |= POLLRDHUP;
+#endif
I think it is better to use PQconnCheckable() to remove the macro.
5. the code of pqSocketCheck and the definition of pqSocketPoll
- result = pqSocketPoll(conn->sock, forRead, forWrite, end_time);
+ result = pqSocketPoll(conn->sock, forRead, forWrite, forConnCheck,
end_time);
-pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
+pqSocketPoll(int sock, int forRead, int forWrite, int forConnCheck,
time_t end_time)
Should these be divided into two lines?
6. the comment of verify_cached_connections
+ * This function emits warnings if a disconnection is found, and this
returns
+ * false only when the lastly verified server seems to be disconnected.
It seems better to write the case where this function returns
true.
7. the comment of postgres_fdw_verify_connection_states
+ * This function emits a warning if a disconnection is found. This
returns
+ * false only when the verified server seems to be disconnected, and
reutrns
+ * NULL if the connection check had not been done.
It seems better to write the case where this function returns
true.
8. the code of
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Socket close is detected."),
+ errhint("Plsease check the health of server.")));
Is it better to use "Connection close is detected" rather than
"Socket close is detected"?
9. the document of postgres_fdw
The document of postgres_fdw_verify_connection_states_* is a little
bit old. Could you update it?
regards,
--
Katsuragi Yuta
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Hi Katsuragi-san,
Thank you for reviewing! PSA new version.
I rethought the pqSocketPoll part. Current interpretation of
arguments seems a little bit confusing because a specific pattern
of arguments has a different meaning. What do you think about
introducing a new argument like `int forConnCheck`? This seems
straightforward and readable.I think it may be better, so fixed.
But now we must consider another thing - will we support combination
of conncheck
and {read|write} or timeout? Especially about timeout, if someone
calls pqSocketPoll()
with forConnCheck = 1 and end_time = -1, the process may be stuck
because it waits
till socket peer closed connection.
Currently the forConnCheck can be specified with other request, but
timeout must be zero.Yes, we need to consider these.
I'm wondering whether we need a special care for the combination
of event and timeout. Surely, if forConnCheck is set and end_time = -1,
pqSocketPoll blocks until the connection close. However, the
behavior matches the meaning of the arguments and does not seem
confusing (also not an error state). Do we need to restrict this
kind of usage in the pqSocketPoll side? I think like the following
might be fine.```
if (!forRead && !forWrite)
{
if (!(forConnCheck && PQconnCheckable()))
return 0;
}
```
Seems right, I was too pessimistic. Fixed.
While making the patch, I come up with idea that
postgres_fdw_verify_connection_states*
returns NULL if PQconnCheck() cannot work on this platform. This can be
done by
adding PQconnCheckable(). It may be reasonable because the checking is
not really
done on this environment. How do you think?I agree with you.
Changed.
Followings are comments for v33. Please check. 0001: 1. the comment of PQconnCheck +/* + * Check whether the socket peer closed connection or not. + *Check whether the socket peer closed 'the' connection or not?
Changed.
2. the comment of pqSocketCheck - * or both. Returns >0 if one or more conditions are met, 0 if it timed - * out, -1 if an error occurred. + * or both. Moreover, this function can check the health of socket on some + * limited platforms if end_time is 0.the health of socket -> the health of the connection?
if end_time is 0 -> if forConnCehck is specified?
Fixed.
3. the comment of pqSocketPoll - * If neither forRead nor forWrite are set, immediately return a timeout - * condition (without waiting). Return >0 if condition is met, 0 - * if a timeout occurred, -1 if an error or interrupt occurred. + * Moreover, this function can check the health of socket on some limited + * platforms if end_time is 0.the health of socket -> the health of the connection?
if end_time is 0 -> if forConnCehck is specified?
Fixed.
4. the code of pqSocketPoll +#if defined(POLLRDHUP) + if (forConnCheck) + input_fd.events |= POLLRDHUP; +#endifI think it is better to use PQconnCheckable() to remove the macro.
IIUC the macro is needed. In FreeBSD, macOS and other platforms do not have the
macro POLLRDHUP so they cannot compile. I checked by my CI and got following error.
```
...
FAILED: src/interfaces/libpq/libpq.a.p/fe-misc.c.o
...
../src/interfaces/libpq/fe-misc.c:1149:22: error: use of undeclared identifier 'POLLRDHUP'
input_fd.events |= POLLRDHUP;
````
It must be invisible from them.
5. the code of pqSocketCheck and the definition of pqSocketPoll - result = pqSocketPoll(conn->sock, forRead, forWrite, end_time); + result = pqSocketPoll(conn->sock, forRead, forWrite, forConnCheck, end_time);-pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time) +pqSocketPoll(int sock, int forRead, int forWrite, int forConnCheck, time_t end_time)Should these be divided into two lines?
pgindent did not say anything about them, but I divided.
6. the comment of verify_cached_connections + * This function emits warnings if a disconnection is found, and this returns + * false only when the lastly verified server seems to be disconnected.
Updated. I think comments were not correct, so these were also fixed.
It seems better to write the case where this function returns true. 7. the comment of postgres_fdw_verify_connection_states + * This function emits a warning if a disconnection is found. This returns + * false only when the verified server seems to be disconnected, and reutrns + * NULL if the connection check had not been done.It seems better to write the case where this function returns
true.
8. the code of + (errcode(ERRCODE_CONNECTION_FAILURE), + errmsg("%s", str.data), + errdetail("Socket close is detected."), + errhint("Plsease check the health of server.")));Is it better to use "Connection close is detected" rather than
"Socket close is detected"?
Changed.
9. the document of postgres_fdw
The document of postgres_fdw_verify_connection_states_* is a little
bit old. Could you update it?
Updated. IIUC postgres_fdw_verify_connection_states returns
* true, if the connection is verified.
* false, if the connection seems to be disconnected.
* NULL, if this is not the supported platform or connection has not been established.
And postgres_fdw_verify_connection_states_all returns
* true if all the connections are verified.
* false, if one of connections seems to be disconnected.
* NULL, if this is not the supported platform or this backend has never established connections
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v34-0001-Add-PQconnCheck-and-PQconnCheckable-to-libpq.patchapplication/octet-stream; name=v34-0001-Add-PQconnCheck-and-PQconnCheckable-to-libpq.patchDownload
From 0b3a6479c4ccadf97ab48925bfd42fe3088887e8 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:18 +0000
Subject: [PATCH v34 1/3] Add PQconnCheck and PQconnCheckable to libpq
PQconnCheck() function allows to check the status of the connection by
polling the socket. This function is currently available only on systems
that support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQconnCheckable() checks whether the above function is available or not.
---
doc/src/sgml/libpq.sgml | 38 +++++++++++++++
src/interfaces/libpq/exports.txt | 2 +
src/interfaces/libpq/fe-misc.c | 79 ++++++++++++++++++++++++++------
src/interfaces/libpq/libpq-fe.h | 4 ++
4 files changed, 108 insertions(+), 15 deletions(-)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 3ccd8ff942..b6461cf82f 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,44 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQconnCheck">
+ <term><function>PQconnCheck</function><indexterm><primary>PQconnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the health of the connection.
+
+<synopsis>
+int PQconnCheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ This function checks the health of the connection. Unlike <xref linkend="libpq-PQstatus"/>,
+ this check is performed by polling the corresponding socket. This
+ function is currently available only on systems that support the
+ non-standard <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol>
+ system call, including Linux. <xref linkend="libpq-PQconnCheck"/>
+ returns greater than zero if the remote peer seems to be closed, returns
+ <literal>0</literal> if the socket is valid, and returns <literal>-1</literal>
+ if the connection has already been closed or an error has occurred.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQconnCheckable">
+ <term><function>PQconnCheckable</function><indexterm><primary>PQconnCheckable</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns true (1) or false (0) to indicate if the <xref linkend="libpq-PQconnCheck"/>
+ function is supported on this platform.
+
+<synopsis>
+int PQconnCheckable(void);
+</synopsis>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..e7f0d435bd 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQconnCheck 187
+PQconnCheckable 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..fba5359dcb 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -53,9 +53,10 @@
static int pqPutMsgBytes(const void *buf, size_t len, PGconn *conn);
static int pqSendSome(PGconn *conn, int len);
-static int pqSocketCheck(PGconn *conn, int forRead, int forWrite,
- time_t end_time);
-static int pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time);
+static int pqSocketCheck(PGconn *conn, int forRead,
+ int forWrite, int forConnCheck, time_t end_time);
+static int pqSocketPoll(int sock, int forRead,
+ int forWrite, int forConnCheck, time_t end_time);
/*
* PQlibVersion: return the libpq version number
@@ -993,7 +994,7 @@ pqWaitTimed(int forRead, int forWrite, PGconn *conn, time_t finish_time)
{
int result;
- result = pqSocketCheck(conn, forRead, forWrite, finish_time);
+ result = pqSocketCheck(conn, forRead, forWrite, 0, finish_time);
if (result < 0)
return -1; /* errorMessage is already set */
@@ -1014,7 +1015,7 @@ pqWaitTimed(int forRead, int forWrite, PGconn *conn, time_t finish_time)
int
pqReadReady(PGconn *conn)
{
- return pqSocketCheck(conn, 1, 0, (time_t) 0);
+ return pqSocketCheck(conn, 1, 0, 0, (time_t) 0);
}
/*
@@ -1024,19 +1025,52 @@ pqReadReady(PGconn *conn)
int
pqWriteReady(PGconn *conn)
{
- return pqSocketCheck(conn, 0, 1, (time_t) 0);
+ return pqSocketCheck(conn, 0, 1, 0, (time_t) 0);
+}
+
+/*
+ * Check whether the socket peer closed the connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad or an error occurred.
+ */
+int
+PQconnCheck(PGconn *conn)
+{
+ return pqSocketCheck(conn, 0, 0, 1, (time_t) 0);
+}
+
+/*
+ * Check whether PQconnCheck() can work on this platform.
+ *
+ * Returns true (1) if this can use PQconnCheck(), otherwise false (0).
+ */
+int
+PQconnCheckable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
}
/*
* Checks a socket, using poll or select, for data to be read, written,
- * or both. Returns >0 if one or more conditions are met, 0 if it timed
- * out, -1 if an error occurred.
+ * or both. Moreover, this function can check the health of the connetion on
+ * some limited platforms if forConnCehck is specified.
+ *
+ * Returns >0 if one or more conditions are met, 0 if it timed out, -1 if an
+ * error occurred. Note that if 0 is returned and forConnCheck is requested, it
+ * means that the socket has not matched POLLRDHUP event and the socket has
+ * still survived.
*
* If SSL is in use, the SSL buffer is checked prior to checking the socket
* for read data directly.
*/
static int
-pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
+pqSocketCheck(PGconn *conn, int forRead,
+ int forWrite, int forConnCheck, time_t end_time)
{
int result;
@@ -1059,7 +1093,8 @@ pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
/* We will retry as long as we get EINTR */
do
- result = pqSocketPoll(conn->sock, forRead, forWrite, end_time);
+ result = pqSocketPoll(conn->sock, forRead,
+ forWrite, forConnCheck, end_time);
while (result < 0 && SOCK_ERRNO == EINTR);
if (result < 0)
@@ -1076,15 +1111,21 @@ pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
/*
* Check a file descriptor for read and/or write data, possibly waiting.
- * If neither forRead nor forWrite are set, immediately return a timeout
- * condition (without waiting). Return >0 if condition is met, 0
- * if a timeout occurred, -1 if an error or interrupt occurred.
+ * Moreover, this function can check the health of connection on some limited
+ * platform if forConnCehck is specified.
+ *
+ * If neither forRead, forWrite nor forConnCheck are set, immediately return a
+ * timeout condition (without waiting). Return >0 if condition is met, 0 if a
+ * timeout occurred, -1 if an error or interrupt occurred. Note that if 0 is
+ * returned and forConnCheck is requested, it means that the socket has not
+ * matched POLLRDHUP event and the socket has still survived.
*
* Timeout is infinite if end_time is -1. Timeout is immediate (no blocking)
* if end_time is 0 (or indeed, any time before now).
*/
static int
-pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
+pqSocketPoll(int sock, int forRead,
+ int forWrite, int forConnCheck, time_t end_time)
{
/* We use poll(2) if available, otherwise select(2) */
#ifdef HAVE_POLL
@@ -1092,7 +1133,11 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
int timeout_ms;
if (!forRead && !forWrite)
- return 0;
+ {
+ /* Connection check can be available on some limted platforms */
+ if (!(forConnCheck && PQconnCheckable()))
+ return 0;
+ }
input_fd.fd = sock;
input_fd.events = POLLERR;
@@ -1102,6 +1147,10 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
input_fd.events |= POLLIN;
if (forWrite)
input_fd.events |= POLLOUT;
+#if defined(POLLRDHUP)
+ if (forConnCheck)
+ input_fd.events |= POLLRDHUP;
+#endif
/* Compute appropriate timeout interval */
if (end_time == ((time_t) -1))
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..e1bd0cd7b7 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQconnCheck(PGconn *conn);
+extern int PQconnCheckable(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v34-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v34-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From 2da884f1dab6278a1a3fd71faf02f659da71934f Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v34 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQconnCheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if existing connection is not closed by the remote peer.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 162 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 19 ++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 74 ++++++++
6 files changed, 258 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 12b54f15cd..99aff6304e 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -87,6 +87,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -117,6 +120,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid, bool *checked);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1832,3 +1836,161 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found. This return true
+ * if disconnections cannot be found, otherwise return false.
+ *
+ * checked will be set to true if PQconnCheck() is called at least once.
+ */
+static bool
+verify_cached_connections(Oid serverid, bool *checked)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ *checked = false;
+
+ Assert(ConnectionHash);
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQconnCheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+
+ /* Set a flag to notify the caller */
+ *checked = true;
+ }
+ }
+
+ /* Raise a warning if disconnections are found */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Connection close is detected."),
+ errhint("Plsease check the health of server.")));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found. This returns true
+ * if existing connection is not closed by the remote peer. false is returned
+ * if the local session seems to be disconnected from other servers. NULL is
+ * returned if a connection to the specified foreign server has not been
+ * established yet, or this function is not available on this platform.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+ bool result,
+ checked = false;
+
+ /* quick exit if the checking does not work well on this platfrom */
+ if (!PQconnCheckable())
+ PG_RETURN_NULL();
+
+ /* quick exit if connection cache has not been initialized yet */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ result = verify_cached_connections(server->serverid, &checked);
+
+ /* Return the result if checking function was called, otherwise NULL */
+ if (checked)
+ PG_RETURN_BOOL(result);
+ else
+ PG_RETURN_NULL();
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ bool result,
+ checked = false;
+
+ /* quick exit if the checking does not work well on this platfrom */
+ if (!PQconnCheckable())
+ PG_RETURN_NULL();
+
+ /* quick exit if connection cache has not been initialized yet */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ result = verify_cached_connections(InvalidOid, &checked);
+
+ /* Return the result if checking function was called, otherwise NULL */
+ if (checked)
+ PG_RETURN_BOOL(result);
+ else
+ PG_RETURN_NULL();
+}
+
+/*
+ * Check whether functions for verifying cached connections work well or not
+ */
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(PQconnCheckable());
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..a8556b4c9f
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,19 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 644f51835b..85e21f8904 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -826,6 +826,80 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if existing connection is not closed by
+ the remote peer. <literal>false</literal> is returned if the local
+ session seems to be disconnected from other servers. <literal>NULL</literal>
+ is returned if a connection to the specified foreign server has not been
+ established yet, or this function is not available on this platform.
+ If no foreign server with the given name is found, an error is reported.
+ Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if all connections are not closed by the
+ remote peer. <literal>false</literal> is returned if the local session
+ seems to be disconnected from at least one remote server. <literal>NULL</literal>
+ is returned if the local session does not have connection caches, or this
+ function is not available on this platform. Example usage of the
+ function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether <function>postgres_fdw_verify_connection_states</function>
+ and <function>postgres_fdw_verify_connection_states</function> work well
+ or not. This returns <literal>true</literal> if it can be used, otherwise
+ returns <literal>false</literal>. Example usage of the function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v34-0003-add-test.patchapplication/octet-stream; name=v34-0003-add-test.patchDownload
From 139c1e4d64ae8bfeb8e3eb2a174eb0ab762f6412 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:36 +0000
Subject: [PATCH v34 3/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 64 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 62 ++++++++++++++++++
2 files changed, 126 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 04a3ef450c..6446f36092 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11783,3 +11783,67 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+-- ..And call above function
+CALL test_verify_function(false);
+INFO: 00000
+ERROR: 08006
+CALL test_verify_function(true);
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 4f3088c03e..b413f96e32 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3979,3 +3979,65 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+-- ..And call above function
+CALL test_verify_function(false);
+CALL test_verify_function(true);
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
Hi Kuroda-san,
Thank you for updating the patch!
4. the code of pqSocketPoll +#if defined(POLLRDHUP) + if (forConnCheck) + input_fd.events |= POLLRDHUP; +#endifI think it is better to use PQconnCheckable() to remove the macro.
IIUC the macro is needed. In FreeBSD, macOS and other platforms do not
have the
macro POLLRDHUP so they cannot compile. I checked by my CI and got
following error.```
...
FAILED: src/interfaces/libpq/libpq.a.p/fe-misc.c.o
...
../src/interfaces/libpq/fe-misc.c:1149:22: error: use of undeclared
identifier 'POLLRDHUP'
input_fd.events |= POLLRDHUP;
````It must be invisible from them.
Sorry, my mistake...
9. the document of postgres_fdw
The document of postgres_fdw_verify_connection_states_* is a little
bit old. Could you update it?Updated. IIUC postgres_fdw_verify_connection_states returns
* true, if the connection is verified.
* false, if the connection seems to be disconnected.
* NULL, if this is not the supported platform or connection has not
been established.And postgres_fdw_verify_connection_states_all returns
* true if all the connections are verified.
* false, if one of connections seems to be disconnected.
* NULL, if this is not the supported platform or this backend has
never established connections
I think 'backend has never established connections' is a little bit
strong.
I think the following cases also return NULL. The case where a
connection was established, however the connection is now closed
by the postgres_fdw_disconnect() or something. NULL is also returned if
the connection is invalidated. So, I think 'NULL, if no valid
connection is established or the function is not supported on
the platform.' is better. What do you think?
Followings are my comments for v34. Please check.
0001:
1. the document of pqConnCheck
+ <literal>0</literal> if the socket is valid, and returns
<literal>-1</literal>
+ if the connection has already been closed or an error has
occurred.
1.1 if the socket is valid -> returns 0 if the 'connection is not
closed'?
1.2 returns -1 if the connection has already been closed <- Let me ask
a question.
Isn't this a situation where we would like to check using this
function? Is 'error has occurred' insufficient?
2. the comment of pqSocketCheck
+ * means that the socket has not matched POLLRDHUP event and the socket
has
+ * still survived.
socket has still survived -> connection is not closed by the socket
peer?
3. the comment of pqSocketPoll
+ * returned and forConnCheck is requested, it means that the socket has
not
+ * matched POLLRDHUP event and the socket has still survived.
socket has still survived -> connection is not closed by the socket
peer?
0002:
4. the comment of verify_cached_connections
+ * This function emits warnings if a disconnection is found. This
return true
+ * if disconnections cannot be found, otherwise return false.
return ture -> return's' true
return false -> return's' false
5. the comment of postgres_fdw_verify_connection_states
+ * if the local session seems to be disconnected from other servers.
NULL is
+ * returned if a connection to the specified foreign server has not
been
+ * established yet, or this function is not available on this platform.
Considering the above discussion, 'NULL is returned if a valid
connection to the specified foreign server is not established or
this function...' seems better. What do you think?
6. the document of postgres_fdw_verify_connection_states
<literal>NULL</literal>
+ is returned if a connection to the specified foreign server has
not been
+ established yet, or this function is not available on this
platform
The same as comment no.5.
7. the document of postgres_fdw_verify_connection_states_all
<literal>NULL</literal>
+ is returned if the local session does not have connection caches,
or this
+ function is not available on this platform.
I think there is a case where a connection cache exists but valid
connections do not exist and NULL is returned (disconnection case).
Almost the same document as the postgres_fdw_verify_connection_states
case (comment no.5) seems better.
8. the document of postgres_fdw_can_verify_connection_states
+ This function checks whether
<function>postgres_fdw_verify_connection_states</function>
+ and <function>postgres_fdw_verify_connection_states</function>
work well
Should the latter (or former) postgres_fdw_verify_connection_states be
postgres_fdw_verify_connection_states_all?
regards,
--
Katsuragi Yuta
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Katsuragi-san,
Thank you for reviewing! PSA new version.
4. the code of pqSocketPoll +#if defined(POLLRDHUP) + if (forConnCheck) + input_fd.events |= POLLRDHUP; +#endifI think it is better to use PQconnCheckable() to remove the macro.
IIUC the macro is needed. In FreeBSD, macOS and other platforms do not
have the
macro POLLRDHUP so they cannot compile. I checked by my CI and got
following error.```
...
FAILED: src/interfaces/libpq/libpq.a.p/fe-misc.c.o
...
../src/interfaces/libpq/fe-misc.c:1149:22: error: use of undeclared
identifier 'POLLRDHUP'
input_fd.events |= POLLRDHUP;
````It must be invisible from them.
Sorry, my mistake...
No issues :-).
9. the document of postgres_fdw
The document of postgres_fdw_verify_connection_states_* is a little
bit old. Could you update it?Updated. IIUC postgres_fdw_verify_connection_states returns
* true, if the connection is verified.
* false, if the connection seems to be disconnected.
* NULL, if this is not the supported platform or connection has not
been established.And postgres_fdw_verify_connection_states_all returns
* true if all the connections are verified.
* false, if one of connections seems to be disconnected.
* NULL, if this is not the supported platform or this backend has
never established connectionsI think 'backend has never established connections' is a little bit
strong.
I think the following cases also return NULL. The case where a
connection was established, however the connection is now closed
by the postgres_fdw_disconnect() or something. NULL is also returned if
the connection is invalidated. So, I think 'NULL, if no valid
connection is established or the function is not supported on
the platform.' is better. What do you think?
Disconnect functions have never been in my mind. Descriptions must be updated.
Followings are my comments for v34. Please check.
0001: 1. the document of pqConnCheck + <literal>0</literal> if the socket is valid, and returns <literal>-1</literal> + if the connection has already been closed or an error has occurred.1.1 if the socket is valid -> returns 0 if the 'connection is not
closed'?
Fixed.
1.2 returns -1 if the connection has already been closed <- Let me ask
a question.
Isn't this a situation where we would like to check using this
function? Is 'error has occurred' insufficient?
Seems right, fixed.
2. the comment of pqSocketCheck + * means that the socket has not matched POLLRDHUP event and the socket has + * still survived.socket has still survived -> connection is not closed by the socket
peer?
Fixed.
3. the comment of pqSocketPoll + * returned and forConnCheck is requested, it means that the socket has not + * matched POLLRDHUP event and the socket has still survived.socket has still survived -> connection is not closed by the socket
peer?
Fixed.
0002: 4. the comment of verify_cached_connections + * This function emits warnings if a disconnection is found. This return true + * if disconnections cannot be found, otherwise return false.return ture -> return's' true
return false -> return's' false
Fixed.
5. the comment of postgres_fdw_verify_connection_states + * if the local session seems to be disconnected from other servers. NULL is + * returned if a connection to the specified foreign server has not been + * established yet, or this function is not available on this platform.Considering the above discussion, 'NULL is returned if a valid
connection to the specified foreign server is not established or
this function...' seems better. What do you think?
Right, fixed.
6. the document of postgres_fdw_verify_connection_states <literal>NULL</literal> + is returned if a connection to the specified foreign server has not been + established yet, or this function is not available on this platformThe same as comment no.5.
Right, fixed.
7. the document of postgres_fdw_verify_connection_states_all <literal>NULL</literal> + is returned if the local session does not have connection caches, or this + function is not available on this platform.I think there is a case where a connection cache exists but valid
connections do not exist and NULL is returned (disconnection case).
Almost the same document as the postgres_fdw_verify_connection_states
case (comment no.5) seems better.
Yes, but completely same statement cannot be used because these is not
specified foreign server. How about:
NULL is returned if there are no established connections or this function ...
8. the document of postgres_fdw_can_verify_connection_states + This function checks whether <function>postgres_fdw_verify_connection_states</function> + and <function>postgres_fdw_verify_connection_states</function> work wellShould the latter (or former) postgres_fdw_verify_connection_states be
postgres_fdw_verify_connection_states_all?
That was copy-and-paste error, fixed.
regards,
--
Katsuragi Yuta
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v35-0001-Add-PQconnCheck-and-PQconnCheckable-to-libpq.patchapplication/octet-stream; name=v35-0001-Add-PQconnCheck-and-PQconnCheckable-to-libpq.patchDownload
From 7183d0caec360464dbc0e5e83c31eef837d77477 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:18 +0000
Subject: [PATCH v35 1/3] Add PQconnCheck and PQconnCheckable to libpq
PQconnCheck() function allows to check the status of the connection by
polling the socket. This function is currently available only on systems
that support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQconnCheckable() checks whether the above function is available or not.
---
doc/src/sgml/libpq.sgml | 38 +++++++++++++++
src/interfaces/libpq/exports.txt | 2 +
src/interfaces/libpq/fe-misc.c | 79 ++++++++++++++++++++++++++------
src/interfaces/libpq/libpq-fe.h | 4 ++
4 files changed, 108 insertions(+), 15 deletions(-)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 3ccd8ff942..b1a4471403 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,44 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQconnCheck">
+ <term><function>PQconnCheck</function><indexterm><primary>PQconnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the health of the connection.
+
+<synopsis>
+int PQconnCheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ This function checks the health of the connection. Unlike <xref linkend="libpq-PQstatus"/>,
+ this check is performed by polling the corresponding socket. This
+ function is currently available only on systems that support the
+ non-standard <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol>
+ system call, including Linux. <xref linkend="libpq-PQconnCheck"/>
+ returns greater than zero if the remote peer seems to be closed, returns
+ <literal>0</literal> if the connection is not closed, and returns
+ <literal>-1</literal> if an error has occurred.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQconnCheckable">
+ <term><function>PQconnCheckable</function><indexterm><primary>PQconnCheckable</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns true (1) or false (0) to indicate if the <xref linkend="libpq-PQconnCheck"/>
+ function is supported on this platform.
+
+<synopsis>
+int PQconnCheckable(void);
+</synopsis>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..e7f0d435bd 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQconnCheck 187
+PQconnCheckable 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..897eb413b1 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -53,9 +53,10 @@
static int pqPutMsgBytes(const void *buf, size_t len, PGconn *conn);
static int pqSendSome(PGconn *conn, int len);
-static int pqSocketCheck(PGconn *conn, int forRead, int forWrite,
- time_t end_time);
-static int pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time);
+static int pqSocketCheck(PGconn *conn, int forRead,
+ int forWrite, int forConnCheck, time_t end_time);
+static int pqSocketPoll(int sock, int forRead,
+ int forWrite, int forConnCheck, time_t end_time);
/*
* PQlibVersion: return the libpq version number
@@ -993,7 +994,7 @@ pqWaitTimed(int forRead, int forWrite, PGconn *conn, time_t finish_time)
{
int result;
- result = pqSocketCheck(conn, forRead, forWrite, finish_time);
+ result = pqSocketCheck(conn, forRead, forWrite, 0, finish_time);
if (result < 0)
return -1; /* errorMessage is already set */
@@ -1014,7 +1015,7 @@ pqWaitTimed(int forRead, int forWrite, PGconn *conn, time_t finish_time)
int
pqReadReady(PGconn *conn)
{
- return pqSocketCheck(conn, 1, 0, (time_t) 0);
+ return pqSocketCheck(conn, 1, 0, 0, (time_t) 0);
}
/*
@@ -1024,19 +1025,52 @@ pqReadReady(PGconn *conn)
int
pqWriteReady(PGconn *conn)
{
- return pqSocketCheck(conn, 0, 1, (time_t) 0);
+ return pqSocketCheck(conn, 0, 1, 0, (time_t) 0);
+}
+
+/*
+ * Check whether the socket peer closed the connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad or an error occurred.
+ */
+int
+PQconnCheck(PGconn *conn)
+{
+ return pqSocketCheck(conn, 0, 0, 1, (time_t) 0);
+}
+
+/*
+ * Check whether PQconnCheck() can work on this platform.
+ *
+ * Returns true (1) if this can use PQconnCheck(), otherwise false (0).
+ */
+int
+PQconnCheckable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
}
/*
* Checks a socket, using poll or select, for data to be read, written,
- * or both. Returns >0 if one or more conditions are met, 0 if it timed
- * out, -1 if an error occurred.
+ * or both. Moreover, this function can check the health of the connetion on
+ * some limited platforms if forConnCehck is specified.
+ *
+ * Returns >0 if one or more conditions are met, 0 if it timed out, -1 if an
+ * error occurred. Note that if 0 is returned and forConnCheck is requested, it
+ * means that the socket has not matched POLLRDHUP event and the connection is
+ * not closed by the socket peer.
*
* If SSL is in use, the SSL buffer is checked prior to checking the socket
* for read data directly.
*/
static int
-pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
+pqSocketCheck(PGconn *conn, int forRead,
+ int forWrite, int forConnCheck, time_t end_time)
{
int result;
@@ -1059,7 +1093,8 @@ pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
/* We will retry as long as we get EINTR */
do
- result = pqSocketPoll(conn->sock, forRead, forWrite, end_time);
+ result = pqSocketPoll(conn->sock, forRead,
+ forWrite, forConnCheck, end_time);
while (result < 0 && SOCK_ERRNO == EINTR);
if (result < 0)
@@ -1076,15 +1111,21 @@ pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
/*
* Check a file descriptor for read and/or write data, possibly waiting.
- * If neither forRead nor forWrite are set, immediately return a timeout
- * condition (without waiting). Return >0 if condition is met, 0
- * if a timeout occurred, -1 if an error or interrupt occurred.
+ * Moreover, this function can check the health of connection on some limited
+ * platform if forConnCehck is specified.
+ *
+ * If neither forRead, forWrite nor forConnCheck are set, immediately return a
+ * timeout condition (without waiting). Return >0 if condition is met, 0 if a
+ * timeout occurred, -1 if an error or interrupt occurred. Note that if 0 is
+ * returned and forConnCheck is requested, it means that the socket has not
+ * matched POLLRDHUP event and the connection is not closed by the socket peer.
*
* Timeout is infinite if end_time is -1. Timeout is immediate (no blocking)
* if end_time is 0 (or indeed, any time before now).
*/
static int
-pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
+pqSocketPoll(int sock, int forRead,
+ int forWrite, int forConnCheck, time_t end_time)
{
/* We use poll(2) if available, otherwise select(2) */
#ifdef HAVE_POLL
@@ -1092,7 +1133,11 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
int timeout_ms;
if (!forRead && !forWrite)
- return 0;
+ {
+ /* Connection check can be available on some limted platforms */
+ if (!(forConnCheck && PQconnCheckable()))
+ return 0;
+ }
input_fd.fd = sock;
input_fd.events = POLLERR;
@@ -1102,6 +1147,10 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
input_fd.events |= POLLIN;
if (forWrite)
input_fd.events |= POLLOUT;
+#if defined(POLLRDHUP)
+ if (forConnCheck)
+ input_fd.events |= POLLRDHUP;
+#endif
/* Compute appropriate timeout interval */
if (end_time == ((time_t) -1))
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..e1bd0cd7b7 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQconnCheck(PGconn *conn);
+extern int PQconnCheckable(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v35-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v35-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From d9ef6cf61b767c3d552c3adb0b65f9cef2bbe57a Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v35 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQconnCheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if existing connection is not closed by the remote peer.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 162 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 19 ++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 74 ++++++++
6 files changed, 258 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 12b54f15cd..28f0775ffa 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -87,6 +87,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -117,6 +120,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid, bool *checked);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1832,3 +1836,161 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found. This returns true
+ * if disconnections cannot be found, otherwise returns false.
+ *
+ * checked will be set to true if PQconnCheck() is called at least once.
+ */
+static bool
+verify_cached_connections(Oid serverid, bool *checked)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ *checked = false;
+
+ Assert(ConnectionHash);
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQconnCheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+
+ /* Set a flag to notify the caller */
+ *checked = true;
+ }
+ }
+
+ /* Raise a warning if disconnections are found */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Connection close is detected."),
+ errhint("Plsease check the health of server.")));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found. This returns true
+ * if existing connection is not closed by the remote peer. false is returned
+ * if the local session seems to be disconnected from other servers. NULL is
+ * returned if a valid connection to the specified foreign server is not
+ * established or this function is not available on this platform.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+ bool result,
+ checked = false;
+
+ /* quick exit if the checking does not work well on this platfrom */
+ if (!PQconnCheckable())
+ PG_RETURN_NULL();
+
+ /* quick exit if connection cache has not been initialized yet */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ result = verify_cached_connections(server->serverid, &checked);
+
+ /* Return the result if checking function was called, otherwise NULL */
+ if (checked)
+ PG_RETURN_BOOL(result);
+ else
+ PG_RETURN_NULL();
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ bool result,
+ checked = false;
+
+ /* quick exit if the checking does not work well on this platfrom */
+ if (!PQconnCheckable())
+ PG_RETURN_NULL();
+
+ /* quick exit if connection cache has not been initialized yet */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ result = verify_cached_connections(InvalidOid, &checked);
+
+ /* Return the result if checking function was called, otherwise NULL */
+ if (checked)
+ PG_RETURN_BOOL(result);
+ else
+ PG_RETURN_NULL();
+}
+
+/*
+ * Check whether functions for verifying cached connections work well or not
+ */
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(PQconnCheckable());
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..a8556b4c9f
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,19 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 644f51835b..8cdb0d0a9d 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -826,6 +826,80 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if existing connection is not closed by
+ the remote peer. <literal>false</literal> is returned if the local
+ session seems to be disconnected from other servers. <literal>NULL</literal>
+ is returned if a valid connection to the specified foreign server is not
+ established or this function is not available on this platform. If no
+ foreign server with the given name is found, an error is reported.
+ Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if all connections are not closed by the
+ remote peer. <literal>false</literal> is returned if the local session
+ seems to be disconnected from at least one remote server. <literal>NULL</literal>
+ is returned if there are no established connections or this function is
+ not available on this platform. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether <function>postgres_fdw_verify_connection_states</function>
+ and <function>postgres_fdw_verify_connection_states_all</function> work
+ well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the
+ function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v35-0003-add-test.patchapplication/octet-stream; name=v35-0003-add-test.patchDownload
From 987d157a13d8f2dc200b99b0a914f105a167e100 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:36 +0000
Subject: [PATCH v35 3/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 64 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 62 ++++++++++++++++++
2 files changed, 126 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 04a3ef450c..6446f36092 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11783,3 +11783,67 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+-- ..And call above function
+CALL test_verify_function(false);
+INFO: 00000
+ERROR: 08006
+CALL test_verify_function(true);
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 4f3088c03e..b413f96e32 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3979,3 +3979,65 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+-- ..And call above function
+CALL test_verify_function(false);
+CALL test_verify_function(true);
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
Hi Kuroda-san,
Thank you for updating the patch!
I think we can update the status to ready for committer after
this fix, if there is no objection.
7. the document of postgres_fdw_verify_connection_states_all <literal>NULL</literal> + is returned if the local session does not have connection caches, or this + function is not available on this platform.I think there is a case where a connection cache exists but valid
connections do not exist and NULL is returned (disconnection case).
Almost the same document as the postgres_fdw_verify_connection_states
case (comment no.5) seems better.Yes, but completely same statement cannot be used because these is not
specified foreign server. How about:
NULL is returned if there are no established connections or this
function ...
Yes, to align with the postgres_fdw_verify_connection_states()
case, how about writing the connection is not valid. Like the
following?
'NULL is returned if no valid connections are established or
this function...'
This is my comment for v35. Please check.
0002:
1. the comment of verify_cached_connections (I missed one minor point.)
+ * This function emits warnings if a disconnection is found. This
returns true
+ * if disconnections cannot be found, otherwise returns false.
I think false is returned only if disconnections are found and
true is returned in all other cases. So, modifying the description
like the following seems better.
'This returns false if disconnections are found, otherwise
returns true.'
regards,
--
Katsuragi Yuta
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Katsuragi-san,
Thank you for reviewing! PSA new version patches.
I think we can update the status to ready for committer after
this fix, if there is no objection.
That's a very good news for me! How about other people?
7. the document of postgres_fdw_verify_connection_states_all <literal>NULL</literal> + is returned if the local session does not have connection caches, or this + function is not available on this platform.I think there is a case where a connection cache exists but valid
connections do not exist and NULL is returned (disconnection case).
Almost the same document as the postgres_fdw_verify_connection_states
case (comment no.5) seems better.Yes, but completely same statement cannot be used because these is not
specified foreign server. How about:
NULL is returned if there are no established connections or this
function ...Yes, to align with the postgres_fdw_verify_connection_states()
case, how about writing the connection is not valid. Like the
following?
'NULL is returned if no valid connections are established or
this function...'
Prefer yours, fixed.
This is my comment for v35. Please check. 0002: 1. the comment of verify_cached_connections (I missed one minor point.) + * This function emits warnings if a disconnection is found. This returns true + * if disconnections cannot be found, otherwise returns false.I think false is returned only if disconnections are found and
true is returned in all other cases. So, modifying the description
like the following seems better.
'This returns false if disconnections are found, otherwise
returns true.'
Fixed.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v36-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v36-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From 80e7e98d63f71b2114b1059ba753c62381b15eed Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v36 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQconnCheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if existing connection is not closed by the remote peer.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 162 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 19 ++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 74 ++++++++
6 files changed, 258 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 12b54f15cd..da1155275f 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -87,6 +87,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -117,6 +120,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid, bool *checked);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1832,3 +1836,161 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found. This returns false
+ * if disconnections are found, otherwise returns true.
+ *
+ * checked will be set to true if PQconnCheck() is called at least once.
+ */
+static bool
+verify_cached_connections(Oid serverid, bool *checked)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ *checked = false;
+
+ Assert(ConnectionHash);
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQconnCheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+
+ /* Set a flag to notify the caller */
+ *checked = true;
+ }
+ }
+
+ /* Raise a warning if disconnections are found */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ (errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Connection close is detected."),
+ errhint("Plsease check the health of server.")));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found. This returns true
+ * if existing connection is not closed by the remote peer. false is returned
+ * if the local session seems to be disconnected from other servers. NULL is
+ * returned if a valid connection to the specified foreign server is not
+ * established or this function is not available on this platform.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+ bool result,
+ checked = false;
+
+ /* quick exit if the checking does not work well on this platfrom */
+ if (!PQconnCheckable())
+ PG_RETURN_NULL();
+
+ /* quick exit if connection cache has not been initialized yet */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ result = verify_cached_connections(server->serverid, &checked);
+
+ /* Return the result if checking function was called, otherwise NULL */
+ if (checked)
+ PG_RETURN_BOOL(result);
+ else
+ PG_RETURN_NULL();
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ bool result,
+ checked = false;
+
+ /* quick exit if the checking does not work well on this platfrom */
+ if (!PQconnCheckable())
+ PG_RETURN_NULL();
+
+ /* quick exit if connection cache has not been initialized yet */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ result = verify_cached_connections(InvalidOid, &checked);
+
+ /* Return the result if checking function was called, otherwise NULL */
+ if (checked)
+ PG_RETURN_BOOL(result);
+ else
+ PG_RETURN_NULL();
+}
+
+/*
+ * Check whether functions for verifying cached connections work well or not
+ */
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(PQconnCheckable());
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..a8556b4c9f
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,19 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 644f51835b..db4ce37c30 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -826,6 +826,80 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if existing connection is not closed by
+ the remote peer. <literal>false</literal> is returned if the local
+ session seems to be disconnected from other servers. <literal>NULL</literal>
+ is returned if a valid connection to the specified foreign server is not
+ established or this function is not available on this platform. If no
+ foreign server with the given name is found, an error is reported.
+ Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if all connections are not closed by the
+ remote peer. <literal>false</literal> is returned if the local session
+ seems to be disconnected from at least one remote server. <literal>NULL</literal>
+ is returned if no valid connections are established or this function is
+ not available on this platform. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether <function>postgres_fdw_verify_connection_states</function>
+ and <function>postgres_fdw_verify_connection_states_all</function> work
+ well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the
+ function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v36-0003-add-test.patchapplication/octet-stream; name=v36-0003-add-test.patchDownload
From 861ccc0f1a119305d4466f0a09f6043a8b3cb866 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:36 +0000
Subject: [PATCH v36 3/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 64 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 62 ++++++++++++++++++
2 files changed, 126 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 04a3ef450c..6446f36092 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11783,3 +11783,67 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+-- ..And call above function
+CALL test_verify_function(false);
+INFO: 00000
+ERROR: 08006
+CALL test_verify_function(true);
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 4f3088c03e..b413f96e32 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3979,3 +3979,65 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+-- ..And call above function
+CALL test_verify_function(false);
+CALL test_verify_function(true);
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
v36-0001-Add-PQconnCheck-and-PQconnCheckable-to-libpq.patchapplication/octet-stream; name=v36-0001-Add-PQconnCheck-and-PQconnCheckable-to-libpq.patchDownload
From 7183d0caec360464dbc0e5e83c31eef837d77477 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:18 +0000
Subject: [PATCH v36 1/3] Add PQconnCheck and PQconnCheckable to libpq
PQconnCheck() function allows to check the status of the connection by
polling the socket. This function is currently available only on systems
that support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQconnCheckable() checks whether the above function is available or not.
---
doc/src/sgml/libpq.sgml | 38 +++++++++++++++
src/interfaces/libpq/exports.txt | 2 +
src/interfaces/libpq/fe-misc.c | 79 ++++++++++++++++++++++++++------
src/interfaces/libpq/libpq-fe.h | 4 ++
4 files changed, 108 insertions(+), 15 deletions(-)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 3ccd8ff942..b1a4471403 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,44 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQconnCheck">
+ <term><function>PQconnCheck</function><indexterm><primary>PQconnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the health of the connection.
+
+<synopsis>
+int PQconnCheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ This function checks the health of the connection. Unlike <xref linkend="libpq-PQstatus"/>,
+ this check is performed by polling the corresponding socket. This
+ function is currently available only on systems that support the
+ non-standard <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol>
+ system call, including Linux. <xref linkend="libpq-PQconnCheck"/>
+ returns greater than zero if the remote peer seems to be closed, returns
+ <literal>0</literal> if the connection is not closed, and returns
+ <literal>-1</literal> if an error has occurred.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQconnCheckable">
+ <term><function>PQconnCheckable</function><indexterm><primary>PQconnCheckable</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns true (1) or false (0) to indicate if the <xref linkend="libpq-PQconnCheck"/>
+ function is supported on this platform.
+
+<synopsis>
+int PQconnCheckable(void);
+</synopsis>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..e7f0d435bd 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQconnCheck 187
+PQconnCheckable 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..897eb413b1 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -53,9 +53,10 @@
static int pqPutMsgBytes(const void *buf, size_t len, PGconn *conn);
static int pqSendSome(PGconn *conn, int len);
-static int pqSocketCheck(PGconn *conn, int forRead, int forWrite,
- time_t end_time);
-static int pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time);
+static int pqSocketCheck(PGconn *conn, int forRead,
+ int forWrite, int forConnCheck, time_t end_time);
+static int pqSocketPoll(int sock, int forRead,
+ int forWrite, int forConnCheck, time_t end_time);
/*
* PQlibVersion: return the libpq version number
@@ -993,7 +994,7 @@ pqWaitTimed(int forRead, int forWrite, PGconn *conn, time_t finish_time)
{
int result;
- result = pqSocketCheck(conn, forRead, forWrite, finish_time);
+ result = pqSocketCheck(conn, forRead, forWrite, 0, finish_time);
if (result < 0)
return -1; /* errorMessage is already set */
@@ -1014,7 +1015,7 @@ pqWaitTimed(int forRead, int forWrite, PGconn *conn, time_t finish_time)
int
pqReadReady(PGconn *conn)
{
- return pqSocketCheck(conn, 1, 0, (time_t) 0);
+ return pqSocketCheck(conn, 1, 0, 0, (time_t) 0);
}
/*
@@ -1024,19 +1025,52 @@ pqReadReady(PGconn *conn)
int
pqWriteReady(PGconn *conn)
{
- return pqSocketCheck(conn, 0, 1, (time_t) 0);
+ return pqSocketCheck(conn, 0, 1, 0, (time_t) 0);
+}
+
+/*
+ * Check whether the socket peer closed the connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad or an error occurred.
+ */
+int
+PQconnCheck(PGconn *conn)
+{
+ return pqSocketCheck(conn, 0, 0, 1, (time_t) 0);
+}
+
+/*
+ * Check whether PQconnCheck() can work on this platform.
+ *
+ * Returns true (1) if this can use PQconnCheck(), otherwise false (0).
+ */
+int
+PQconnCheckable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
}
/*
* Checks a socket, using poll or select, for data to be read, written,
- * or both. Returns >0 if one or more conditions are met, 0 if it timed
- * out, -1 if an error occurred.
+ * or both. Moreover, this function can check the health of the connetion on
+ * some limited platforms if forConnCehck is specified.
+ *
+ * Returns >0 if one or more conditions are met, 0 if it timed out, -1 if an
+ * error occurred. Note that if 0 is returned and forConnCheck is requested, it
+ * means that the socket has not matched POLLRDHUP event and the connection is
+ * not closed by the socket peer.
*
* If SSL is in use, the SSL buffer is checked prior to checking the socket
* for read data directly.
*/
static int
-pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
+pqSocketCheck(PGconn *conn, int forRead,
+ int forWrite, int forConnCheck, time_t end_time)
{
int result;
@@ -1059,7 +1093,8 @@ pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
/* We will retry as long as we get EINTR */
do
- result = pqSocketPoll(conn->sock, forRead, forWrite, end_time);
+ result = pqSocketPoll(conn->sock, forRead,
+ forWrite, forConnCheck, end_time);
while (result < 0 && SOCK_ERRNO == EINTR);
if (result < 0)
@@ -1076,15 +1111,21 @@ pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
/*
* Check a file descriptor for read and/or write data, possibly waiting.
- * If neither forRead nor forWrite are set, immediately return a timeout
- * condition (without waiting). Return >0 if condition is met, 0
- * if a timeout occurred, -1 if an error or interrupt occurred.
+ * Moreover, this function can check the health of connection on some limited
+ * platform if forConnCehck is specified.
+ *
+ * If neither forRead, forWrite nor forConnCheck are set, immediately return a
+ * timeout condition (without waiting). Return >0 if condition is met, 0 if a
+ * timeout occurred, -1 if an error or interrupt occurred. Note that if 0 is
+ * returned and forConnCheck is requested, it means that the socket has not
+ * matched POLLRDHUP event and the connection is not closed by the socket peer.
*
* Timeout is infinite if end_time is -1. Timeout is immediate (no blocking)
* if end_time is 0 (or indeed, any time before now).
*/
static int
-pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
+pqSocketPoll(int sock, int forRead,
+ int forWrite, int forConnCheck, time_t end_time)
{
/* We use poll(2) if available, otherwise select(2) */
#ifdef HAVE_POLL
@@ -1092,7 +1133,11 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
int timeout_ms;
if (!forRead && !forWrite)
- return 0;
+ {
+ /* Connection check can be available on some limted platforms */
+ if (!(forConnCheck && PQconnCheckable()))
+ return 0;
+ }
input_fd.fd = sock;
input_fd.events = POLLERR;
@@ -1102,6 +1147,10 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
input_fd.events |= POLLIN;
if (forWrite)
input_fd.events |= POLLOUT;
+#if defined(POLLRDHUP)
+ if (forConnCheck)
+ input_fd.events |= POLLRDHUP;
+#endif
/* Compute appropriate timeout interval */
if (end_time == ((time_t) -1))
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..e1bd0cd7b7 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,10 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQconnCheck(PGconn *conn);
+extern int PQconnCheckable(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
On Tue, 7 Mar 2023 at 09:53, Hayato Kuroda (Fujitsu)
<kuroda.hayato@fujitsu.com> wrote:
Dear Katsuragi-san,
Thank you for reviewing! PSA new version patches.
I think we can update the status to ready for committer after
this fix, if there is no objection.That's a very good news for me! How about other people?
7. the document of postgres_fdw_verify_connection_states_all <literal>NULL</literal> + is returned if the local session does not have connection caches, or this + function is not available on this platform.I think there is a case where a connection cache exists but valid
connections do not exist and NULL is returned (disconnection case).
Almost the same document as the postgres_fdw_verify_connection_states
case (comment no.5) seems better.Yes, but completely same statement cannot be used because these is not
specified foreign server. How about:
NULL is returned if there are no established connections or this
function ...Yes, to align with the postgres_fdw_verify_connection_states()
case, how about writing the connection is not valid. Like the
following?
'NULL is returned if no valid connections are established or
this function...'Prefer yours, fixed.
This is my comment for v35. Please check. 0002: 1. the comment of verify_cached_connections (I missed one minor point.) + * This function emits warnings if a disconnection is found. This returns true + * if disconnections cannot be found, otherwise returns false.I think false is returned only if disconnections are found and
true is returned in all other cases. So, modifying the description
like the following seems better.
'This returns false if disconnections are found, otherwise
returns true.'Fixed.
Few comments:
1) There is no handling of forConnCheck in #else HAVE_POLL, if this is
intentional we could add some comments for the same:
static int
-pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
+pqSocketPoll(int sock, int forRead,
+ int forWrite, int forConnCheck, time_t end_time)
{
/* We use poll(2) if available, otherwise select(2) */
#ifdef HAVE_POLL
@@ -1092,7 +1133,11 @@ pqSocketPoll(int sock, int forRead, int
forWrite, time_t end_time)
int timeout_ms;
if (!forRead && !forWrite)
- return 0;
2) Can this condition be added to the parent if condition:
if (!forRead && !forWrite)
- return 0;
+ {
+ /* Connection check can be available on some limted platforms */
+ if (!(forConnCheck && PQconnCheckable()))
+ return 0;
+ }
3) Can we add a comment for PQconnCheckable:
+/* Check whether the postgres server is still alive or not */
+extern int PQconnCheck(PGconn *conn);
+extern int PQconnCheckable(void);
+
4) "Note that if 0 is returned and forConnCheck is requested" doesn't
sound right, it can be changed to "Note that if 0 is returned when
forConnCheck is requested"
+ * If neither forRead, forWrite nor forConnCheck are set, immediately return a
+ * timeout condition (without waiting). Return >0 if condition is met, 0 if a
+ * timeout occurred, -1 if an error or interrupt occurred. Note that if 0 is
+ * returned and forConnCheck is requested, it means that the socket has not
+ * matched POLLRDHUP event and the connection is not closed by the socket peer.
Regards,
Vignesh
Dear Vignesh,
Thank you for reviewing! PSA new version.
Few comments: 1) There is no handling of forConnCheck in #else HAVE_POLL, if this is intentional we could add some comments for the same: static int -pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time) +pqSocketPoll(int sock, int forRead, + int forWrite, int forConnCheck, time_t end_time) { /* We use poll(2) if available, otherwise select(2) */ #ifdef HAVE_POLL @@ -1092,7 +1133,11 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time) int timeout_ms;if (!forRead && !forWrite)
- return 0;
Comments were added. This missing is intentional, because with the patch present
we do not implement checking feature for kqueue(). If you want to check the
detailed implementation of that, please see 0004 patch attached on [1]/messages/by-id/TYAPR01MB58669EAAC02493BFF9F39B06F5D99@TYAPR01MB5866.jpnprd01.prod.outlook.com.
2) Can this condition be added to the parent if condition: if (!forRead && !forWrite) - return 0; + { + /* Connection check can be available on some limted platforms */ + if (!(forConnCheck && PQconnCheckable())) + return 0; + }
Changed, and added comments atop the if-statement.
3) Can we add a comment for PQconnCheckable: +/* Check whether the postgres server is still alive or not */ +extern int PQconnCheck(PGconn *conn); +extern int PQconnCheckable(void); +
Added. And I found the tab should be used to divide data type and name, so fixed.
4) "Note that if 0 is returned and forConnCheck is requested" doesn't sound right, it can be changed to "Note that if 0 is returned when forConnCheck is requested" + * If neither forRead, forWrite nor forConnCheck are set, immediately return a + * timeout condition (without waiting). Return >0 if condition is met, 0 if a + * timeout occurred, -1 if an error or interrupt occurred. Note that if 0 is + * returned and forConnCheck is requested, it means that the socket has not + * matched POLLRDHUP event and the connection is not closed by the socket peer.
Fixed.
[1]: /messages/by-id/TYAPR01MB58669EAAC02493BFF9F39B06F5D99@TYAPR01MB5866.jpnprd01.prod.outlook.com
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v37-0001-Add-PQconnCheck-and-PQconnCheckable-to-libpq.patchapplication/octet-stream; name=v37-0001-Add-PQconnCheck-and-PQconnCheckable-to-libpq.patchDownload
From a7d47f6eba34077c0b9da7551b5be7c360131a6a Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:18 +0000
Subject: [PATCH v37 1/3] Add PQconnCheck and PQconnCheckable to libpq
PQconnCheck() function allows to check the status of the connection by
polling the socket. This function is currently available only on systems
that support the non-standard POLLRDHUP extension to the poll system call,
including Linux.
PQconnCheckable() checks whether the above function is available or not.
---
doc/src/sgml/libpq.sgml | 38 ++++++++++++++
src/interfaces/libpq/exports.txt | 2 +
src/interfaces/libpq/fe-misc.c | 86 ++++++++++++++++++++++++++------
src/interfaces/libpq/libpq-fe.h | 6 +++
4 files changed, 117 insertions(+), 15 deletions(-)
diff --git a/doc/src/sgml/libpq.sgml b/doc/src/sgml/libpq.sgml
index 3ccd8ff942..b1a4471403 100644
--- a/doc/src/sgml/libpq.sgml
+++ b/doc/src/sgml/libpq.sgml
@@ -2679,6 +2679,44 @@ void *PQgetssl(const PGconn *conn);
</listitem>
</varlistentry>
+ <varlistentry id="libpq-PQconnCheck">
+ <term><function>PQconnCheck</function><indexterm><primary>PQconnCheck</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns the health of the connection.
+
+<synopsis>
+int PQconnCheck(PGconn *conn);
+</synopsis>
+ </para>
+
+ <para>
+ This function checks the health of the connection. Unlike <xref linkend="libpq-PQstatus"/>,
+ this check is performed by polling the corresponding socket. This
+ function is currently available only on systems that support the
+ non-standard <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol>
+ system call, including Linux. <xref linkend="libpq-PQconnCheck"/>
+ returns greater than zero if the remote peer seems to be closed, returns
+ <literal>0</literal> if the connection is not closed, and returns
+ <literal>-1</literal> if an error has occurred.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry id="libpq-PQconnCheckable">
+ <term><function>PQconnCheckable</function><indexterm><primary>PQconnCheckable</primary></indexterm></term>
+ <listitem>
+ <para>
+ Returns true (1) or false (0) to indicate if the <xref linkend="libpq-PQconnCheck"/>
+ function is supported on this platform.
+
+<synopsis>
+int PQconnCheckable(void);
+</synopsis>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</para>
diff --git a/src/interfaces/libpq/exports.txt b/src/interfaces/libpq/exports.txt
index e8bcc88370..e7f0d435bd 100644
--- a/src/interfaces/libpq/exports.txt
+++ b/src/interfaces/libpq/exports.txt
@@ -186,3 +186,5 @@ PQpipelineStatus 183
PQsetTraceFlags 184
PQmblenBounded 185
PQsendFlushRequest 186
+PQconnCheck 187
+PQconnCheckable 188
diff --git a/src/interfaces/libpq/fe-misc.c b/src/interfaces/libpq/fe-misc.c
index 3653a1a8a6..ccb9a0ae31 100644
--- a/src/interfaces/libpq/fe-misc.c
+++ b/src/interfaces/libpq/fe-misc.c
@@ -53,9 +53,10 @@
static int pqPutMsgBytes(const void *buf, size_t len, PGconn *conn);
static int pqSendSome(PGconn *conn, int len);
-static int pqSocketCheck(PGconn *conn, int forRead, int forWrite,
- time_t end_time);
-static int pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time);
+static int pqSocketCheck(PGconn *conn, int forRead,
+ int forWrite, int forConnCheck, time_t end_time);
+static int pqSocketPoll(int sock, int forRead,
+ int forWrite, int forConnCheck, time_t end_time);
/*
* PQlibVersion: return the libpq version number
@@ -993,7 +994,7 @@ pqWaitTimed(int forRead, int forWrite, PGconn *conn, time_t finish_time)
{
int result;
- result = pqSocketCheck(conn, forRead, forWrite, finish_time);
+ result = pqSocketCheck(conn, forRead, forWrite, 0, finish_time);
if (result < 0)
return -1; /* errorMessage is already set */
@@ -1014,7 +1015,7 @@ pqWaitTimed(int forRead, int forWrite, PGconn *conn, time_t finish_time)
int
pqReadReady(PGconn *conn)
{
- return pqSocketCheck(conn, 1, 0, (time_t) 0);
+ return pqSocketCheck(conn, 1, 0, 0, (time_t) 0);
}
/*
@@ -1024,19 +1025,52 @@ pqReadReady(PGconn *conn)
int
pqWriteReady(PGconn *conn)
{
- return pqSocketCheck(conn, 0, 1, (time_t) 0);
+ return pqSocketCheck(conn, 0, 1, 0, (time_t) 0);
+}
+
+/*
+ * Check whether the socket peer closed the connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad or an error occurred.
+ */
+int
+PQconnCheck(PGconn *conn)
+{
+ return pqSocketCheck(conn, 0, 0, 1, (time_t) 0);
+}
+
+/*
+ * Check whether PQconnCheck() can work on this platform.
+ *
+ * Returns true (1) if this can use PQconnCheck(), otherwise false (0).
+ */
+int
+PQconnCheckable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
}
/*
* Checks a socket, using poll or select, for data to be read, written,
- * or both. Returns >0 if one or more conditions are met, 0 if it timed
- * out, -1 if an error occurred.
+ * or both. Moreover, this function can check the health of the connetion on
+ * some limited platforms if forConnCehck is specified.
+ *
+ * Returns >0 if one or more conditions are met, 0 if it timed out, -1 if an
+ * error occurred. Note that if 0 is returned when forConnCheck is requested,
+ * it means that the socket has not matched POLLRDHUP event and the connection
+ * is not closed by the socket peer.
*
* If SSL is in use, the SSL buffer is checked prior to checking the socket
* for read data directly.
*/
static int
-pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
+pqSocketCheck(PGconn *conn, int forRead,
+ int forWrite, int forConnCheck, time_t end_time)
{
int result;
@@ -1059,7 +1093,8 @@ pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
/* We will retry as long as we get EINTR */
do
- result = pqSocketPoll(conn->sock, forRead, forWrite, end_time);
+ result = pqSocketPoll(conn->sock, forRead,
+ forWrite, forConnCheck, end_time);
while (result < 0 && SOCK_ERRNO == EINTR);
if (result < 0)
@@ -1076,22 +1111,33 @@ pqSocketCheck(PGconn *conn, int forRead, int forWrite, time_t end_time)
/*
* Check a file descriptor for read and/or write data, possibly waiting.
- * If neither forRead nor forWrite are set, immediately return a timeout
- * condition (without waiting). Return >0 if condition is met, 0
- * if a timeout occurred, -1 if an error or interrupt occurred.
+ * Moreover, this function can check the health of connection on some limited
+ * platform if forConnCehck is specified.
+ *
+ * If neither forRead, forWrite nor forConnCheck are set, immediately return a
+ * timeout condition (without waiting). Return >0 if condition is met, 0 if a
+ * timeout occurred, -1 if an error or interrupt occurred. Note that if 0 is
+ * returned when forConnCheck is requested, it means that the socket has not
+ * matched POLLRDHUP event and the connection is not closed by the socket peer.
*
* Timeout is infinite if end_time is -1. Timeout is immediate (no blocking)
* if end_time is 0 (or indeed, any time before now).
*/
static int
-pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
+pqSocketPoll(int sock, int forRead,
+ int forWrite, int forConnCheck, time_t end_time)
{
/* We use poll(2) if available, otherwise select(2) */
#ifdef HAVE_POLL
struct pollfd input_fd;
int timeout_ms;
- if (!forRead && !forWrite)
+ /*
+ * Quick exit if no effective options are given. Note that connection
+ * check can be available on some limted platforms.
+ */
+ if (!forRead && !forWrite &&
+ !(forConnCheck && PQconnCheckable()))
return 0;
input_fd.fd = sock;
@@ -1102,6 +1148,10 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
input_fd.events |= POLLIN;
if (forWrite)
input_fd.events |= POLLOUT;
+#if defined(POLLRDHUP)
+ if (forConnCheck)
+ input_fd.events |= POLLRDHUP;
+#endif
/* Compute appropriate timeout interval */
if (end_time == ((time_t) -1))
@@ -1136,6 +1186,12 @@ pqSocketPoll(int sock, int forRead, int forWrite, time_t end_time)
if (forWrite)
FD_SET(sock, &output_mask);
+
+ /*
+ * forConncheck is not checked because the feature is not supported on
+ * this platform.
+ */
+
FD_SET(sock, &except_mask);
/* Compute appropriate timeout interval */
diff --git a/src/interfaces/libpq/libpq-fe.h b/src/interfaces/libpq/libpq-fe.h
index f3d9220496..3759a87225 100644
--- a/src/interfaces/libpq/libpq-fe.h
+++ b/src/interfaces/libpq/libpq-fe.h
@@ -648,6 +648,12 @@ extern int PQdsplen(const char *s, int encoding);
/* Get encoding id from environment variable PGCLIENTENCODING */
extern int PQenv2encoding(void);
+/* Check whether the postgres server is still alive or not */
+extern int PQconnCheck(PGconn *conn);
+
+/* Check whether PQconnCheck() can work on this platform */
+extern int PQconnCheckable(void);
+
/* === in fe-auth.c === */
extern char *PQencryptPassword(const char *passwd, const char *user);
--
2.27.0
v37-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchapplication/octet-stream; name=v37-0002-postgres_fdw-add-postgres_fdw_verify_connection_.patchDownload
From 789ea32a9bb3f5b9186a60fed85d1a30dc6b4441 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v37 2/3] postgres_fdw: add
postgres_fdw_verify_connection_states
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by PQconnCheck(), which means this is
available only on systems that support the non-standard POLLRDHUP extension
to the poll system call, including Linux.
This returns true if existing connection is not closed by the remote peer.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 162 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 19 ++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 74 ++++++++
6 files changed, 258 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 12b54f15cd..1bcf70cb12 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -87,6 +87,9 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_states_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection_states);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -117,6 +120,7 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static bool verify_cached_connections(Oid serverid, bool *checked);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1832,3 +1836,161 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID matches with the specified one. If
+ * InvalidOid is specified, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found. This returns false
+ * if disconnections are found, otherwise returns true.
+ *
+ * checked will be set to true if PQconnCheck() is called at least once.
+ */
+static bool
+verify_cached_connections(Oid serverid, bool *checked)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool result = true;
+ StringInfoData str;
+
+ *checked = false;
+
+ Assert(ConnectionHash);
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ if (PQconnCheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+
+ /* Set a flag to notify the caller */
+ *checked = true;
+ }
+ }
+
+ /* Raise a warning if disconnections are found */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Connection close is detected."),
+ errhint("Plsease check the health of server."));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Verify the specified cached connections.
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name.
+ *
+ * This function emits a warning if a disconnection is found. This returns true
+ * if existing connection is not closed by the remote peer. false is returned
+ * if the local session seems to be disconnected from other servers. NULL is
+ * returned if a valid connection to the specified foreign server is not
+ * established or this function is not available on this platform.
+ */
+Datum
+postgres_fdw_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ ForeignServer *server;
+ char *servername;
+ bool result,
+ checked = false;
+
+ /* quick exit if the checking does not work well on this platfrom */
+ if (!PQconnCheckable())
+ PG_RETURN_NULL();
+
+ /* quick exit if connection cache has not been initialized yet */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+ server = GetForeignServerByName(servername, false);
+
+ result = verify_cached_connections(server->serverid, &checked);
+
+ /* Return the result if checking function was called, otherwise NULL */
+ if (checked)
+ PG_RETURN_BOOL(result);
+ else
+ PG_RETURN_NULL();
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_states_all(PG_FUNCTION_ARGS)
+{
+ bool result,
+ checked = false;
+
+ /* quick exit if the checking does not work well on this platfrom */
+ if (!PQconnCheckable())
+ PG_RETURN_NULL();
+
+ /* quick exit if connection cache has not been initialized yet */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ result = verify_cached_connections(InvalidOid, &checked);
+
+ /* Return the result if checking function was called, otherwise NULL */
+ if (checked)
+ PG_RETURN_BOOL(result);
+ else
+ PG_RETURN_NULL();
+}
+
+/*
+ * Check whether functions for verifying cached connections work well or not
+ */
+Datum
+postgres_fdw_can_verify_connection_states(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(PQconnCheckable());
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..a8556b4c9f
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,19 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection_states (text)
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_states_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection_states ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 644f51835b..db4ce37c30 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -826,6 +826,80 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states(server_name text) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. This check is performed by polling the socket
+ and allows long-running transactions to be aborted sooner if the kernel
+ reports that the connection is closed. This function is currently
+ available only on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if existing connection is not closed by
+ the remote peer. <literal>false</literal> is returned if the local
+ session seems to be disconnected from other servers. <literal>NULL</literal>
+ is returned if a valid connection to the specified foreign server is not
+ established or this function is not available on this platform. If no
+ foreign server with the given name is found, an error is reported.
+ Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states('loopback1');
+ postgres_fdw_verify_connection_states
+---------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_states_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if all connections are not closed by the
+ remote peer. <literal>false</literal> is returned if the local session
+ seems to be disconnected from at least one remote server. <literal>NULL</literal>
+ is returned if no valid connections are established or this function is
+ not available on this platform. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_states_all();
+ postgres_fdw_verify_connection_states_all
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether <function>postgres_fdw_verify_connection_states</function>
+ and <function>postgres_fdw_verify_connection_states_all</function> work
+ well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the
+ function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v37-0003-add-test.patchapplication/octet-stream; name=v37-0003-add-test.patchDownload
From ac91e814de9b99550c120700c872d7da40b118b9 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:36 +0000
Subject: [PATCH v37 3/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 64 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 62 ++++++++++++++++++
2 files changed, 126 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 04a3ef450c..6446f36092 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11783,3 +11783,67 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+-- ..And call above function
+CALL test_verify_function(false);
+INFO: 00000
+ERROR: 08006
+CALL test_verify_function(true);
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 4f3088c03e..b413f96e32 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3979,3 +3979,65 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection_states();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_states_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection_states('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection_states_all() could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+-- ..And call above function
+CALL test_verify_function(false);
+CALL test_verify_function(true);
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
On 2023-03-08 13:40, Hayato Kuroda (Fujitsu) wrote:
Dear Vignesh,
Thank you for reviewing! PSA new version.
Hi,
Thank you for the comments, Vignesh.
Thank you for updating the patch, Kuroda-san. This fix looks fine to me.
And also, there seems no other comments from this post [1]/messages/by-id/TYAPR01MB5866F8EA3C06E1B43E42E4E4F5B79@TYAPR01MB5866.jpnprd01.prod.outlook.com.
So, I'm planning to update the status to ready for committer
on next Monday.
[1]: /messages/by-id/TYAPR01MB5866F8EA3C06E1B43E42E4E4F5B79@TYAPR01MB5866.jpnprd01.prod.outlook.com
/messages/by-id/TYAPR01MB5866F8EA3C06E1B43E42E4E4F5B79@TYAPR01MB5866.jpnprd01.prod.outlook.com
regards,
--
Katsuragi Yuta
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
On 2023-03-10 18:07, Katsuragi Yuta wrote:
On 2023-03-08 13:40, Hayato Kuroda (Fujitsu) wrote:
Dear Vignesh,
Thank you for reviewing! PSA new version.
Hi,
Thank you for the comments, Vignesh.
Thank you for updating the patch, Kuroda-san. This fix looks fine to
me.And also, there seems no other comments from this post [1].
So, I'm planning to update the status to ready for committer
on next Monday.[1]:
/messages/by-id/TYAPR01MB5866F8EA3C06E1B43E42E4E4F5B79@TYAPR01MB5866.jpnprd01.prod.outlook.comregards,
Hi,
I updated the status of the patch to ready for committer.
regards,
--
Katsuragi Yuta
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Katsuragi-san,
Hi,
I updated the status of the patch to ready for committer.
regards,
Thank you so much for your reviewing!
Now we can wait comments from senior members and committers.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
On 2023/03/13 16:05, Hayato Kuroda (Fujitsu) wrote:
Thank you so much for your reviewing!
Now we can wait comments from senior members and committers.
Thanks for working on this patch!
Regarding 0001 patch, on second thought, to me, it seems odd to expose
a function that doesn't have anything to directly do with PostgreSQL
as a libpq function. The function simply calls poll() on the socket
with POLLRDHUP if it is supported. While it is certainly convenient to
have this function, I'm not sure that it fits within the scope of libpq.
Thought?
Regarding 0002 patch, the behavior of postgres_fdw_verify_connection_states()
in regards to multiple connections using different user mappings seems
not well documented. The function seems to return false if either of
those connections has been closed.
This behavior means that it's difficult to identify which connection
has been closed when there are multiple ones to the given server.
To make it easier to identify that, it could be helpful to extend
the postgres_fdw_verify_connection_states() function so that it accepts
a unique connection as an input instead of just the server name.
One suggestion is to extend the function so that it accepts
both the server name and the user name used for the connection,
and checks the specified connection. If only the server name is specified,
the function should check all connections to the server and return false
if any of them are closed. This would be helpful since there is typically
only one connection to the server in most cases.
Additionally, it would be helpful to extend the postgres_fdw_get_connections()
function to also return the user name used for each connection,
as currently there is no straightforward way to identify it.
The function name "postgres_fdw_verify_connection_states" may seem
unnecessarily long to me. A simpler name like
"postgres_fdw_verify_connection" may be enough?
The patch may not be ready for commit due to the review comments,
and with the feature freeze approaching in a few days,
it may not be possible to include this feature in v16.
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Fujii Masao <masao.fujii@oss.nttdata.com> writes:
Regarding 0001 patch, on second thought, to me, it seems odd to expose
a function that doesn't have anything to directly do with PostgreSQL
as a libpq function. The function simply calls poll() on the socket
with POLLRDHUP if it is supported. While it is certainly convenient to
have this function, I'm not sure that it fits within the scope of libpq.
Thought?
Yeah, that does not seem great, partly because the semantics would be
platform-dependent. I don't think we want that to become part of
libpq's API.
regards, tom lane
Dear Fujii-san, Tom,
Thank you for giving a suggestion! PSA new version.
Regarding 0001 patch, on second thought, to me, it seems odd to expose
a function that doesn't have anything to directly do with PostgreSQL
as a libpq function. The function simply calls poll() on the socket
with POLLRDHUP if it is supported. While it is certainly convenient to
have this function, I'm not sure that it fits within the scope of libpq.
Thought?
Current style is motivated by Onder [1]/messages/by-id/CACawEhW19nPfbFpvfke9eidFDxAy+ic36wmY0s936T=xzxgHog@mail.gmail.com and later discussions. I thought it might
be useful for other developers, but OK, I can remove changes on libpq modules.
Horiguchi-san has suggested [2]/messages/by-id/20221017.172642.45253962719866795.horikyota.ntt@gmail.com that it might be overkill to use WaitEventSet()
mechanism, so I kept using poll().
I reused the same naming as previous version because they actually do something
Like libpq, but better naming is very welcome.
Regarding 0002 patch, the behavior of postgres_fdw_verify_connection_states()
in regards to multiple connections using different user mappings seems
not well documented. The function seems to return false if either of
those connections has been closed.
I did not considered the situation because I have not came up with the situation
that only one of connections to the same foreign server is broken.
This behavior means that it's difficult to identify which connection
has been closed when there are multiple ones to the given server.
To make it easier to identify that, it could be helpful to extend
the postgres_fdw_verify_connection_states() function so that it accepts
a unique connection as an input instead of just the server name.
One suggestion is to extend the function so that it accepts
both the server name and the user name used for the connection,
and checks the specified connection. If only the server name is specified,
the function should check all connections to the server and return false
if any of them are closed. This would be helpful since there is typically
only one connection to the server in most cases.
Just to confirm, your point "user name" means a local user, right?
I made a patch for addressing them.
Additionally, it would be helpful to extend the postgres_fdw_get_connections()
function to also return the user name used for each connection,
as currently there is no straightforward way to identify it.
Added, See 0003. IIUC there is no good way to extract user mapping from its OID, so I have
added an function to do that and used it.
The function name "postgres_fdw_verify_connection_states" may seem
unnecessarily long to me. A simpler name like
"postgres_fdw_verify_connection" may be enough?
Renamed.
The patch may not be ready for commit due to the review comments,
and with the feature freeze approaching in a few days,
it may not be possible to include this feature in v16.
It is sad for me, but it is more important for PostgreSQL to add nicer codes.
I changed status to "Needs review" again.
[1]: /messages/by-id/CACawEhW19nPfbFpvfke9eidFDxAy+ic36wmY0s936T=xzxgHog@mail.gmail.com
[2]: /messages/by-id/20221017.172642.45253962719866795.horikyota.ntt@gmail.com
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v38-0001-postgres_fdw-add-postgres_fdw_verify_connection-.patchapplication/octet-stream; name=v38-0001-postgres_fdw-add-postgres_fdw_verify_connection-.patchDownload
From d43d974921631c2bde433fd1f0fe4c912d0d116e Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v38 1/3] postgres_fdw: add postgres_fdw_verify_connection
variants
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by polling the socket. This feature is
currently available only on systems that support the non-standard POLLRDHUP
extension to the poll system call, including Linux.
They return true if existing connection is not closed by the remote peer.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 257 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 25 ++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 77 ++++++
6 files changed, 362 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 8eb9194506..5cd886bb2d 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -12,6 +12,10 @@
*/
#include "postgres.h"
+#if HAVE_POLL_H
+#include <poll.h>
+#endif
+
#include "access/htup_details.h"
#include "access/xact.h"
#include "catalog/pg_user_mapping.h"
@@ -24,6 +28,7 @@
#include "postgres_fdw.h"
#include "storage/fd.h"
#include "storage/latch.h"
+#include "utils/acl.h"
#include "utils/builtins.h"
#include "utils/datetime.h"
#include "utils/hsearch.h"
@@ -87,6 +92,10 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_server_user);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_server);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -117,6 +126,13 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static Datum postgres_fdw_verify_connection(FunctionCallInfo fcinfo);
+static bool verify_cached_connections(Oid serverid, Oid userid,
+ bool *checked);
+
+/* Low layer-like functions. They are used for verifying connections. */
+static int PQconnCheck(PGconn *conn);
+static bool PQconnCheckable(void);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1831,3 +1847,244 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID and user mapping OID matche with the
+ * specified one. If userid is specified as InvalidOid, it verifies cached
+ * connections which have arbitrary user mapping OID. If serverid is specified
+ * as InvalidOid, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found. This returns false
+ * if disconnections are found, otherwise returns true.
+ *
+ * checked will be set to true if PQconnCheck() is called at least once.
+ */
+static bool
+verify_cached_connections(Oid serverid, Oid userid, bool *checked)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool check_user_mapping = OidIsValid(userid);
+ bool result = true;
+ StringInfoData str;
+
+ Assert(ConnectionHash);
+
+ *checked = false;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ /* Skip if the given userid is different from the key */
+ if (!all && check_user_mapping && (entry->key != userid))
+ continue;
+
+ if (PQconnCheck(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\"", server->servername);
+ }
+
+ /* Set a flag to notify the caller */
+ *checked = true;
+ }
+ }
+
+ /* Raise a warning if disconnections are found */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Connection close is detected."),
+ errhint("Plsease check the health of server."));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Internal function for postgres_fdw_verify_connection variants
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name. If
+ * username is given, verifications are done only for foreign servers which is
+ * mapped by the user.
+ *
+ * This function emits a warning if a disconnection is found. This returns true
+ * if existing connection is not closed by the remote peer. false is returned
+ * if the local session seems to be disconnected from other servers. NULL is
+ * returned if a valid connection to the specified foreign server is not
+ * established or this function is not available on this platform.
+ */
+static Datum
+postgres_fdw_verify_connection(FunctionCallInfo fcinfo)
+{
+ ForeignServer *server = NULL;
+ UserMapping *user = NULL;
+ bool result,
+ checked;
+
+ /* Quick exit if the checking does not work well on this platfrom */
+ if (!PQconnCheckable())
+ PG_RETURN_NULL();
+
+ /* Quick exit if connection cache has not been initialized yet */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ /* If server name is specified, find a foreign server */
+ if (PG_NARGS() >= 1)
+ {
+ char *servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+
+ server = GetForeignServerByName(servername, false);
+ }
+
+ /* If user name is specified, find a user mapping */
+ if (PG_NARGS() >= 2)
+ {
+ char *username = text_to_cstring(PG_GETARG_TEXT_PP(1));
+ Oid userid = get_role_oid(username, false);
+
+ user = GetUserMapping(userid, server->serverid);
+ }
+
+ result = verify_cached_connections(server ? server->serverid : InvalidOid,
+ user ? user->umid : InvalidOid,
+ &checked);
+
+ if (checked)
+ PG_RETURN_BOOL(result);
+ else
+ PG_RETURN_NULL();
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_all(PG_FUNCTION_ARGS)
+{
+ return postgres_fdw_verify_connection(fcinfo);
+}
+
+/*
+ * postgres_fdw_verify_connection variants
+ *
+ * They are all named 'postgres_fdw_verify_connection' at the SQL level.
+ * They take combinations of server name and user name.
+ */
+
+/*
+ * This function passes both server name and user name to
+ * postgres_fdw_verify_connection().
+ */
+Datum
+postgres_fdw_verify_connection_server_user(PG_FUNCTION_ARGS)
+{
+ return postgres_fdw_verify_connection(fcinfo);
+}
+
+/*
+ * This function passes only server name to
+ * postgres_fdw_verify_connection().
+ */
+Datum
+postgres_fdw_verify_connection_server(PG_FUNCTION_ARGS)
+{
+ return postgres_fdw_verify_connection(fcinfo);
+}
+
+/*
+ * Check whether functions for verifying cached connections work well or not
+ */
+Datum
+postgres_fdw_can_verify_connection(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(PQconnCheckable());
+}
+
+/*
+ * Check whether the socket peer closed the connection or not.
+ *
+ * Returns >0 if remote peer seems to be closed, 0 if it is valid,
+ * -1 if the input connection is bad or an error occurred.
+ */
+int
+PQconnCheck(PGconn *conn)
+{
+ int sock = PQsocket(conn);
+ if (!PQconnCheckable())
+ return 0;
+
+ if (!conn || PQstatus(conn) != CONNECTION_OK || sock == PGINVALID_SOCKET)
+ return -1;
+
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ {
+ struct pollfd input_fd;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP;
+ input_fd.revents = 0;
+
+ poll(&input_fd, 1, 0);
+
+ return input_fd.revents;
+ }
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether PQconnCheck() can work on this platform.
+ *
+ * Returns true if this can use PQconnCheck(), otherwise false.
+ */
+bool
+PQconnCheckable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..78ee82cc74
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,25 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection (IN server_name text,
+ IN user_name text)
+RETURNS bool
+AS 'MODULE_PATHNAME', 'postgres_fdw_verify_connection_server_user'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection (IN server_name text)
+RETURNS bool
+AS 'MODULE_PATHNAME', 'postgres_fdw_verify_connection_server'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index d43ea71407..b4bc45b74f 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -831,6 +831,83 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection(server_name text <optional>, user_name text </optional>) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. If the user name is given, This function
+ checks only remote connections which is associated with the given user by
+ user mapping. Otherwise all the connections with given server name are
+ checked. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports that
+ the connection is closed. This function is currently available only on
+ systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if existing connection is not closed by
+ the remote peer. <literal>false</literal> is returned if either of
+ checked connections has been closed. <literal>NULL</literal> is returned
+ if a valid connection to the specified foreign server is not established
+ or this function is not available on this platform. If no foreign server
+ with the given name is found, an error is reported.
+ Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection('loopback1');
+ postgres_fdw_verify_connection
+--------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if all connections are not closed by the
+ remote peer. <literal>false</literal> is returned if the local session
+ seems to be disconnected from at least one remote server. <literal>NULL</literal>
+ is returned if no valid connections are established or this function is
+ not available on this platform. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_all();
+ postgres_fdw_verify_connection_all
+------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether <function>postgres_fdw_verify_connection</function>
+ and <function>postgres_fdw_verify_connection_all</function> work
+ well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the
+ function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.27.0
v38-0002-add-test.patchapplication/octet-stream; name=v38-0002-add-test.patchDownload
From 7ae9c0cd5dcc6d3d5bdf612218e8bd90b8b31c74 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:36 +0000
Subject: [PATCH v38 2/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 64 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 62 ++++++++++++++++++
2 files changed, 126 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 04a3ef450c..4723b2c5ce 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11783,3 +11783,67 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection variant could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+-- ..And call above function
+CALL test_verify_function(false);
+INFO: 00000
+ERROR: 08006
+CALL test_verify_function(true);
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 4f3088c03e..bce5d25aa7 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3979,3 +3979,65 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection variant could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+-- ..And call above function
+CALL test_verify_function(false);
+CALL test_verify_function(true);
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
v38-0003-Extend-postgres_fdw_get_connections-to-return-us.patchapplication/octet-stream; name=v38-0003-Extend-postgres_fdw_get_connections-to-return-us.patchDownload
From c281cde98debf6256ff3d682c3f764d6d73b8020 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Tue, 4 Apr 2023 16:19:06 +0000
Subject: [PATCH v38 3/3] Extend postgres_fdw_get_connections to return user
name
---
contrib/postgres_fdw/connection.c | 10 ++++--
.../postgres_fdw/expected/postgres_fdw.out | 2 +-
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 8 +++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 2 +-
doc/src/sgml/postgres-fdw.sgml | 32 +++++++++----------
src/backend/foreign/foreign.c | 28 ++++++++++++++++
src/include/foreign/foreign.h | 1 +
7 files changed, 63 insertions(+), 20 deletions(-)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 5cd886bb2d..b67082ae4d 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -1648,7 +1648,7 @@ pgfdw_finish_pre_subcommit_cleanup(List *pending_entries, int curlevel)
Datum
postgres_fdw_get_connections(PG_FUNCTION_ARGS)
{
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 2
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 3
ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
HASH_SEQ_STATUS scan;
ConnCacheEntry *entry;
@@ -1710,11 +1710,17 @@ postgres_fdw_get_connections(PG_FUNCTION_ARGS)
/* Show null, if no server name was found */
nulls[0] = true;
+ nulls[1] = true;
}
else
+ {
+ UserMapping *user = GetUserMappingFromOid(entry->key);
+
values[0] = CStringGetTextDatum(server->servername);
+ values[1] = CStringGetTextDatum(MappingUserName(user->userid));
+ }
- values[1] = BoolGetDatum(!entry->invalidated);
+ values[2] = BoolGetDatum(!entry->invalidated);
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 4723b2c5ce..1ee5a65aca 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10014,7 +10014,7 @@ drop cascades to foreign table ft7
-- List all the existing cached connections. loopback and loopback3
-- should be output as invalid connections. Also the server name for
-- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+SELECT server_name, valid FROM postgres_fdw_get_connections() ORDER BY 1;
server_name | valid
-------------+-------
loopback | f
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
index 78ee82cc74..8e6aa3e949 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -3,6 +3,14 @@
-- complain if script is sourced in psql, rather than via ALTER EXTENSION
\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+DROP FUNCTION postgres_fdw_get_connections ();
+
+CREATE FUNCTION postgres_fdw_get_connections (OUT server_name text,
+ OUT user_name text, OUT valid boolean)
+RETURNS SETOF record
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
CREATE FUNCTION postgres_fdw_verify_connection (IN server_name text,
IN user_name text)
RETURNS bool
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index bce5d25aa7..8a9297b29a 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3153,7 +3153,7 @@ DROP SERVER loopback3 CASCADE;
-- List all the existing cached connections. loopback and loopback3
-- should be output as invalid connections. Also the server name for
-- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+SELECT server_name, valid FROM postgres_fdw_get_connections() ORDER BY 1;
-- The invalid connections get closed in pgfdw_xact_callback during commit.
COMMIT;
-- All cached connections were closed while committing above xact, so no
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index b4bc45b74f..e57520629e 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -761,27 +761,27 @@ OPTIONS (ADD password_required 'false');
<variablelist>
<varlistentry>
- <term><function>postgres_fdw_get_connections(OUT server_name text, OUT valid boolean) returns setof record</function></term>
+ <term><function>postgres_fdw_get_connections(OUT server_name text, OUT user_name text, OUT valid boolean) returns setof record</function></term>
<listitem>
<para>
- This function returns the foreign server names of all the open
- connections that <filename>postgres_fdw</filename> established from
- the local session to the foreign servers. It also returns whether
- each connection is valid or not. <literal>false</literal> is returned
- if the foreign server connection is used in the current local
- transaction but its foreign server or user mapping is changed or
- dropped (Note that server name of an invalid connection will be
- <literal>NULL</literal> if the server is dropped),
- and then such invalid connection will be closed at
- the end of that transaction. <literal>true</literal> is returned
- otherwise. If there are no open connections, no record is returned.
+ This function returns the foreign server names and user names of all the
+ open connections that <filename>postgres_fdw</filename> established from
+ the local session to the foreign servers. It also returns whether each
+ connection is valid or not. <literal>false</literal> is returned if the
+ foreign server connection is used in the current local transaction but
+ its foreign server or user mapping is changed or dropped (Note that
+ server name and user name of an invalid connection will be
+ <literal>NULL</literal> if the server is dropped), and then such invalid
+ connection will be closed at the end of that transaction.
+ <literal>true</literal> is returned otherwise. If there are no open
+ connections, no record is returned.
Example usage of the function:
<screen>
postgres=# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid
--------------+-------
- loopback1 | t
- loopback2 | f
+ server_name | user_name | validvalid
+-------------+------------------------
+ loopback1 | postgres | t
+ loopback2 | | f
</screen>
</para>
</listitem>
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index dca02271dc..2dd7789fe6 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -242,6 +242,34 @@ GetUserMapping(Oid userid, Oid serverid)
return um;
}
+/*
+ * GetUserMappingFromOid - look up the user mapping by its oid.
+ */
+UserMapping *
+GetUserMappingFromOid(Oid usermappigid)
+{
+ HeapTuple tp;
+ UserMapping *um;
+ Form_pg_user_mapping umform;
+
+ tp = SearchSysCache1(USERMAPPINGOID,
+ ObjectIdGetDatum(usermappigid));
+
+ if (!HeapTupleIsValid(tp))
+ elog(ERROR, "cache lookup failed for user mapping %u", usermappigid);
+
+ umform = ((Form_pg_user_mapping) GETSTRUCT(tp));
+
+ um = (UserMapping *) palloc(sizeof(UserMapping));
+ um->umid = umform->oid;
+ um->userid = umform->umuser;
+ um->serverid = umform->umserver;
+
+ ReleaseSysCache(tp);
+
+ return um;
+}
+
/*
* GetForeignTable - look up the foreign table definition by relation oid.
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 5256d4d91f..25c9d40699 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -70,6 +70,7 @@ extern ForeignServer *GetForeignServerExtended(Oid serverid,
extern ForeignServer *GetForeignServerByName(const char *srvname,
bool missing_ok);
extern UserMapping *GetUserMapping(Oid userid, Oid serverid);
+extern UserMapping *GetUserMappingFromOid(Oid usermappigid);
extern ForeignDataWrapper *GetForeignDataWrapper(Oid fdwid);
extern ForeignDataWrapper *GetForeignDataWrapperExtended(Oid fdwid,
bits16 flags);
--
2.27.0
Dear hackers,
Dear Fujii-san, Tom,
Thank you for giving a suggestion! PSA new version.
I have reviewed and revised patches by myself.
* Fix handing of poll() based on the Horiguchi-san's point
* Fix WARNING message that shows user name which is used for connection
* PQconnCheck(), PQconnCheckable () are renamed
[1]: /messages/by-id/20230209.115009.2229702014236187289.horikyota.ntt@gmail.com
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v39-0001-postgres_fdw-add-postgres_fdw_verify_connection-.patchapplication/octet-stream; name=v39-0001-postgres_fdw-add-postgres_fdw_verify_connection-.patchDownload
From df23917e070654a4f06691467bc8ba41b771608b Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v39 1/3] postgres_fdw: add postgres_fdw_verify_connection
variants
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by polling the socket. This feature is
currently available only on systems that support the non-standard POLLRDHUP
extension to the poll system call, including Linux.
They return true if existing connection is not closed by the remote peer.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 271 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 25 ++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 77 +++++
src/backend/foreign/foreign.c | 28 ++
src/include/foreign/foreign.h | 1 +
8 files changed, 405 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 8eb9194506..9acd8835cd 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -12,6 +12,10 @@
*/
#include "postgres.h"
+#if HAVE_POLL_H
+#include <poll.h>
+#endif
+
#include "access/htup_details.h"
#include "access/xact.h"
#include "catalog/pg_user_mapping.h"
@@ -24,6 +28,7 @@
#include "postgres_fdw.h"
#include "storage/fd.h"
#include "storage/latch.h"
+#include "utils/acl.h"
#include "utils/builtins.h"
#include "utils/datetime.h"
#include "utils/hsearch.h"
@@ -87,6 +92,10 @@ static bool xact_got_connection = false;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_server_user);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_server);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -117,6 +126,13 @@ static void pgfdw_finish_pre_subcommit_cleanup(List *pending_entries,
int curlevel);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static Datum postgres_fdw_verify_connection(FunctionCallInfo fcinfo);
+static bool verify_cached_connections(Oid serverid, Oid userid,
+ bool *checked);
+
+/* Low layer-like functions. They are used for verifying connections. */
+static int pgfdw_conn_check(PGconn *conn);
+static bool pgfdw_conn_checkable(void);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1831,3 +1847,258 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID and user mapping OID matche with the
+ * specified one. If userid is specified as InvalidOid, it verifies cached
+ * connections which have arbitrary user mapping OID. If serverid is specified
+ * as InvalidOid, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found. This returns false
+ * if disconnections are found, otherwise returns true.
+ *
+ * checked will be set to true if pgfdw_conn_check() is called at least once.
+ */
+static bool
+verify_cached_connections(Oid serverid, Oid userid, bool *checked)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool check_user_mapping = OidIsValid(userid);
+ bool result = true;
+ StringInfoData str;
+
+ Assert(ConnectionHash);
+
+ *checked = false;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ /* Skip if the given userid is different from the key */
+ if (!all && check_user_mapping && (entry->key != userid))
+ continue;
+
+ if (pgfdw_conn_check(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+ UserMapping *user = GetUserMappingFromOid(entry->key);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\" for user \"%s\"",
+ server->servername,
+ MappingUserName(user->userid));
+ }
+
+ /* Set a flag to notify the caller */
+ *checked = true;
+ }
+ }
+
+ /* Raise a warning if disconnections are found */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Connection close is detected."),
+ errhint("Plsease check the health of server."));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Internal function for postgres_fdw_verify_connection variants
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name. If
+ * username is given, verifications are done only for foreign servers which is
+ * mapped by the user.
+ *
+ * This function emits a warning if a disconnection is found. This returns true
+ * if existing connection is not closed by the remote peer. false is returned
+ * if the local session seems to be disconnected from other servers. NULL is
+ * returned if a valid connection to the specified foreign server is not
+ * established or this function is not available on this platform.
+ */
+static Datum
+postgres_fdw_verify_connection(FunctionCallInfo fcinfo)
+{
+ ForeignServer *server = NULL;
+ UserMapping *user = NULL;
+ bool result,
+ checked;
+
+ /* Quick exit if the checking does not work well on this platfrom */
+ if (!pgfdw_conn_checkable())
+ PG_RETURN_NULL();
+
+ /* Quick exit if connection cache has not been initialized yet */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ /* If server name is specified, find a foreign server */
+ if (PG_NARGS() >= 1)
+ {
+ char *servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+
+ server = GetForeignServerByName(servername, false);
+ }
+
+ /* If user name is specified, find a user mapping */
+ if (PG_NARGS() >= 2)
+ {
+ char *username = text_to_cstring(PG_GETARG_TEXT_PP(1));
+ Oid userid = get_role_oid(username, false);
+
+ user = GetUserMapping(userid, server->serverid);
+ }
+
+ result = verify_cached_connections(server ? server->serverid : InvalidOid,
+ user ? user->umid : InvalidOid,
+ &checked);
+
+ if (checked)
+ PG_RETURN_BOOL(result);
+ else
+ PG_RETURN_NULL();
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_all(PG_FUNCTION_ARGS)
+{
+ return postgres_fdw_verify_connection(fcinfo);
+}
+
+/*
+ * postgres_fdw_verify_connection variants
+ *
+ * They are all named 'postgres_fdw_verify_connection' at the SQL level.
+ * They take combinations of server name and user name.
+ */
+
+/*
+ * This function passes both server name and user name to
+ * postgres_fdw_verify_connection().
+ */
+Datum
+postgres_fdw_verify_connection_server_user(PG_FUNCTION_ARGS)
+{
+ return postgres_fdw_verify_connection(fcinfo);
+}
+
+/*
+ * This function passes only server name to postgres_fdw_verify_connection().
+ * This means that the internal function does not care about the difference of
+ * local user.
+ */
+Datum
+postgres_fdw_verify_connection_server(PG_FUNCTION_ARGS)
+{
+ return postgres_fdw_verify_connection(fcinfo);
+}
+
+/*
+ * Check whether functions for verifying cached connections work well or not
+ */
+Datum
+postgres_fdw_can_verify_connection(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(pgfdw_conn_checkable());
+}
+
+/*
+ * Check whether the socket peer closed the connection or not.
+ *
+ * Returns >0 if input connection is bad or remote peer seems to be closed,
+ * 0 if it is valid, and -1 if an error occurred.
+ */
+static int
+pgfdw_conn_check(PGconn *conn)
+{
+ int sock = PQsocket(conn);
+ if (!pgfdw_conn_checkable())
+ return 0;
+
+ if (!conn || PQstatus(conn) != CONNECTION_OK || sock == PGINVALID_SOCKET)
+ return -1;
+
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ {
+ /*
+ * This platform seems to have poll(2), and can wait POLLRDHUP event.
+ * So construct pollfd and directly call it.
+ */
+ struct pollfd input_fd;
+ int result;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP;
+ input_fd.revents = 0;
+
+ do
+ result = poll(&input_fd, 1, 0);
+ while (result < 0 && errno == EINTR);
+
+ if (result < 0)
+ return -1;
+
+ return input_fd.revents;
+ }
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether pgfdw_conn_check() can work on this platform.
+ *
+ * Returns true if this can use pgfdw_conn_check(), otherwise false.
+ */
+static bool
+pgfdw_conn_checkable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..78ee82cc74
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,25 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection (IN server_name text,
+ IN user_name text)
+RETURNS bool
+AS 'MODULE_PATHNAME', 'postgres_fdw_verify_connection_server_user'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection (IN server_name text)
+RETURNS bool
+AS 'MODULE_PATHNAME', 'postgres_fdw_verify_connection_server'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index d43ea71407..b4bc45b74f 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -831,6 +831,83 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection(server_name text <optional>, user_name text </optional>) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. If the user name is given, This function
+ checks only remote connections which is associated with the given user by
+ user mapping. Otherwise all the connections with given server name are
+ checked. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports that
+ the connection is closed. This function is currently available only on
+ systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if existing connection is not closed by
+ the remote peer. <literal>false</literal> is returned if either of
+ checked connections has been closed. <literal>NULL</literal> is returned
+ if a valid connection to the specified foreign server is not established
+ or this function is not available on this platform. If no foreign server
+ with the given name is found, an error is reported.
+ Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection('loopback1');
+ postgres_fdw_verify_connection
+--------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if all connections are not closed by the
+ remote peer. <literal>false</literal> is returned if the local session
+ seems to be disconnected from at least one remote server. <literal>NULL</literal>
+ is returned if no valid connections are established or this function is
+ not available on this platform. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_all();
+ postgres_fdw_verify_connection_all
+------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether <function>postgres_fdw_verify_connection</function>
+ and <function>postgres_fdw_verify_connection_all</function> work
+ well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the
+ function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index dca02271dc..2dd7789fe6 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -242,6 +242,34 @@ GetUserMapping(Oid userid, Oid serverid)
return um;
}
+/*
+ * GetUserMappingFromOid - look up the user mapping by its oid.
+ */
+UserMapping *
+GetUserMappingFromOid(Oid usermappigid)
+{
+ HeapTuple tp;
+ UserMapping *um;
+ Form_pg_user_mapping umform;
+
+ tp = SearchSysCache1(USERMAPPINGOID,
+ ObjectIdGetDatum(usermappigid));
+
+ if (!HeapTupleIsValid(tp))
+ elog(ERROR, "cache lookup failed for user mapping %u", usermappigid);
+
+ umform = ((Form_pg_user_mapping) GETSTRUCT(tp));
+
+ um = (UserMapping *) palloc(sizeof(UserMapping));
+ um->umid = umform->oid;
+ um->userid = umform->umuser;
+ um->serverid = umform->umserver;
+
+ ReleaseSysCache(tp);
+
+ return um;
+}
+
/*
* GetForeignTable - look up the foreign table definition by relation oid.
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 5256d4d91f..25c9d40699 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -70,6 +70,7 @@ extern ForeignServer *GetForeignServerExtended(Oid serverid,
extern ForeignServer *GetForeignServerByName(const char *srvname,
bool missing_ok);
extern UserMapping *GetUserMapping(Oid userid, Oid serverid);
+extern UserMapping *GetUserMappingFromOid(Oid usermappigid);
extern ForeignDataWrapper *GetForeignDataWrapper(Oid fdwid);
extern ForeignDataWrapper *GetForeignDataWrapperExtended(Oid fdwid,
bits16 flags);
--
2.27.0
v39-0002-add-test.patchapplication/octet-stream; name=v39-0002-add-test.patchDownload
From ccf7a734b02e59a8b141d05e25d4129e24c4a0cd Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:36 +0000
Subject: [PATCH v39 2/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 64 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 62 ++++++++++++++++++
2 files changed, 126 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 04a3ef450c..4723b2c5ce 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -11783,3 +11783,67 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection variant could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+-- ..And call above function
+CALL test_verify_function(false);
+INFO: 00000
+ERROR: 08006
+CALL test_verify_function(true);
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 4f3088c03e..bce5d25aa7 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3979,3 +3979,65 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection variant could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+-- ..And call above function
+CALL test_verify_function(false);
+CALL test_verify_function(true);
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
v39-0003-Extend-postgres_fdw_get_connections-to-return-us.patchapplication/octet-stream; name=v39-0003-Extend-postgres_fdw_get_connections-to-return-us.patchDownload
From d0cbf7e58af6cd27e86ff80dc1b88198ff3cdb7f Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Wed, 5 Apr 2023 06:10:51 +0000
Subject: [PATCH v39 3/3] Extend postgres_fdw_get_connections to return user
name
---
contrib/postgres_fdw/connection.c | 10 ++++--
.../postgres_fdw/expected/postgres_fdw.out | 2 +-
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 8 +++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 2 +-
doc/src/sgml/postgres-fdw.sgml | 32 +++++++++----------
5 files changed, 34 insertions(+), 20 deletions(-)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 9acd8835cd..e19f051d0c 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -1648,7 +1648,7 @@ pgfdw_finish_pre_subcommit_cleanup(List *pending_entries, int curlevel)
Datum
postgres_fdw_get_connections(PG_FUNCTION_ARGS)
{
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 2
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 3
ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
HASH_SEQ_STATUS scan;
ConnCacheEntry *entry;
@@ -1710,11 +1710,17 @@ postgres_fdw_get_connections(PG_FUNCTION_ARGS)
/* Show null, if no server name was found */
nulls[0] = true;
+ nulls[1] = true;
}
else
+ {
+ UserMapping *user = GetUserMappingFromOid(entry->key);
+
values[0] = CStringGetTextDatum(server->servername);
+ values[1] = CStringGetTextDatum(MappingUserName(user->userid));
+ }
- values[1] = BoolGetDatum(!entry->invalidated);
+ values[2] = BoolGetDatum(!entry->invalidated);
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 4723b2c5ce..1ee5a65aca 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10014,7 +10014,7 @@ drop cascades to foreign table ft7
-- List all the existing cached connections. loopback and loopback3
-- should be output as invalid connections. Also the server name for
-- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+SELECT server_name, valid FROM postgres_fdw_get_connections() ORDER BY 1;
server_name | valid
-------------+-------
loopback | f
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
index 78ee82cc74..8e6aa3e949 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -3,6 +3,14 @@
-- complain if script is sourced in psql, rather than via ALTER EXTENSION
\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+DROP FUNCTION postgres_fdw_get_connections ();
+
+CREATE FUNCTION postgres_fdw_get_connections (OUT server_name text,
+ OUT user_name text, OUT valid boolean)
+RETURNS SETOF record
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
CREATE FUNCTION postgres_fdw_verify_connection (IN server_name text,
IN user_name text)
RETURNS bool
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index bce5d25aa7..8a9297b29a 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3153,7 +3153,7 @@ DROP SERVER loopback3 CASCADE;
-- List all the existing cached connections. loopback and loopback3
-- should be output as invalid connections. Also the server name for
-- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+SELECT server_name, valid FROM postgres_fdw_get_connections() ORDER BY 1;
-- The invalid connections get closed in pgfdw_xact_callback during commit.
COMMIT;
-- All cached connections were closed while committing above xact, so no
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index b4bc45b74f..e57520629e 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -761,27 +761,27 @@ OPTIONS (ADD password_required 'false');
<variablelist>
<varlistentry>
- <term><function>postgres_fdw_get_connections(OUT server_name text, OUT valid boolean) returns setof record</function></term>
+ <term><function>postgres_fdw_get_connections(OUT server_name text, OUT user_name text, OUT valid boolean) returns setof record</function></term>
<listitem>
<para>
- This function returns the foreign server names of all the open
- connections that <filename>postgres_fdw</filename> established from
- the local session to the foreign servers. It also returns whether
- each connection is valid or not. <literal>false</literal> is returned
- if the foreign server connection is used in the current local
- transaction but its foreign server or user mapping is changed or
- dropped (Note that server name of an invalid connection will be
- <literal>NULL</literal> if the server is dropped),
- and then such invalid connection will be closed at
- the end of that transaction. <literal>true</literal> is returned
- otherwise. If there are no open connections, no record is returned.
+ This function returns the foreign server names and user names of all the
+ open connections that <filename>postgres_fdw</filename> established from
+ the local session to the foreign servers. It also returns whether each
+ connection is valid or not. <literal>false</literal> is returned if the
+ foreign server connection is used in the current local transaction but
+ its foreign server or user mapping is changed or dropped (Note that
+ server name and user name of an invalid connection will be
+ <literal>NULL</literal> if the server is dropped), and then such invalid
+ connection will be closed at the end of that transaction.
+ <literal>true</literal> is returned otherwise. If there are no open
+ connections, no record is returned.
Example usage of the function:
<screen>
postgres=# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid
--------------+-------
- loopback1 | t
- loopback2 | f
+ server_name | user_name | validvalid
+-------------+------------------------
+ loopback1 | postgres | t
+ loopback2 | | f
</screen>
</para>
</listitem>
--
2.27.0
On Mon, Dec 11, 2023 at 2:08 PM Hayato Kuroda (Fujitsu)
<kuroda.hayato@fujitsu.com> wrote:
Dear Fujii-san, Tom,
Thank you for giving a suggestion! PSA new version.
Regarding 0001 patch, on second thought, to me, it seems odd to expose
a function that doesn't have anything to directly do with PostgreSQL
as a libpq function. The function simply calls poll() on the socket
with POLLRDHUP if it is supported. While it is certainly convenient to
have this function, I'm not sure that it fits within the scope of libpq.
Thought?Current style is motivated by Onder [1] and later discussions. I thought it might
be useful for other developers, but OK, I can remove changes on libpq modules.
Horiguchi-san has suggested [2] that it might be overkill to use WaitEventSet()
mechanism, so I kept using poll().
I reused the same naming as previous version because they actually do something
Like libpq, but better naming is very welcome.Regarding 0002 patch, the behavior of postgres_fdw_verify_connection_states()
in regards to multiple connections using different user mappings seems
not well documented. The function seems to return false if either of
those connections has been closed.I did not considered the situation because I have not came up with the situation
that only one of connections to the same foreign server is broken.This behavior means that it's difficult to identify which connection
has been closed when there are multiple ones to the given server.
To make it easier to identify that, it could be helpful to extend
the postgres_fdw_verify_connection_states() function so that it accepts
a unique connection as an input instead of just the server name.
One suggestion is to extend the function so that it accepts
both the server name and the user name used for the connection,
and checks the specified connection. If only the server name is specified,
the function should check all connections to the server and return false
if any of them are closed. This would be helpful since there is typically
only one connection to the server in most cases.Just to confirm, your point "user name" means a local user, right?
I made a patch for addressing them.Additionally, it would be helpful to extend the postgres_fdw_get_connections()
function to also return the user name used for each connection,
as currently there is no straightforward way to identify it.Added, See 0003. IIUC there is no good way to extract user mapping from its OID, so I have
added an function to do that and used it.The function name "postgres_fdw_verify_connection_states" may seem
unnecessarily long to me. A simpler name like
"postgres_fdw_verify_connection" may be enough?Renamed.
The patch may not be ready for commit due to the review comments,
and with the feature freeze approaching in a few days,
it may not be possible to include this feature in v16.It is sad for me, but it is more important for PostgreSQL to add nicer codes.
I changed status to "Needs review" again.
I am failing to apply the latest
Patch-"v39-0001-postgres_fdw-add-postgres_fdw_verify_connection-.patch"
for review. Please find the error I am facing:
D:\Project\Postgres>git am
D:\Project\Patch\v39-0001-postgres_fdw-add-postgres_fdw_verify_connection-.patch
error: patch failed: contrib/postgres_fdw/connection.c:117
error: contrib/postgres_fdw/connection.c: patch does not apply
hint: Use 'git am --show-current-patch=diff' to see the failed patch
Applying: postgres_fdw: add postgres_fdw_verify_connection variants
Patch failed at 0001 postgres_fdw: add postgres_fdw_verify_connection variants
When you have resolved this problem, run "git am --continue".
If you prefer to skip this patch, run "git am --skip" instead.
To restore the original branch and stop patching, run "git am --abort".
Please rebase and post an updated version of the Patch.
Thanks and Regards,
Shubham Khanna.
Dear Shubham,
I am failing to apply the latest
Patch-"v39-0001-postgres_fdw-add-postgres_fdw_verify_connection-.patch"
for review. Please find the error I am facing:
D:\Project\Postgres>git am
D:\Project\Patch\v39-0001-postgres_fdw-add-postgres_fdw_verify_connection
-.patch
error: patch failed: contrib/postgres_fdw/connection.c:117
error: contrib/postgres_fdw/connection.c: patch does not apply
hint: Use 'git am --show-current-patch=diff' to see the failed patch
Applying: postgres_fdw: add postgres_fdw_verify_connection variants
Patch failed at 0001 postgres_fdw: add postgres_fdw_verify_connection variants
When you have resolved this problem, run "git am --continue".
If you prefer to skip this patch, run "git am --skip" instead.
To restore the original branch and stop patching, run "git am --abort".
Oh, good catch. Here is a new patch set. There are no new changes from v39.
Best Regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v40-0001-postgres_fdw-add-postgres_fdw_verify_connection-.patchapplication/octet-stream; name=v40-0001-postgres_fdw-add-postgres_fdw_verify_connection-.patchDownload
From 246ee4a63daafaba1bcf462bd1b72fd4406653ad Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v40 1/3] postgres_fdw: add postgres_fdw_verify_connection
variants
This function can verify the status of connections that are establieshed by
postgres_fdw. This check wil be done by polling the socket. This feature is
currently available only on systems that support the non-standard POLLRDHUP
extension to the poll system call, including Linux.
They return true if existing connection is not closed by the remote peer.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 271 ++++++++++++++++++
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 25 ++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 77 +++++
src/backend/foreign/foreign.c | 28 ++
src/include/foreign/foreign.h | 1 +
8 files changed, 405 insertions(+), 2 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 5800c6a9fb..ad1fd00289 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -12,6 +12,10 @@
*/
#include "postgres.h"
+#if HAVE_POLL_H
+#include <poll.h>
+#endif
+
#include "access/htup_details.h"
#include "access/xact.h"
#include "catalog/pg_user_mapping.h"
@@ -25,6 +29,7 @@
#include "postgres_fdw.h"
#include "storage/fd.h"
#include "storage/latch.h"
+#include "utils/acl.h"
#include "utils/builtins.h"
#include "utils/datetime.h"
#include "utils/hsearch.h"
@@ -113,6 +118,10 @@ static uint32 pgfdw_we_get_result = 0;
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_server_user);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_server);
+PG_FUNCTION_INFO_V1(postgres_fdw_verify_connection_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -159,6 +168,13 @@ static void pgfdw_security_check(const char **keywords, const char **values,
UserMapping *user, PGconn *conn);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static Datum postgres_fdw_verify_connection(FunctionCallInfo fcinfo);
+static bool verify_cached_connections(Oid serverid, Oid userid,
+ bool *checked);
+
+/* Low layer-like functions. They are used for verifying connections. */
+static int pgfdw_conn_check(PGconn *conn);
+static bool pgfdw_conn_checkable(void);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -2241,3 +2257,258 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Workhorse to verify cached connections.
+ *
+ * This function scans all the connection cache entries and verifies the
+ * connections whose foreign server OID and user mapping OID matche with the
+ * specified one. If userid is specified as InvalidOid, it verifies cached
+ * connections which have arbitrary user mapping OID. If serverid is specified
+ * as InvalidOid, it verifies all the cached connections.
+ *
+ * This function emits warnings if a disconnection is found. This returns false
+ * if disconnections are found, otherwise returns true.
+ *
+ * checked will be set to true if pgfdw_conn_check() is called at least once.
+ */
+static bool
+verify_cached_connections(Oid serverid, Oid userid, bool *checked)
+{
+ HASH_SEQ_STATUS scan;
+ ConnCacheEntry *entry;
+ bool all = !OidIsValid(serverid);
+ bool check_user_mapping = OidIsValid(userid);
+ bool result = true;
+ StringInfoData str;
+
+ Assert(ConnectionHash);
+
+ *checked = false;
+
+ hash_seq_init(&scan, ConnectionHash);
+ while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
+ {
+ /* Ignore cache entry if no open connection right now */
+ if (!entry->conn)
+ continue;
+
+ /* Skip if the entry is invalidated */
+ if (entry->invalidated)
+ continue;
+
+ if (all || entry->serverid == serverid)
+ {
+ /* Skip if the given userid is different from the key */
+ if (!all && check_user_mapping && (entry->key != userid))
+ continue;
+
+ if (pgfdw_conn_check(entry->conn))
+ {
+ /* A foreign server might be down, so construct a message */
+ ForeignServer *server = GetForeignServer(entry->serverid);
+ UserMapping *user = GetUserMappingFromOid(entry->key);
+
+ if (result)
+ {
+ /*
+ * Initialize and add a prefix if this is the first
+ * disconnection we found.
+ */
+ initStringInfo(&str);
+ appendStringInfo(&str, "could not connect to server ");
+
+ result = false;
+ }
+ else
+ appendStringInfo(&str, ", ");
+
+ appendStringInfo(&str, "\"%s\" for user \"%s\"",
+ server->servername,
+ MappingUserName(user->userid));
+ }
+
+ /* Set a flag to notify the caller */
+ *checked = true;
+ }
+ }
+
+ /* Raise a warning if disconnections are found */
+ if (!result)
+ {
+ Assert(str.len);
+ ereport(WARNING,
+ errcode(ERRCODE_CONNECTION_FAILURE),
+ errmsg("%s", str.data),
+ errdetail("Connection close is detected."),
+ errhint("Plsease check the health of server."));
+ pfree(str.data);
+ }
+
+ return result;
+}
+
+/*
+ * Internal function for postgres_fdw_verify_connection variants
+ *
+ * This function verifies the connections that are established by postgres_fdw
+ * from the local session to the foreign server with the given name. If
+ * username is given, verifications are done only for foreign servers which is
+ * mapped by the user.
+ *
+ * This function emits a warning if a disconnection is found. This returns true
+ * if existing connection is not closed by the remote peer. false is returned
+ * if the local session seems to be disconnected from other servers. NULL is
+ * returned if a valid connection to the specified foreign server is not
+ * established or this function is not available on this platform.
+ */
+static Datum
+postgres_fdw_verify_connection(FunctionCallInfo fcinfo)
+{
+ ForeignServer *server = NULL;
+ UserMapping *user = NULL;
+ bool result,
+ checked;
+
+ /* Quick exit if the checking does not work well on this platfrom */
+ if (!pgfdw_conn_checkable())
+ PG_RETURN_NULL();
+
+ /* Quick exit if connection cache has not been initialized yet */
+ if (!ConnectionHash)
+ PG_RETURN_NULL();
+
+ /* If server name is specified, find a foreign server */
+ if (PG_NARGS() >= 1)
+ {
+ char *servername = text_to_cstring(PG_GETARG_TEXT_PP(0));
+
+ server = GetForeignServerByName(servername, false);
+ }
+
+ /* If user name is specified, find a user mapping */
+ if (PG_NARGS() >= 2)
+ {
+ char *username = text_to_cstring(PG_GETARG_TEXT_PP(1));
+ Oid userid = get_role_oid(username, false);
+
+ user = GetUserMapping(userid, server->serverid);
+ }
+
+ result = verify_cached_connections(server ? server->serverid : InvalidOid,
+ user ? user->umid : InvalidOid,
+ &checked);
+
+ if (checked)
+ PG_RETURN_BOOL(result);
+ else
+ PG_RETURN_NULL();
+}
+
+/*
+ * Verify all the cached connections.
+ *
+ * This function verifies all the connections that are established by postgres_fdw
+ * from the local session to the foreign servers.
+ */
+Datum
+postgres_fdw_verify_connection_all(PG_FUNCTION_ARGS)
+{
+ return postgres_fdw_verify_connection(fcinfo);
+}
+
+/*
+ * postgres_fdw_verify_connection variants
+ *
+ * They are all named 'postgres_fdw_verify_connection' at the SQL level.
+ * They take combinations of server name and user name.
+ */
+
+/*
+ * This function passes both server name and user name to
+ * postgres_fdw_verify_connection().
+ */
+Datum
+postgres_fdw_verify_connection_server_user(PG_FUNCTION_ARGS)
+{
+ return postgres_fdw_verify_connection(fcinfo);
+}
+
+/*
+ * This function passes only server name to postgres_fdw_verify_connection().
+ * This means that the internal function does not care about the difference of
+ * local user.
+ */
+Datum
+postgres_fdw_verify_connection_server(PG_FUNCTION_ARGS)
+{
+ return postgres_fdw_verify_connection(fcinfo);
+}
+
+/*
+ * Check whether functions for verifying cached connections work well or not
+ */
+Datum
+postgres_fdw_can_verify_connection(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(pgfdw_conn_checkable());
+}
+
+/*
+ * Check whether the socket peer closed the connection or not.
+ *
+ * Returns >0 if input connection is bad or remote peer seems to be closed,
+ * 0 if it is valid, and -1 if an error occurred.
+ */
+static int
+pgfdw_conn_check(PGconn *conn)
+{
+ int sock = PQsocket(conn);
+ if (!pgfdw_conn_checkable())
+ return 0;
+
+ if (!conn || PQstatus(conn) != CONNECTION_OK || sock == PGINVALID_SOCKET)
+ return -1;
+
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ {
+ /*
+ * This platform seems to have poll(2), and can wait POLLRDHUP event.
+ * So construct pollfd and directly call it.
+ */
+ struct pollfd input_fd;
+ int result;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP;
+ input_fd.revents = 0;
+
+ do
+ result = poll(&input_fd, 1, 0);
+ while (result < 0 && errno == EINTR);
+
+ if (result < 0)
+ return -1;
+
+ return input_fd.revents;
+ }
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether pgfdw_conn_check() can work on this platform.
+ *
+ * Returns true if this can use pgfdw_conn_check(), otherwise false.
+ */
+static bool
+pgfdw_conn_checkable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b451f165e..29118d47bb 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..78ee82cc74
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,25 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+CREATE FUNCTION postgres_fdw_verify_connection (IN server_name text,
+ IN user_name text)
+RETURNS bool
+AS 'MODULE_PATHNAME', 'postgres_fdw_verify_connection_server_user'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection (IN server_name text)
+RETURNS bool
+AS 'MODULE_PATHNAME', 'postgres_fdw_verify_connection_server'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_verify_connection_all ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 2ba96aa295..a01ad80c53 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -847,6 +847,83 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection(server_name text <optional>, user_name text </optional>) returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of remote connections established by
+ <filename>postgres_fdw</filename> from the local session to the foreign
+ server with the given name. If the user name is given, This function
+ checks only remote connections which is associated with the given user by
+ user mapping. Otherwise all the connections with given server name are
+ checked. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports that
+ the connection is closed. This function is currently available only on
+ systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if existing connection is not closed by
+ the remote peer. <literal>false</literal> is returned if either of
+ checked connections has been closed. <literal>NULL</literal> is returned
+ if a valid connection to the specified foreign server is not established
+ or this function is not available on this platform. If no foreign server
+ with the given name is found, an error is reported.
+ Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection('loopback1');
+ postgres_fdw_verify_connection
+--------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+ <varlistentry>
+ <term><function>postgres_fdw_verify_connection_all() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks the status of all the remote connections established
+ by <filename>postgres_fdw</filename> from the local session to the
+ foreign servers. This check is performed by polling the socket and allows
+ long-running transactions to be aborted sooner if the kernel reports
+ that the connection is closed. This function is currently available only
+ on systems that support the non-standard <symbol>POLLRDHUP</symbol>
+ extension to the <symbol>poll</symbol> system call, including Linux. This
+ returns <literal>true</literal> if all connections are not closed by the
+ remote peer. <literal>false</literal> is returned if the local session
+ seems to be disconnected from at least one remote server. <literal>NULL</literal>
+ is returned if no valid connections are established or this function is
+ not available on this platform. Example usage of the function:
+<screen>
+postgres=# SELECT postgres_fdw_verify_connection_all();
+ postgres_fdw_verify_connection_all
+------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection_states() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether <function>postgres_fdw_verify_connection</function>
+ and <function>postgres_fdw_verify_connection_all</function> work
+ well or not. This returns <literal>true</literal> if it can be used,
+ otherwise returns <literal>false</literal>. Example usage of the
+ function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection_states();
+ postgres_fdw_can_verify_connection_states
+-------------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index fc3edef2a8..8a5cd80732 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -246,6 +246,34 @@ GetUserMapping(Oid userid, Oid serverid)
return um;
}
+/*
+ * GetUserMappingFromOid - look up the user mapping by its oid.
+ */
+UserMapping *
+GetUserMappingFromOid(Oid usermappigid)
+{
+ HeapTuple tp;
+ UserMapping *um;
+ Form_pg_user_mapping umform;
+
+ tp = SearchSysCache1(USERMAPPINGOID,
+ ObjectIdGetDatum(usermappigid));
+
+ if (!HeapTupleIsValid(tp))
+ elog(ERROR, "cache lookup failed for user mapping %u", usermappigid);
+
+ umform = ((Form_pg_user_mapping) GETSTRUCT(tp));
+
+ um = (UserMapping *) palloc(sizeof(UserMapping));
+ um->umid = umform->oid;
+ um->userid = umform->umuser;
+ um->serverid = umform->umserver;
+
+ ReleaseSysCache(tp);
+
+ return um;
+}
+
/*
* GetForeignTable - look up the foreign table definition by relation oid.
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 5256d4d91f..25c9d40699 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -70,6 +70,7 @@ extern ForeignServer *GetForeignServerExtended(Oid serverid,
extern ForeignServer *GetForeignServerByName(const char *srvname,
bool missing_ok);
extern UserMapping *GetUserMapping(Oid userid, Oid serverid);
+extern UserMapping *GetUserMappingFromOid(Oid usermappigid);
extern ForeignDataWrapper *GetForeignDataWrapper(Oid fdwid);
extern ForeignDataWrapper *GetForeignDataWrapperExtended(Oid fdwid,
bits16 flags);
--
2.27.0
v40-0002-add-test.patchapplication/octet-stream; name=v40-0002-add-test.patchDownload
From 793c8976302fc127d419d7864cdf97e43aef6d16 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:36 +0000
Subject: [PATCH v40 2/3] add test
---
.../postgres_fdw/expected/postgres_fdw.out | 64 +++++++++++++++++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 62 ++++++++++++++++++
2 files changed, 126 insertions(+)
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index c988745b92..566d37df60 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -12165,3 +12165,67 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection variant could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+-- ..And call above function
+CALL test_verify_function(false);
+INFO: 00000
+ERROR: 08006
+CALL test_verify_function(true);
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index cb40540702..7b3ae99511 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -4176,3 +4176,65 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_verify_foreign_servers function
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function(use_all boolean) AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ IF use_all IS TRUE THEN
+ SELECT INTO result postgres_fdw_verify_connection_all();
+ ELSE
+ SELECT INTO result postgres_fdw_verify_connection('loopback');
+ END IF;
+
+ RESET client_min_messages;
+ ELSE
+ result = false;
+ END IF;
+
+ -- If result is FALSE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS FALSE THEN
+ RAISE INFO 'postgres_fdw_verify_connection variant could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+-- ..And call above function
+CALL test_verify_function(false);
+CALL test_verify_function(true);
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
--
2.27.0
v40-0003-Extend-postgres_fdw_get_connections-to-return-us.patchapplication/octet-stream; name=v40-0003-Extend-postgres_fdw_get_connections-to-return-us.patchDownload
From a4a6bc0b090f93772d88b17f02743ec87304f0f0 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Wed, 5 Apr 2023 06:10:51 +0000
Subject: [PATCH v40 3/3] Extend postgres_fdw_get_connections to return user
name
---
contrib/postgres_fdw/connection.c | 10 ++++--
.../postgres_fdw/expected/postgres_fdw.out | 2 +-
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 8 +++++
contrib/postgres_fdw/sql/postgres_fdw.sql | 2 +-
doc/src/sgml/postgres-fdw.sgml | 32 +++++++++----------
5 files changed, 34 insertions(+), 20 deletions(-)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index ad1fd00289..39a0d72246 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -2058,7 +2058,7 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
Datum
postgres_fdw_get_connections(PG_FUNCTION_ARGS)
{
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 2
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 3
ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
HASH_SEQ_STATUS scan;
ConnCacheEntry *entry;
@@ -2120,11 +2120,17 @@ postgres_fdw_get_connections(PG_FUNCTION_ARGS)
/* Show null, if no server name was found */
nulls[0] = true;
+ nulls[1] = true;
}
else
+ {
+ UserMapping *user = GetUserMappingFromOid(entry->key);
+
values[0] = CStringGetTextDatum(server->servername);
+ values[1] = CStringGetTextDatum(MappingUserName(user->userid));
+ }
- values[1] = BoolGetDatum(!entry->invalidated);
+ values[2] = BoolGetDatum(!entry->invalidated);
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 566d37df60..7d4c2e5884 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10349,7 +10349,7 @@ drop cascades to foreign table ft7
-- List all the existing cached connections. loopback and loopback3
-- should be output as invalid connections. Also the server name for
-- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+SELECT server_name, valid FROM postgres_fdw_get_connections() ORDER BY 1;
server_name | valid
-------------+-------
loopback | f
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
index 78ee82cc74..8e6aa3e949 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -3,6 +3,14 @@
-- complain if script is sourced in psql, rather than via ALTER EXTENSION
\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+DROP FUNCTION postgres_fdw_get_connections ();
+
+CREATE FUNCTION postgres_fdw_get_connections (OUT server_name text,
+ OUT user_name text, OUT valid boolean)
+RETURNS SETOF record
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
CREATE FUNCTION postgres_fdw_verify_connection (IN server_name text,
IN user_name text)
RETURNS bool
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 7b3ae99511..d1bf46fd35 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3326,7 +3326,7 @@ DROP SERVER loopback3 CASCADE;
-- List all the existing cached connections. loopback and loopback3
-- should be output as invalid connections. Also the server name for
-- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+SELECT server_name, valid FROM postgres_fdw_get_connections() ORDER BY 1;
-- The invalid connections get closed in pgfdw_xact_callback during commit.
COMMIT;
-- All cached connections were closed while committing above xact, so no
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index a01ad80c53..8cc32f09f4 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -777,27 +777,27 @@ OPTIONS (ADD password_required 'false');
<variablelist>
<varlistentry>
- <term><function>postgres_fdw_get_connections(OUT server_name text, OUT valid boolean) returns setof record</function></term>
+ <term><function>postgres_fdw_get_connections(OUT server_name text, OUT user_name text, OUT valid boolean) returns setof record</function></term>
<listitem>
<para>
- This function returns the foreign server names of all the open
- connections that <filename>postgres_fdw</filename> established from
- the local session to the foreign servers. It also returns whether
- each connection is valid or not. <literal>false</literal> is returned
- if the foreign server connection is used in the current local
- transaction but its foreign server or user mapping is changed or
- dropped (Note that server name of an invalid connection will be
- <literal>NULL</literal> if the server is dropped),
- and then such invalid connection will be closed at
- the end of that transaction. <literal>true</literal> is returned
- otherwise. If there are no open connections, no record is returned.
+ This function returns the foreign server names and user names of all the
+ open connections that <filename>postgres_fdw</filename> established from
+ the local session to the foreign servers. It also returns whether each
+ connection is valid or not. <literal>false</literal> is returned if the
+ foreign server connection is used in the current local transaction but
+ its foreign server or user mapping is changed or dropped (Note that
+ server name and user name of an invalid connection will be
+ <literal>NULL</literal> if the server is dropped), and then such invalid
+ connection will be closed at the end of that transaction.
+ <literal>true</literal> is returned otherwise. If there are no open
+ connections, no record is returned.
Example usage of the function:
<screen>
postgres=# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid
--------------+-------
- loopback1 | t
- loopback2 | f
+ server_name | user_name | validvalid
+-------------+------------------------
+ loopback1 | postgres | t
+ loopback2 | | f
</screen>
</para>
</listitem>
--
2.27.0
On 2023/12/12 11:43, Hayato Kuroda (Fujitsu) wrote:
Dear Shubham,
I am failing to apply the latest
Patch-"v39-0001-postgres_fdw-add-postgres_fdw_verify_connection-.patch"
for review. Please find the error I am facing:
D:\Project\Postgres>git am
D:\Project\Patch\v39-0001-postgres_fdw-add-postgres_fdw_verify_connection
-.patch
error: patch failed: contrib/postgres_fdw/connection.c:117
error: contrib/postgres_fdw/connection.c: patch does not apply
hint: Use 'git am --show-current-patch=diff' to see the failed patch
Applying: postgres_fdw: add postgres_fdw_verify_connection variants
Patch failed at 0001 postgres_fdw: add postgres_fdw_verify_connection variants
When you have resolved this problem, run "git am --continue".
If you prefer to skip this patch, run "git am --skip" instead.
To restore the original branch and stop patching, run "git am --abort".Oh, good catch. Here is a new patch set. There are no new changes from v39.
Thanks for the patches!
I've just started reviewing them.
Here are the review comments for 0001 patch:
Do we really need postgres_fdw_verify_connection_all()? The proposed feature
aims to check if all postgres_fdw connections used within the transaction
are still open. If any of those connections are closed, the transaction
can't be committed successfully, so users can roll back immediately upon
detecting a closed connection.
However, postgres_fdw_verify_connection_all() checks all connections made in
the session, not just those used in the current transaction. This means
users can't determine if they should roll back the transaction based on
its return value. Therefore, I'm concerned that
postgres_fdw_verify_connection_all() might not be very useful. Thoughts?
Considering the purpose of this feature, wouldn't it be better to extend
postgres_fdw_get_connections() to include a "used_in_xact" column
(indicating whether the connection has been used in the current transaction)
and a "closed" column (indicating whether the connection has been closed)?
This approach might be more effective than introducing a new function
like the postgres_fdw_verify_connection family?
If it's too much to check if the connection is closed by default whenever
calling postgres_fdw_get_connections(), we could modify it to accept
an argument indicating whether to perform this check. Thoughts?
Here are the review comments for 0003 patch:
The source comment in postgres_fdw_get_connections() should mention
the return value user_name.
We also need to handle the case where the user mapping used by
the connection cache has been dropped. Otherwise, this could
lead to an error.
-----------------------------
=# BEGIN;
=*# SELECT * FROM postgres_fdw_get_connections();
server_name | user_name | valid
-------------+-----------+-------
loopback | public | t
(1 row)
=*# DROP USER MAPPING FOR public SERVER loopback ;
=*# SELECT * FROM postgres_fdw_get_connections();
ERROR: cache lookup failed for user mapping 16409
-----------------------------
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+SELECT server_name, valid FROM postgres_fdw_get_connections() ORDER BY 1;
Shouldn't this test also check if the returned user_name is valid?
+ server_name | user_name | validvalid
+-------------+------------------------
+ loopback1 | postgres | t
+ loopback2 | | f
The column name "validvalid" should be "valid".
How can we cause the record with server_name != NULL but user_name = NULL?
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Fujii-san,
Hi, long time no see :-).
Thanks for reviewing the patch! PSA new version.
I've just started reviewing them.
Here are the review comments for 0001 patch:
Do we really need postgres_fdw_verify_connection_all()? The proposed feature
aims to check if all postgres_fdw connections used within the transaction
are still open. If any of those connections are closed, the transaction
can't be committed successfully, so users can roll back immediately upon
detecting a closed connection.However, postgres_fdw_verify_connection_all() checks all connections made in
the session, not just those used in the current transaction. This means
users can't determine if they should roll back the transaction based on
its return value. Therefore, I'm concerned that
postgres_fdw_verify_connection_all() might not be very useful. Thoughts?
Right. My primal motivation is to detect the disconnection from remotes and abort
current transaction as soon as possible. In this case, as I posted in [1]/messages/by-id/TYAPR01MB58668728393648C2F7DC7C85F5399@TYAPR01MB5866.jpnprd01.prod.outlook.com,
...all() is not so helpful.
I agreed to remove the function from patch set. Done.
Considering the purpose of this feature, wouldn't it be better to extend
postgres_fdw_get_connections() to include a "used_in_xact" column
(indicating whether the connection has been used in the current transaction)
and a "closed" column (indicating whether the connection has been closed)?
This approach might be more effective than introducing a new function
like the postgres_fdw_verify_connection family?If it's too much to check if the connection is closed by default whenever
calling postgres_fdw_get_connections(), we could modify it to accept
an argument indicating whether to perform this check. Thoughts?
Sounds interesting. If we can accept to change the definition of pre-existing
function, it seems better. To keep the default behavior, an input parameter
should be added. Attached patch tried to implement.
Here are the review comments for 0003 patch:
The source comment in postgres_fdw_get_connections() should mention
the return value user_name.
Document was updated.
We also need to handle the case where the user mapping used by
the connection cache has been dropped. Otherwise, this could
lead to an error.-----------------------------
=# BEGIN;
=*# SELECT * FROM postgres_fdw_get_connections();
server_name | user_name | valid
-------------+-----------+-------
loopback | public | t
(1 row)=*# DROP USER MAPPING FOR public SERVER loopback ;
=*# SELECT * FROM postgres_fdw_get_connections();
ERROR: cache lookup failed for user mapping 16409
-----------------------------
Fixed.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1; +SELECT server_name, valid FROM postgres_fdw_get_connections() ORDER BY 1;Shouldn't this test also check if the returned user_name is valid?
You meant to say that we should print the user_name, right? Done.
+ server_name | user_name | validvalid +-------------+------------------------ + loopback1 | postgres | t + loopback2 | | fThe column name "validvalid" should be "valid".
Right, fixed.
How can we cause the record with server_name != NULL but user_name = NULL?
Now this can happen when user_name is dropped, but the example was updated.
Below contains a summary of changes.
0001:
- Instead of adding new functions, postgres_fdw_get_connections() was extended.
Some tricks were added to support old versions. I followed pg_stat_statements.c.
Attributes were added after the `valid` to preserve ordering of the old version.
- I found an inconsistency of name between source and doc,
so I unified to postgres_fdw_can_verify_connection().
- Also, test patch (0002) was combined into this.
0002:
- user_name was added after the `valid` to preserve ordering of the old version.
- GetUserMappingFromOid() is allowed to miss a tuple.
[1]: /messages/by-id/TYAPR01MB58668728393648C2F7DC7C85F5399@TYAPR01MB5866.jpnprd01.prod.outlook.com
Best regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v41-0001-postgres_fdw-Allow-postgres_fdw_get_connections-.patchapplication/octet-stream; name=v41-0001-postgres_fdw-Allow-postgres_fdw_get_connections-.patchDownload
From 60cd57abf3a161ccbe5c0e6cdd506fd0db965f04 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v41 1/2] postgres_fdw: Allow postgres_fdw_get_connections() to
check connection
If requested, postgres_fdw_get_connections() can verify the status of
connections that are establieshed by postgres_fdw. This check wil be
done by polling the socket. This feature is currently available only
on systems that support the non-standard POLLRDHUP extension to the
poll system call, including Linux.
"closed" column is set to false if existing connection is not closed
by the remote peer.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 151 +++++++++++++++++-
.../postgres_fdw/expected/postgres_fdw.out | 65 +++++++-
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 22 +++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
contrib/postgres_fdw/sql/postgres_fdw.sql | 57 +++++++
doc/src/sgml/postgres-fdw.sgml | 71 ++++++--
8 files changed, 344 insertions(+), 27 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index c1b0cad453..6d23768389 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 33e8054f64..edc2f5eb46 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -12,6 +12,10 @@
*/
#include "postgres.h"
+#if HAVE_POLL_H
+#include <poll.h>
+#endif
+
#include "access/htup_details.h"
#include "access/xact.h"
#include "catalog/pg_user_mapping.h"
@@ -107,12 +111,20 @@ static uint32 pgfdw_we_get_result = 0;
(entry)->xact_depth, (entry)->xact_depth); \
} while(0)
+enum pgfdwVersion
+{
+ PGFDW_V1_0 = 0,
+ PGFDW_V1_2,
+} pgfdwVersion;
+
/*
* SQL functions
*/
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
+PG_FUNCTION_INFO_V1(postgres_fdw_get_connections_1_2);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
+PG_FUNCTION_INFO_V1(postgres_fdw_can_verify_connection);
/* prototypes of private functions */
static void make_new_connection(ConnCacheEntry *entry, UserMapping *user);
@@ -159,6 +171,12 @@ static void pgfdw_security_check(const char **keywords, const char **values,
UserMapping *user, PGconn *conn);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static Datum postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
+ enum pgfdwVersion api_version);
+
+/* Low layer-like functions. They are used for verifying connections. */
+static int pgfdw_conn_check(PGconn *conn);
+static bool pgfdw_conn_checkable(void);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1978,22 +1996,31 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
}
/*
- * List active foreign server connections.
+ * Internal function for postgres_fdw_get_connections variants.
*
- * This function takes no input parameter and returns setof record made of
- * following values:
+ * If the api_version is 1.0, this function takes no input parameter and
+ * returns setof record made of following values:
* - server_name - server name of active connection. In case the foreign server
* is dropped but still the connection is active, then the server name will
* be NULL in output.
* - valid - true/false representing whether the connection is valid or not.
* Note that the connections can get invalidated in pgfdw_inval_callback.
*
+ * If the version is 1.2 and later, this function takes an input parameter,
+ * which indicates the need for a health check. Regarding the returned record,
+ * this returns two additional values:
+ * - used_in_xact - indicates whether the server has been used in a transaction
+ * or not.
+ * - closed - true if the local session seems to be disconnected from other
+ * servers.
+ *
* No records are returned when there are no cached connections at all.
*/
-Datum
-postgres_fdw_get_connections(PG_FUNCTION_ARGS)
+static Datum
+postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
+ enum pgfdwVersion api_version)
{
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 2
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 4
ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
HASH_SEQ_STATUS scan;
ConnCacheEntry *entry;
@@ -2061,12 +2088,55 @@ postgres_fdw_get_connections(PG_FUNCTION_ARGS)
values[1] = BoolGetDatum(!entry->invalidated);
+ /* Add additional attributes if the version is 1.2 or later */
+ if (api_version == PGFDW_V1_2)
+ {
+ bool require_verify = PG_GETARG_BOOL(1);
+
+ /* Has this server been used in the transaction? */
+ values[2] = BoolGetDatum(entry->xact_depth > 0);
+
+ /*
+ * If requested and the connection is not invalidated, check the
+ * status of the remote connection from the backend process and
+ * return the result. Otherwise returns NULL.
+ */
+ if (require_verify && !entry->invalidated && entry->conn)
+ {
+ values[3] = BoolGetDatum(pgfdw_conn_checkable() ?
+ pgfdw_conn_check(entry->conn) != 0 :
+ false);
+ }
+ else
+ nulls[3] = true;
+ }
+
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
}
PG_RETURN_VOID();
}
+/*
+ * List active foreign server connections.
+ *
+ * The SQL API of this function has changed in version, which could verify the
+ * status of remote connections. The actual implementation was moved to the
+ * internal function, and we could switch by the api_version to support the old
+ * SQL declaration.
+ */
+Datum
+postgres_fdw_get_connections_1_2(PG_FUNCTION_ARGS)
+{
+ return postgres_fdw_get_connections_internal(fcinfo, PGFDW_V1_2);
+}
+
+Datum
+postgres_fdw_get_connections(PG_FUNCTION_ARGS)
+{
+ return postgres_fdw_get_connections_internal(fcinfo, PGFDW_V1_0);
+}
+
/*
* Disconnect the specified cached connections.
*
@@ -2192,3 +2262,72 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Check whether functions for verifying cached connections work well or not
+ */
+Datum
+postgres_fdw_can_verify_connection(PG_FUNCTION_ARGS)
+{
+ PG_RETURN_BOOL(pgfdw_conn_checkable());
+}
+
+/*
+ * Check whether the socket peer closed the connection or not.
+ *
+ * Returns >0 if input connection is bad or remote peer seems to be closed,
+ * 0 if it is valid, and -1 if an error occurred.
+ */
+static int
+pgfdw_conn_check(PGconn *conn)
+{
+ int sock = PQsocket(conn);
+
+ if (!pgfdw_conn_checkable())
+ return 0;
+
+ if (!conn || PQstatus(conn) != CONNECTION_OK || sock == PGINVALID_SOCKET)
+ return -1;
+
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ {
+ /*
+ * This platform seems to have poll(2), and can wait POLLRDHUP event.
+ * So construct pollfd and directly call it.
+ */
+ struct pollfd input_fd;
+ int result;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP;
+ input_fd.revents = 0;
+
+ do
+ result = poll(&input_fd, 1, 0);
+ while (result < 0 && errno == EINTR);
+
+ if (result < 0)
+ return -1;
+
+ return input_fd.revents;
+ }
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether pgfdw_conn_check() can work on this platform.
+ *
+ * Returns true if this can use pgfdw_conn_check(), otherwise false.
+ */
+static bool
+pgfdw_conn_checkable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 0cc77190dc..4fcf73070c 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10435,10 +10435,10 @@ drop cascades to foreign table ft7
-- should be output as invalid connections. Also the server name for
-- loopback3 should be NULL because the server was dropped.
SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid
--------------+-------
- loopback | f
- | f
+ server_name | valid | used_in_xact | closed
+-------------+-------+--------------+--------
+ loopback | f | t |
+ | f | t |
(2 rows)
-- The invalid connections get closed in pgfdw_xact_callback during commit.
@@ -12257,3 +12257,60 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_get_connections function with require_verify = true
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function() AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT closed INTO result FROM postgres_fdw_get_connections(true);
+
+ RESET client_min_messages;
+ ELSE
+ result = true;
+ END IF;
+
+ -- If result is TRUE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS TRUE THEN
+ RAISE INFO 'postgres_fdw_get_connections could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+-- ..And call above function
+CALL test_verify_function();
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index 2b86d8a6ee..5f60d8ef97 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..6af10110ca
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,22 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+/* First we have to remove it from the extension */
+ALTER EXTENSION postgres_fdw DROP FUNCTION postgres_fdw_get_connections ();
+
+/* Then we can drop it */
+DROP FUNCTION postgres_fdw_get_connections ();
+
+CREATE FUNCTION postgres_fdw_get_connections
+ (IN require_verify boolean DEFAULT false, OUT server_name text,
+ OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
+RETURNS SETOF record
+AS 'MODULE_PATHNAME', 'postgres_fdw_get_connections_1_2'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
+
+CREATE FUNCTION postgres_fdw_can_verify_connection ()
+RETURNS bool
+AS 'MODULE_PATHNAME'
+LANGUAGE C STRICT PARALLEL SAFE;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index b57f8cfda6..fa9c4dd36f 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -4218,3 +4218,60 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_get_connections function with require_verify = true
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- -- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function() AS $$
+DECLARE
+ can_verify boolean;
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ -- Check whether we can do health check on this platform
+ SELECT INTO can_verify postgres_fdw_can_verify_connection();
+
+ -- If the checking can be done on this platform, call it
+ IF can_verify IS TRUE THEN
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
+ SET LOCAL client_min_messages TO ERROR;
+
+ SELECT closed INTO result FROM postgres_fdw_get_connections(true);
+
+ RESET client_min_messages;
+ ELSE
+ result = true;
+ END IF;
+
+ -- If result is TRUE, we succeeded to detect the disconnection or it could
+ -- not be done on this platform. Raise an message.
+ IF result IS TRUE THEN
+ RAISE INFO 'postgres_fdw_get_connections could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+-- ..And call above function
+CALL test_verify_function();
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 1a600382e2..fa2b50450d 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -777,27 +777,48 @@ OPTIONS (ADD password_required 'false');
<variablelist>
<varlistentry>
- <term><function>postgres_fdw_get_connections(OUT server_name text, OUT valid boolean) returns setof record</function></term>
+ <term><function>postgres_fdw_get_connections(IN require_verify boolean DEFAULT false,
+ OUT server_name text, OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
+ returns setof record</function></term>
<listitem>
<para>
This function returns the foreign server names of all the open
connections that <filename>postgres_fdw</filename> established from
- the local session to the foreign servers. It also returns whether
- each connection is valid or not. <literal>false</literal> is returned
- if the foreign server connection is used in the current local
- transaction but its foreign server or user mapping is changed or
- dropped (Note that server name of an invalid connection will be
- <literal>NULL</literal> if the server is dropped),
- and then such invalid connection will be closed at
- the end of that transaction. <literal>true</literal> is returned
- otherwise. If there are no open connections, no record is returned.
+ the local session to the foreign servers. It also returns whether each
+ connection is valid and has been used within a transaction.
+ <literal>valid</literal> is returned as <literal>false</literal> if the
+ foreign server connection is used in the current local transaction but
+ its foreign server or user mapping is changed or dropped (Note that
+ server name of an invalid connection will be <literal>NULL</literal> if
+ the server is dropped), and then such invalid connection will be closed
+ at the end of that transaction. The attribute is set to <literal>true</literal>
+ otherwise.
+ </para>
+ <para>
+ If <literal>require_verify</literal> is set to <literal>true</literal>,
+ the function checks the status of remote connections from the local
+ session to the foreign server. This check is performed by polling the
+ socket, which allows long-running transactions to be aborted sooner if
+ the kernel reports that the connection is closed. This feature is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <literal>closed</literal> attribute indicates the
+ result of this check. <literal>false</literal> means the existing
+ connection is not closed by the remote peer. <literal>true</literal>
+ means if either checked connection has been closed.
+ <literal>NULL</literal> means a valid connection to the specified foreign
+ server is not established, this function is not available on this
+ platform, or <literal>require_verify</literal> is <literal>false</literal>.
+ </para>
+ <para>
+ If there are no open connections, no record is returned.
Example usage of the function:
<screen>
-postgres=# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid
--------------+-------
- loopback1 | t
- loopback2 | f
+postgres=*# SELECT * FROM postgres_fdw_get_connections(true) ORDER BY 1;
+ server_name | valid | used_in_xact | closed
+-------------+-------+--------------+--------
+ loopback1 | t | t | f
+ loopback2 | t | t | f
</screen>
</para>
</listitem>
@@ -847,6 +868,26 @@ postgres=# SELECT postgres_fdw_disconnect_all();
</para>
</listitem>
</varlistentry>
+
+ <varlistentry>
+ <term><function>postgres_fdw_can_verify_connection() returns boolean</function></term>
+ <listitem>
+ <para>
+ This function checks whether <function>postgres_fdw_get_connections</function>
+ can verify the status of remote connections or not. This returns
+ <literal>true</literal> if it can be used, otherwise returns <literal>false</literal>.
+ Example usage of the function:
+
+<screen>
+postgres=# SELECT postgres_fdw_can_verify_connection();
+ postgres_fdw_can_verify_connection
+------------------------------------
+ t
+</screen>
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</sect2>
--
2.43.0
v41-0002-Extend-postgres_fdw_get_connections-to-return-us.patchapplication/octet-stream; name=v41-0002-Extend-postgres_fdw_get_connections-to-return-us.patchDownload
From aeeb82bee861dceb9eae3d8a46226d878c20d2cd Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Thu, 18 Jul 2024 10:11:03 +0000
Subject: [PATCH v41 2/2] Extend postgres_fdw_get_connections to return user
name
---
contrib/postgres_fdw/connection.c | 33 +++++++++++++++---
.../postgres_fdw/expected/postgres_fdw.out | 13 +++----
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 3 +-
contrib/postgres_fdw/sql/postgres_fdw.sql | 5 +--
doc/src/sgml/postgres-fdw.sgml | 12 +++----
src/backend/foreign/foreign.c | 34 +++++++++++++++++++
src/include/foreign/foreign.h | 1 +
7 files changed, 81 insertions(+), 20 deletions(-)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index edc2f5eb46..18abb0994e 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -2008,7 +2008,10 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
*
* If the version is 1.2 and later, this function takes an input parameter,
* which indicates the need for a health check. Regarding the returned record,
- * this returns two additional values:
+ * this returns three additional values:
+ * - user_name - user mapping name of active connection. In case the foreign
+ * server is dropped but still the connection is active, then the server name
+ * will be NULL in output.
* - used_in_xact - indicates whether the server has been used in a transaction
* or not.
* - closed - true if the local session seems to be disconnected from other
@@ -2020,7 +2023,7 @@ static Datum
postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
enum pgfdwVersion api_version)
{
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 4
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 5
ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
HASH_SEQ_STATUS scan;
ConnCacheEntry *entry;
@@ -2092,9 +2095,29 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
if (api_version == PGFDW_V1_2)
{
bool require_verify = PG_GETARG_BOOL(1);
+ UserMapping *user = GetUserMappingFromOid(entry->key, true);
+
+ /*
+ * The same as in the foreign server case, user mappings can also
+ * be dropped in the current explicit transaction, so the same
+ * check as in the server case is required.
+ */
+ if (user)
+ values[2] = CStringGetTextDatum(MappingUserName(user->userid));
+ else
+ {
+ /*
+ * If we reach here, this entry must have been invalidated in
+ * pgfdw_inval_callback, same as server case.
+ */
+ Assert(entry->conn && entry->xact_depth > 0 &&
+ entry->invalidated);
+
+ nulls[2] = true;
+ }
/* Has this server been used in the transaction? */
- values[2] = BoolGetDatum(entry->xact_depth > 0);
+ values[3] = BoolGetDatum(entry->xact_depth > 0);
/*
* If requested and the connection is not invalidated, check the
@@ -2103,12 +2126,12 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
*/
if (require_verify && !entry->invalidated && entry->conn)
{
- values[3] = BoolGetDatum(pgfdw_conn_checkable() ?
+ values[4] = BoolGetDatum(pgfdw_conn_checkable() ?
pgfdw_conn_check(entry->conn) != 0 :
false);
}
else
- nulls[3] = true;
+ nulls[4] = true;
}
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 4fcf73070c..ece6b4cf29 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10432,13 +10432,14 @@ NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to user mapping for public on server loopback3
drop cascades to foreign table ft7
-- List all the existing cached connections. loopback and loopback3
--- should be output as invalid connections. Also the server name for
--- loopback3 should be NULL because the server was dropped.
+-- should be output as invalid connections. Also the server name and user name
+-- for loopback3 should be NULL because both server and user mapping were
+-- dropped.
SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid | used_in_xact | closed
--------------+-------+--------------+--------
- loopback | f | t |
- | f | t |
+ server_name | valid | user_name | used_in_xact | closed
+-------------+-------+-----------+--------------+--------
+ loopback | f | hayato | t |
+ | f | | t |
(2 rows)
-- The invalid connections get closed in pgfdw_xact_callback during commit.
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
index 6af10110ca..0b477a2082 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -11,7 +11,8 @@ DROP FUNCTION postgres_fdw_get_connections ();
CREATE FUNCTION postgres_fdw_get_connections
(IN require_verify boolean DEFAULT false, OUT server_name text,
- OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
+ OUT valid boolean, OUT user_name text, OUT used_in_xact boolean,
+ OUT closed boolean)
RETURNS SETOF record
AS 'MODULE_PATHNAME', 'postgres_fdw_get_connections_1_2'
LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index fa9c4dd36f..12d254d7f0 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3357,8 +3357,9 @@ SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
DROP SERVER loopback3 CASCADE;
-- List all the existing cached connections. loopback and loopback3
--- should be output as invalid connections. Also the server name for
--- loopback3 should be NULL because the server was dropped.
+-- should be output as invalid connections. Also the server name and user name
+-- for loopback3 should be NULL because both server and user mapping were
+-- dropped.
SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
-- The invalid connections get closed in pgfdw_xact_callback during commit.
COMMIT;
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index fa2b50450d..dab796f37f 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -782,8 +782,8 @@ OPTIONS (ADD password_required 'false');
returns setof record</function></term>
<listitem>
<para>
- This function returns the foreign server names of all the open
- connections that <filename>postgres_fdw</filename> established from
+ This function returns the foreign server names and user names of all the
+ open connections that <filename>postgres_fdw</filename> established from
the local session to the foreign servers. It also returns whether each
connection is valid and has been used within a transaction.
<literal>valid</literal> is returned as <literal>false</literal> if the
@@ -815,10 +815,10 @@ OPTIONS (ADD password_required 'false');
Example usage of the function:
<screen>
postgres=*# SELECT * FROM postgres_fdw_get_connections(true) ORDER BY 1;
- server_name | valid | used_in_xact | closed
--------------+-------+--------------+--------
- loopback1 | t | t | f
- loopback2 | t | t | f
+ server_name | valid | user_name | used_in_xact | closed
+-------------+-------+-----------+--------------+--------
+ loopback1 | t | public | t | f
+ loopback2 | t | public | t | f
</screen>
</para>
</listitem>
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index f4f35728b4..c7079dd569 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -246,6 +246,40 @@ GetUserMapping(Oid userid, Oid serverid)
}
+/*
+ * GetUserMappingFromOid - look up the user mapping by its oid.
+ */
+UserMapping *
+GetUserMappingFromOid(Oid usermappigid, bool missing_ok)
+{
+ HeapTuple tp;
+ UserMapping *um;
+ Form_pg_user_mapping umform;
+
+ tp = SearchSysCache1(USERMAPPINGOID, ObjectIdGetDatum(usermappigid));
+
+ if (!HeapTupleIsValid(tp))
+ {
+ if (!missing_ok)
+ elog(ERROR, "cache lookup failed for user mapping %u",
+ usermappigid);
+
+ return NULL;
+ }
+
+ umform = ((Form_pg_user_mapping) GETSTRUCT(tp));
+
+ um = (UserMapping *) palloc(sizeof(UserMapping));
+ um->umid = umform->oid;
+ um->userid = umform->umuser;
+ um->serverid = umform->umserver;
+
+ ReleaseSysCache(tp);
+
+ return um;
+}
+
+
/*
* GetForeignTable - look up the foreign table definition by relation oid.
*/
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 82b8153100..b3941edac0 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -71,6 +71,7 @@ extern ForeignServer *GetForeignServerByName(const char *srvname,
bool missing_ok);
extern UserMapping *GetUserMapping(Oid userid, Oid serverid);
extern ForeignDataWrapper *GetForeignDataWrapper(Oid fdwid);
+extern UserMapping *GetUserMappingFromOid(Oid usermappigid, bool missing_ok);
extern ForeignDataWrapper *GetForeignDataWrapperExtended(Oid fdwid,
bits16 flags);
extern ForeignDataWrapper *GetForeignDataWrapperByName(const char *fdwname,
--
2.43.0
On 2024/07/18 19:49, Hayato Kuroda (Fujitsu) wrote:
Shouldn't this test also check if the returned user_name is valid?
You meant to say that we should print the user_name, right? Done.
Yes, I think it's better to test if the value in the user_name column is as expected.
- I found an inconsistency of name between source and doc,
so I unified to postgres_fdw_can_verify_connection().
I'm unsure about the necessity of introducing a standalone function to check
POLLRDHUP availability. Instead of providing postgres_fdw_can_verify_connection(),
could we modify postgres_fdw_get_connections() to return NULL in the "closed"
column on platforms where POLLRDHUP isn't supported?
- Also, test patch (0002) was combined into this.
0002:
- user_name was added after the `valid` to preserve ordering of the old version.
Do we really need to keep this ordering? Wouldn't it be more intuitive to
have the user_name column next to server_name? In pg_stat_statements,
for example, the ordering isn't always preserved, as seen with
WAL-related columns being added in the middle.
Thanks for reviewing the patch! PSA new version.
Thanks for updating the patches!
The regression test for postgres_fdw failed with the following diff.
----------------------
SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
server_name | valid | user_name | used_in_xact | closed
-------------+-------+-----------+--------------+--------
- loopback | f | hayato | t |
+ loopback | f | runner | t |
| f | | t |
(2 rows)
----------------------
+ * If requested and the connection is not invalidated, check the
+ * status of the remote connection from the backend process and
+ * return the result. Otherwise returns NULL.
+ */
+ if (require_verify && !entry->invalidated && entry->conn)
Should we also consider checking invalidated connections? Even though
a connection is marked as invalidated, it can still be used until
the current transaction ends. Therefore, if an invalidated connection
is used in this transaction (i.e., used_in_xact = true) and has
already been closed (closed = true), users might want to consider
rolling back the transaction promptly. Thought?
+ -- Set client_min_messages to ERROR temporary because the following
+ -- function only throws a WARNING on the supported platform.
Is this still true? From my reading of the code, it doesn't appear
that the function throws a WARNING.
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Fujii-san,
On 2024/07/18 19:49, Hayato Kuroda (Fujitsu) wrote:
Shouldn't this test also check if the returned user_name is valid?
You meant to say that we should print the user_name, right? Done.
Yes, I think it's better to test if the value in the user_name column is as expected.
But this might cause a test failure by cfbot.... See below comment.
- I found an inconsistency of name between source and doc,
so I unified to postgres_fdw_can_verify_connection().I'm unsure about the necessity of introducing a standalone function to check
POLLRDHUP availability. Instead of providing
postgres_fdw_can_verify_connection(),
could we modify postgres_fdw_get_connections() to return NULL in the "closed"
column on platforms where POLLRDHUP isn't supported?
Initially I felt that user might not be able to distinguish whether 1) the
connection has not been established yet or 2) the checking cannot be done on this
platform. But after considering more, such servers are not listed in the function.
So modified like that.
- Also, test patch (0002) was combined into this.
0002:
- user_name was added after the `valid` to preserve ordering of the old version.Do we really need to keep this ordering? Wouldn't it be more intuitive to
have the user_name column next to server_name? In pg_stat_statements,
for example, the ordering isn't always preserved, as seen with
WAL-related columns being added in the middle.
I also prefer the style, so changed accordingly.
Thanks for reviewing the patch! PSA new version.
Thanks for updating the patches!
The regression test for postgres_fdw failed with the following diff.
---------------------- SELECT * FROM postgres_fdw_get_connections() ORDER BY 1; server_name | valid | user_name | used_in_xact | closed -------------+-------+-----------+--------------+-------- - loopback | f | hayato | t | + loopback | f | runner | t | | f | | t | (2 rows) ----------------------
This was because the user_name is quite depends on the environment.
I think it looks not so good, but one approach is to print `user_name = CURRENT_USER`
to test the feature. For loopback3, the user_name is set to NULL so that the column
will be NULL as well. How do you think? Do you have better idea?
+ * If requested and the connection is not invalidated, check the + * status of the remote connection from the backend process and + * return the result. Otherwise returns NULL. + */ + if (require_verify && !entry->invalidated && entry->conn)Should we also consider checking invalidated connections? Even though
a connection is marked as invalidated, it can still be used until
the current transaction ends. Therefore, if an invalidated connection
is used in this transaction (i.e., used_in_xact = true) and has
already been closed (closed = true), users might want to consider
rolling back the transaction promptly. Thought?
I confirmed the meaning of `invalidated` attribute. IIUC:
- It is set to true when the server or user mapping is altered, but
- This connection has already been opened within the transaction.
If the entry is invalided, the server_name of postgres_fdw_get_connections is set
set to NULL (because the entry may be modified). Also, the connection is discarded
when the transaction ends.
Based on the unserstanding, yes, the connection should be also checked. One concern
is that user may not recognize which connection is lost (because the column may be blank).
+ -- Set client_min_messages to ERROR temporary because the following + -- function only throws a WARNING on the supported platform.Is this still true? From my reading of the code, it doesn't appear
that the function throws a WARNING.
Good finding, removed.
Attached patches contain above fixes and comment improvements per request from GPT-4o.
Best regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v42-0001-postgres_fdw-Allow-postgres_fdw_get_connections-.patchapplication/octet-stream; name=v42-0001-postgres_fdw-Allow-postgres_fdw_get_connections-.patchDownload
From 0a8212f4f8a5c3f65dc45ff220f785607b87096a Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Fri, 27 Jan 2023 03:17:30 +0000
Subject: [PATCH v42 1/2] postgres_fdw: Allow postgres_fdw_get_connections() to
check connection
If requested, postgres_fdw_get_connections() can verify the status of
connections that are establieshed by postgres_fdw. This check wil be
done by polling the socket. This feature is currently available only
on systems that support the non-standard POLLRDHUP extension to the
poll system call, including Linux.
"closed" column is set to false if existing connection is not closed
by the remote peer.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 137 +++++++++++++++++-
.../postgres_fdw/expected/postgres_fdw.out | 50 ++++++-
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 17 +++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
contrib/postgres_fdw/sql/postgres_fdw.sql | 42 ++++++
doc/src/sgml/postgres-fdw.sgml | 50 +++++--
8 files changed, 274 insertions(+), 27 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index b9fa699305..88fdce40d6 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw query_cancel
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 33e8054f64..667d8d4a82 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -12,6 +12,10 @@
*/
#include "postgres.h"
+#if HAVE_POLL_H
+#include <poll.h>
+#endif
+
#include "access/htup_details.h"
#include "access/xact.h"
#include "catalog/pg_user_mapping.h"
@@ -107,10 +111,17 @@ static uint32 pgfdw_we_get_result = 0;
(entry)->xact_depth, (entry)->xact_depth); \
} while(0)
+enum pgfdwVersion
+{
+ PGFDW_V1_0 = 0,
+ PGFDW_V1_2,
+} pgfdwVersion;
+
/*
* SQL functions
*/
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
+PG_FUNCTION_INFO_V1(postgres_fdw_get_connections_1_2);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
@@ -159,6 +170,12 @@ static void pgfdw_security_check(const char **keywords, const char **values,
UserMapping *user, PGconn *conn);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static Datum postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
+ enum pgfdwVersion api_version);
+
+/* Low layer-like functions. They are used for verifying connections. */
+static int pgfdw_conn_check(PGconn *conn);
+static bool pgfdw_conn_checkable(void);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1978,22 +1995,31 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
}
/*
- * List active foreign server connections.
+ * Internal function used by postgres_fdw_get_connections variants.
*
- * This function takes no input parameter and returns setof record made of
- * following values:
+ * If the api_version is 1.0, this function takes no input parameter and
+ * returns setof record made of following values:
* - server_name - server name of active connection. In case the foreign server
* is dropped but still the connection is active, then the server name will
* be NULL in output.
* - valid - true/false representing whether the connection is valid or not.
* Note that the connections can get invalidated in pgfdw_inval_callback.
*
+ * If the version is 1.2 and later, this function takes an input parameter,
+ * which indicates the need for a health check. Regarding the returned record,
+ * this returns two additional values:
+ * - used_in_xact - indicates whether the server has been used in a transaction
+ * or not.
+ * - closed - true if the local session seems to be disconnected from other
+ * servers.
+ *
* No records are returned when there are no cached connections at all.
*/
-Datum
-postgres_fdw_get_connections(PG_FUNCTION_ARGS)
+static Datum
+postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
+ enum pgfdwVersion api_version)
{
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 2
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 4
ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
HASH_SEQ_STATUS scan;
ConnCacheEntry *entry;
@@ -2061,12 +2087,51 @@ postgres_fdw_get_connections(PG_FUNCTION_ARGS)
values[1] = BoolGetDatum(!entry->invalidated);
+ /* Add additional attributes if the version is 1.2 or later */
+ if (api_version == PGFDW_V1_2)
+ {
+ bool require_verify = PG_GETARG_BOOL(0);
+
+ /* Has this server been used in the transaction? */
+ values[2] = BoolGetDatum(entry->xact_depth > 0);
+
+ /*
+ * If requested and possible, check the status of remote connection
+ * from the backend process and return the result. Otherwise returns
+ * NULL.
+ */
+ if (require_verify && pgfdw_conn_checkable())
+ values[3] = BoolGetDatum(pgfdw_conn_check(entry->conn) != 0);
+ else
+ nulls[3] = true;
+ }
+
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
}
PG_RETURN_VOID();
}
+/*
+ * List active foreign server connections.
+ *
+ * The SQL API of this function has changed since version 1.2, allowing
+ * verification of the status of remote connections. The actual implementation
+ * was moved to the internal function, and we can switch by the api_version to
+ * support the old SQL declaration.
+ */
+Datum
+postgres_fdw_get_connections_1_2(PG_FUNCTION_ARGS)
+{
+ return postgres_fdw_get_connections_internal(fcinfo, PGFDW_V1_2);
+}
+
+Datum
+postgres_fdw_get_connections(PG_FUNCTION_ARGS)
+{
+ return postgres_fdw_get_connections_internal(fcinfo, PGFDW_V1_0);
+}
+
/*
* Disconnect the specified cached connections.
*
@@ -2192,3 +2257,63 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Check whether the socket peer closed the connection or not.
+ *
+ * Returns >0 if input connection is bad or remote peer seems to be closed,
+ * 0 if it is valid, and -1 if an error occurred.
+ */
+static int
+pgfdw_conn_check(PGconn *conn)
+{
+ int sock = PQsocket(conn);
+
+ if (!pgfdw_conn_checkable())
+ return 0;
+
+ if (!conn || PQstatus(conn) != CONNECTION_OK || sock == PGINVALID_SOCKET)
+ return -1;
+
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ {
+ /*
+ * This platform seems to have poll(2), and can wait POLLRDHUP event.
+ * So construct pollfd and directly call it.
+ */
+ struct pollfd input_fd;
+ int result;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP;
+ input_fd.revents = 0;
+
+ do
+ result = poll(&input_fd, 1, 0);
+ while (result < 0 && errno == EINTR);
+
+ if (result < 0)
+ return -1;
+
+ return input_fd.revents;
+ }
+#else
+ /* Do not support socket checking on this platform, return 0 */
+ return 0;
+#endif
+}
+
+/*
+ * Check whether pgfdw_conn_check() can work on this platform.
+ *
+ * Returns true if this can use pgfdw_conn_check(), otherwise false.
+ */
+static bool
+pgfdw_conn_checkable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 39b2b317e8..22fba7aeb5 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10464,10 +10464,10 @@ drop cascades to foreign table ft7
-- should be output as invalid connections. Also the server name for
-- loopback3 should be NULL because the server was dropped.
SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid
--------------+-------
- loopback | f
- | f
+ server_name | valid | used_in_xact | closed
+-------------+-------+--------------+--------
+ loopback | f | t |
+ | f | t |
(2 rows)
-- The invalid connections get closed in pgfdw_xact_callback during commit.
@@ -12286,3 +12286,45 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_get_connections function with require_verify = true
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function() AS $$
+DECLARE
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ SELECT closed INTO result FROM postgres_fdw_get_connections(true);
+
+ -- If result is TRUE or NULL, we succeeded to detect the disconnection or
+ -- it could not be done on this platform. Raise an message.
+ IF result IS NOT false THEN
+ RAISE INFO 'postgres_fdw_get_connections could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+-- ..And call above function
+CALL test_verify_function();
+INFO: 00000
+ERROR: 08006
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index f0803ee077..3014086ba6 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..9afbc5c39b
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,17 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+/* First we have to remove it from the extension */
+ALTER EXTENSION postgres_fdw DROP FUNCTION postgres_fdw_get_connections ();
+
+/* Then we can drop it */
+DROP FUNCTION postgres_fdw_get_connections ();
+
+CREATE FUNCTION postgres_fdw_get_connections
+ (IN require_verify boolean DEFAULT false, OUT server_name text,
+ OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
+RETURNS SETOF record
+AS 'MODULE_PATHNAME', 'postgres_fdw_get_connections_1_2'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 8be9f99c19..653d049946 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -4235,3 +4235,45 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_get_connections function with require_verify = true
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+-- Disconnect once and set application_name to an arbitrary value
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'healthcheck');
+
+-- Define procedure for testing verify functions
+CREATE PROCEDURE test_verify_function() AS $$
+DECLARE
+ result boolean;
+BEGIN
+ PERFORM 1 FROM ft1 LIMIT 1;
+
+ -- Terminate the remote backend process
+ PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'healthcheck';
+
+ SELECT closed INTO result FROM postgres_fdw_get_connections(true);
+
+ -- If result is TRUE or NULL, we succeeded to detect the disconnection or
+ -- it could not be done on this platform. Raise an message.
+ IF result IS NOT false THEN
+ RAISE INFO 'postgres_fdw_get_connections could detect the disconnection, or health check cannot be used on this platform';
+ END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+-- ..And call above function
+CALL test_verify_function();
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 1a600382e2..c4b52ddefc 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -777,27 +777,47 @@ OPTIONS (ADD password_required 'false');
<variablelist>
<varlistentry>
- <term><function>postgres_fdw_get_connections(OUT server_name text, OUT valid boolean) returns setof record</function></term>
+ <term><function>postgres_fdw_get_connections(IN require_verify boolean DEFAULT false,
+ OUT server_name text, OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
+ returns setof record</function></term>
<listitem>
<para>
This function returns the foreign server names of all the open
connections that <filename>postgres_fdw</filename> established from
- the local session to the foreign servers. It also returns whether
- each connection is valid or not. <literal>false</literal> is returned
- if the foreign server connection is used in the current local
- transaction but its foreign server or user mapping is changed or
- dropped (Note that server name of an invalid connection will be
- <literal>NULL</literal> if the server is dropped),
- and then such invalid connection will be closed at
- the end of that transaction. <literal>true</literal> is returned
- otherwise. If there are no open connections, no record is returned.
+ the local session to the foreign servers. It also returns whether each
+ connection is valid and has been used within a transaction.
+ <literal>valid</literal> is returned as <literal>false</literal> if the
+ foreign server connection is used in the current local transaction but
+ its foreign server or user mapping is changed or dropped (Note that
+ server name of an invalid connection will be <literal>NULL</literal> if
+ the server is dropped), and then such invalid connection will be closed
+ at the end of that transaction. The attribute is set to <literal>true</literal>
+ otherwise.
+ </para>
+ <para>
+ If <literal>require_verify</literal> is set to <literal>true</literal>,
+ the function checks the status of remote connections from the local
+ session to the foreign server. This check is performed by polling the
+ socket, which allows long-running transactions to be aborted sooner if
+ the kernel reports that the connection is closed. This feature is
+ currently available only on systems that support the non-standard
+ <symbol>POLLRDHUP</symbol> extension to the <symbol>poll</symbol> system
+ call, including Linux. <literal>closed</literal> attribute indicates the
+ result of this check. <literal>false</literal> means the existing
+ connection is not closed by the remote peer. <literal>true</literal>
+ means if either checked connection has been closed.
+ <literal>NULL</literal> means this feature is not available on
+ this platform or <literal>require_verify</literal> is <literal>false</literal>.
+ </para>
+ <para>
+ If there are no open connections, no record is returned.
Example usage of the function:
<screen>
-postgres=# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid
--------------+-------
- loopback1 | t
- loopback2 | f
+postgres=*# SELECT * FROM postgres_fdw_get_connections(true) ORDER BY 1;
+ server_name | valid | used_in_xact | closed
+-------------+-------+--------------+--------
+ loopback1 | t | t | f
+ loopback2 | t | t | f
</screen>
</para>
</listitem>
--
2.43.0
v42-0002-Extend-postgres_fdw_get_connections-to-return-us.patchapplication/octet-stream; name=v42-0002-Extend-postgres_fdw_get_connections-to-return-us.patchDownload
From 175d82926ce68a164fd45c0cf9cd68c03342ce0c Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Thu, 18 Jul 2024 10:11:03 +0000
Subject: [PATCH v42 2/2] Extend postgres_fdw_get_connections to return user
name
---
contrib/postgres_fdw/connection.c | 54 +++++++++++++++----
.../postgres_fdw/expected/postgres_fdw.out | 15 +++---
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 3 +-
contrib/postgres_fdw/sql/postgres_fdw.sql | 7 +--
doc/src/sgml/postgres-fdw.sgml | 12 ++---
src/backend/foreign/foreign.c | 34 ++++++++++++
src/include/foreign/foreign.h | 1 +
7 files changed, 100 insertions(+), 26 deletions(-)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 667d8d4a82..9f5dd9c945 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -2007,7 +2007,10 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
*
* If the version is 1.2 and later, this function takes an input parameter,
* which indicates the need for a health check. Regarding the returned record,
- * this returns two additional values:
+ * this returns three additional values:
+ * - user_name - the user mapping name of the active connection. In case the
+ * foreign server is dropped but the connection is still active, then the
+ * server name will be NULL in the output.
* - used_in_xact - indicates whether the server has been used in a transaction
* or not.
* - closed - true if the local session seems to be disconnected from other
@@ -2019,7 +2022,7 @@ static Datum
postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
enum pgfdwVersion api_version)
{
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 4
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 5
ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
HASH_SEQ_STATUS scan;
ConnCacheEntry *entry;
@@ -2036,6 +2039,7 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
ForeignServer *server;
Datum values[POSTGRES_FDW_GET_CONNECTIONS_COLS] = {0};
bool nulls[POSTGRES_FDW_GET_CONNECTIONS_COLS] = {0};
+ int i = 0;
/* We only look for open remote connections */
if (!entry->conn)
@@ -2080,20 +2084,52 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
Assert(entry->conn && entry->xact_depth > 0 && entry->invalidated);
/* Show null, if no server name was found */
- nulls[0] = true;
+ nulls[i++] = true;
}
else
- values[0] = CStringGetTextDatum(server->servername);
+ values[i++] = CStringGetTextDatum(server->servername);
- values[1] = BoolGetDatum(!entry->invalidated);
+ /*
+ * Add user_name to returned tuples if the version is 1.2 or later.
+ * This helps distinguish which connection is closed by the
+ * remote peer.
+ */
+ if (api_version == PGFDW_V1_2)
+ {
+ UserMapping *user = GetUserMappingFromOid(entry->key, true);
- /* Add additional attributes if the version is 1.2 or later */
+ /*
+ * Just like in the foreign server case, user mappings can also
+ * be dropped in the current explicit transaction. Therefore, the
+ * same check as in the server case is required.
+ */
+ if (!user)
+ {
+ /*
+ * If we reach here, this entry must have been invalidated in
+ * pgfdw_inval_callback, same as in the server case.
+ */
+ Assert(entry->conn && entry->xact_depth > 0 &&
+ entry->invalidated);
+
+ nulls[i++] = true;
+ }
+ else
+ values[i++] = CStringGetTextDatum(MappingUserName(user->userid));
+ }
+
+ values[i++] = BoolGetDatum(!entry->invalidated);
+
+ /*
+ * Add "used_in_xact" and "closed" columns if the version is 1.2 or
+ * later.
+ */
if (api_version == PGFDW_V1_2)
{
bool require_verify = PG_GETARG_BOOL(0);
/* Has this server been used in the transaction? */
- values[2] = BoolGetDatum(entry->xact_depth > 0);
+ values[i++] = BoolGetDatum(entry->xact_depth > 0);
/*
* If requested and possible, check the status of remote connection
@@ -2101,9 +2137,9 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
* NULL.
*/
if (require_verify && pgfdw_conn_checkable())
- values[3] = BoolGetDatum(pgfdw_conn_check(entry->conn) != 0);
+ values[i++] = BoolGetDatum(pgfdw_conn_check(entry->conn) != 0);
else
- nulls[3] = true;
+ nulls[i++] = true;
}
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 22fba7aeb5..3250964244 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10461,13 +10461,14 @@ NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to user mapping for public on server loopback3
drop cascades to foreign table ft7
-- List all the existing cached connections. loopback and loopback3
--- should be output as invalid connections. Also the server name for
--- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid | used_in_xact | closed
--------------+-------+--------------+--------
- loopback | f | t |
- | f | t |
+-- should be output as invalid connections. Also the server name and user name
+-- for loopback3 should be NULL because both server and user mapping were
+-- dropped.
+SELECT server_name, user_name = CURRENT_USER as "user_name is same as CURRENT_USER", valid, used_in_xact, closed FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | user_name is same as CURRENT_USER | valid | used_in_xact | closed
+-------------+-----------------------------------+-------+--------------+--------
+ loopback | t | f | t |
+ | | f | t |
(2 rows)
-- The invalid connections get closed in pgfdw_xact_callback during commit.
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
index 9afbc5c39b..5a88433a04 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -11,7 +11,8 @@ DROP FUNCTION postgres_fdw_get_connections ();
CREATE FUNCTION postgres_fdw_get_connections
(IN require_verify boolean DEFAULT false, OUT server_name text,
- OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
+ OUT user_name text, OUT valid boolean, OUT used_in_xact boolean,
+ OUT closed boolean)
RETURNS SETOF record
AS 'MODULE_PATHNAME', 'postgres_fdw_get_connections_1_2'
LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 653d049946..df5033e78c 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3374,9 +3374,10 @@ SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
DROP SERVER loopback3 CASCADE;
-- List all the existing cached connections. loopback and loopback3
--- should be output as invalid connections. Also the server name for
--- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+-- should be output as invalid connections. Also the server name and user name
+-- for loopback3 should be NULL because both server and user mapping were
+-- dropped.
+SELECT server_name, user_name = CURRENT_USER as "user_name is same as CURRENT_USER", valid, used_in_xact, closed FROM postgres_fdw_get_connections() ORDER BY 1;
-- The invalid connections get closed in pgfdw_xact_callback during commit.
COMMIT;
-- All cached connections were closed while committing above xact, so no
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index c4b52ddefc..f8467649c0 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -782,8 +782,8 @@ OPTIONS (ADD password_required 'false');
returns setof record</function></term>
<listitem>
<para>
- This function returns the foreign server names of all the open
- connections that <filename>postgres_fdw</filename> established from
+ This function returns the foreign server names and user names of all the
+ open connections that <filename>postgres_fdw</filename> established from
the local session to the foreign servers. It also returns whether each
connection is valid and has been used within a transaction.
<literal>valid</literal> is returned as <literal>false</literal> if the
@@ -814,10 +814,10 @@ OPTIONS (ADD password_required 'false');
Example usage of the function:
<screen>
postgres=*# SELECT * FROM postgres_fdw_get_connections(true) ORDER BY 1;
- server_name | valid | used_in_xact | closed
--------------+-------+--------------+--------
- loopback1 | t | t | f
- loopback2 | t | t | f
+ server_name | user_name | valid | used_in_xact | closed
+-------------+-----------+-------+--------------+--------
+ loopback1 | public | t | t | f
+ loopback2 | public | t | t | f
</screen>
</para>
</listitem>
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index f4f35728b4..c7079dd569 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -246,6 +246,40 @@ GetUserMapping(Oid userid, Oid serverid)
}
+/*
+ * GetUserMappingFromOid - look up the user mapping by its oid.
+ */
+UserMapping *
+GetUserMappingFromOid(Oid usermappigid, bool missing_ok)
+{
+ HeapTuple tp;
+ UserMapping *um;
+ Form_pg_user_mapping umform;
+
+ tp = SearchSysCache1(USERMAPPINGOID, ObjectIdGetDatum(usermappigid));
+
+ if (!HeapTupleIsValid(tp))
+ {
+ if (!missing_ok)
+ elog(ERROR, "cache lookup failed for user mapping %u",
+ usermappigid);
+
+ return NULL;
+ }
+
+ umform = ((Form_pg_user_mapping) GETSTRUCT(tp));
+
+ um = (UserMapping *) palloc(sizeof(UserMapping));
+ um->umid = umform->oid;
+ um->userid = umform->umuser;
+ um->serverid = umform->umserver;
+
+ ReleaseSysCache(tp);
+
+ return um;
+}
+
+
/*
* GetForeignTable - look up the foreign table definition by relation oid.
*/
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 82b8153100..b3941edac0 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -71,6 +71,7 @@ extern ForeignServer *GetForeignServerByName(const char *srvname,
bool missing_ok);
extern UserMapping *GetUserMapping(Oid userid, Oid serverid);
extern ForeignDataWrapper *GetForeignDataWrapper(Oid fdwid);
+extern UserMapping *GetUserMappingFromOid(Oid usermappigid, bool missing_ok);
extern ForeignDataWrapper *GetForeignDataWrapperExtended(Oid fdwid,
bits16 flags);
extern ForeignDataWrapper *GetForeignDataWrapperByName(const char *fdwname,
--
2.43.0
On 2024/07/24 20:40, Hayato Kuroda (Fujitsu) wrote:
Attached patches contain above fixes and comment improvements per request from GPT-4o.
Thanks for updating the patches!
I’ve created a new base patch and split the v42-0001 patch into two parts
to implement the feature and improvements step by step. After pushing these
patches, I’ll focus on the v42-0002 patch next.
I’ve attached the three patches.
v43-0001:
This new patch enhances documentation for postgres_fdw_get_connections()
output columns. The output columns were documented in text format,
which is manageable for the current two columns. However, upcoming patches
will add new columns, making text descriptions less readable.
This patch updates the documentation to use a table format,
making it easier for users to understand each output column.
v43-0002:
This patch adds the "used_in_xact" column to postgres_fdw_get_connections().
It separates this change from the original v42-0001 patch for clarity.
v43-0003
This patch adds the "closed" column to postgres_fdw_get_connections().
I’ve also made several code improvements, for example adding a typedef for
pgfdwVersion to simplify its usage, and updated typedefs.list.
+enum pgfdwVersion
+{
+ PGFDW_V1_0 = 0,
+ PGFDW_V1_2,
+} pgfdwVersion;
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Attachments:
v43-0001-doc-Enhance-documentation-for-postgres_fdw_get_c.patchtext/plain; charset=UTF-8; name=v43-0001-doc-Enhance-documentation-for-postgres_fdw_get_c.patchDownload
From 53d07523a8e6c44043cdae8782282e5018f14953 Mon Sep 17 00:00:00 2001
From: Fujii Masao <fujii@postgresql.org>
Date: Thu, 25 Jul 2024 20:35:12 +0900
Subject: [PATCH v43 1/3] doc: Enhance documentation for
postgres_fdw_get_connections() output columns.
The documentation previously described the output columns of
postgres_fdw_get_connections() in text format, which was manageable
for the original two columns. However, upcoming patches will add
new columns, making text descriptions less readable.
This commit updates the documentation to use a table format,
making it easier for users to understand each output column.
---
doc/src/sgml/postgres-fdw.sgml | 53 +++++++++++++++++++++++++++-------
1 file changed, 42 insertions(+), 11 deletions(-)
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 1a600382e2..c7e0a7d2a6 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -780,17 +780,9 @@ OPTIONS (ADD password_required 'false');
<term><function>postgres_fdw_get_connections(OUT server_name text, OUT valid boolean) returns setof record</function></term>
<listitem>
<para>
- This function returns the foreign server names of all the open
- connections that <filename>postgres_fdw</filename> established from
- the local session to the foreign servers. It also returns whether
- each connection is valid or not. <literal>false</literal> is returned
- if the foreign server connection is used in the current local
- transaction but its foreign server or user mapping is changed or
- dropped (Note that server name of an invalid connection will be
- <literal>NULL</literal> if the server is dropped),
- and then such invalid connection will be closed at
- the end of that transaction. <literal>true</literal> is returned
- otherwise. If there are no open connections, no record is returned.
+ This function returns information about all open connections that
+ postgres_fdw has established from the local session to foreign servers.
+ If there are no open connections, no records are returned.
Example usage of the function:
<screen>
postgres=# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
@@ -799,7 +791,46 @@ postgres=# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
loopback1 | t
loopback2 | f
</screen>
+ The output columns are described in
+ <xref linkend="postgres-fdw-get-connections-columns"/>.
</para>
+
+ <table id="postgres-fdw-get-connections-columns">
+ <title><function>postgres_fdw_get_connections</function> Output Columns</title>
+ <tgroup cols="3">
+ <thead>
+ <row>
+ <entry>Column</entry>
+ <entry>Type</entry>
+ <entry>Description</entry>
+ </row>
+ </thead>
+
+ <tbody>
+ <row>
+ <entry><structfield>server_name</structfield></entry>
+ <entry><type>text</type></entry>
+ <entry>
+ The foreign server name of this connection. If the server is
+ dropped but the connection remains open (i.e., marked as
+ invalid), this will be <literal>NULL</literal>.
+ </entry>
+ </row>
+ <row>
+ <entry><structfield>valid</structfield></entry>
+ <entry><type>boolean</type></entry>
+ <entry>
+ False if this connection is invalid, meaning it is used in
+ the current transaction but its foreign server or
+ user mapping has been changed or dropped.
+ The invalid connection will be closed at the end of
+ the transaction. True is returned otherwise.
+ </entry>
+ </row>
+ </tbody>
+ </tgroup>
+ </table>
+
</listitem>
</varlistentry>
--
2.45.2
v43-0002-postgres_fdw-Add-used_in_xact-column-to-postgres.patchtext/plain; charset=UTF-8; name=v43-0002-postgres_fdw-Add-used_in_xact-column-to-postgres.patchDownload
From b7e65e27a28d3fb4a2da75947a8093bfff0e7d9a Mon Sep 17 00:00:00 2001
From: Fujii Masao <fujii@postgresql.org>
Date: Thu, 25 Jul 2024 20:42:00 +0900
Subject: [PATCH v43 2/3] postgres_fdw: Add "used_in_xact" column to
postgres_fdw_get_connections().
This commit extends the postgres_fdw_get_connections() function to
include a new used_in_xact column, indicating whether each connection
is used in the current transaction.
This addition is particularly useful for the upcoming feature that
will check if connections are closed. By using those information,
users can verify if postgres_fdw connections used in a transaction
remain open. If any connection is closed, the transaction cannot
be committed successfully. In this case users can roll back it
immediately without waiting for transaction end.
The SQL API for postgres_fdw_get_connections() is updated by
this commit and may change in the future. To handle compatibility
with older SQL declarations, an API versioning system is introduced,
allowing the function to behave differently based on the API version.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 84 +++++++++++++++++--
.../postgres_fdw/expected/postgres_fdw.out | 8 +-
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 16 ++++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 21 +++--
src/tools/pgindent/typedefs.list | 1 +
8 files changed, 114 insertions(+), 21 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index b9fa699305..88fdce40d6 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw query_cancel
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 33e8054f64..2e587de023 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -107,10 +107,20 @@ static uint32 pgfdw_we_get_result = 0;
(entry)->xact_depth, (entry)->xact_depth); \
} while(0)
+/*
+ * Extension version number, for supporting older extension versions' objects
+ */
+typedef enum pgfdwVersion
+{
+ PGFDW_V1_1 = 0,
+ PGFDW_V1_2,
+} pgfdwVersion;
+
/*
* SQL functions
*/
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
+PG_FUNCTION_INFO_V1(postgres_fdw_get_connections_1_2);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
@@ -159,6 +169,8 @@ static void pgfdw_security_check(const char **keywords, const char **values,
UserMapping *user, PGconn *conn);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static void postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
+ pgfdwVersion api_version);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1977,23 +1989,34 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
}
}
+/* Number of output arguments (columns) for various API versions */
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_1 2
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 3
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 3 /* maximum of above */
+
/*
- * List active foreign server connections.
+ * Internal function used by postgres_fdw_get_connections variants.
+ *
+ * For API version 1.1, this function returns a set of records with
+ * the following values:
*
- * This function takes no input parameter and returns setof record made of
- * following values:
* - server_name - server name of active connection. In case the foreign server
* is dropped but still the connection is active, then the server name will
* be NULL in output.
* - valid - true/false representing whether the connection is valid or not.
- * Note that the connections can get invalidated in pgfdw_inval_callback.
+ * Note that connections can become invalid in pgfdw_inval_callback.
+ *
+ * For API version 1.2 and later, this function returns the following
+ * additional value along with the two values from version 1.1:
+ *
+ * - used_in_xact - true if the connection is used in the current transaction.
*
* No records are returned when there are no cached connections at all.
*/
-Datum
-postgres_fdw_get_connections(PG_FUNCTION_ARGS)
+static void
+postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
+ pgfdwVersion api_version)
{
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 2
ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
HASH_SEQ_STATUS scan;
ConnCacheEntry *entry;
@@ -2002,7 +2025,22 @@ postgres_fdw_get_connections(PG_FUNCTION_ARGS)
/* If cache doesn't exist, we return no records */
if (!ConnectionHash)
- PG_RETURN_VOID();
+ return;
+
+ /* Check we have the expected number of output arguments */
+ switch (rsinfo->setDesc->natts)
+ {
+ case POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_1:
+ if (api_version != PGFDW_V1_1)
+ elog(ERROR, "incorrect number of output arguments");
+ break;
+ case POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2:
+ if (api_version != PGFDW_V1_2)
+ elog(ERROR, "incorrect number of output arguments");
+ break;
+ default:
+ elog(ERROR, "incorrect number of output arguments");
+ }
hash_seq_init(&scan, ConnectionHash);
while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
@@ -2061,10 +2099,38 @@ postgres_fdw_get_connections(PG_FUNCTION_ARGS)
values[1] = BoolGetDatum(!entry->invalidated);
+ if (api_version >= PGFDW_V1_2)
+ {
+ /* Is this connection used in the current transaction? */
+ values[2] = BoolGetDatum(entry->xact_depth > 0);
+ }
+
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
}
+}
+
+/*
+ * List active foreign server connections.
+ *
+ * The SQL API of this function has changed multiple times, and will likely
+ * do so again in future. To support the case where a newer version of this
+ * loadable module is being used with an old SQL declaration of the function,
+ * we continue to support the older API versions.
+ */
+Datum
+postgres_fdw_get_connections_1_2(PG_FUNCTION_ARGS)
+{
+ postgres_fdw_get_connections_internal(fcinfo, PGFDW_V1_2);
+
+ return (Datum) 0;
+}
+
+Datum
+postgres_fdw_get_connections(PG_FUNCTION_ARGS)
+{
+ postgres_fdw_get_connections_internal(fcinfo, PGFDW_V1_1);
- PG_RETURN_VOID();
+ return (Datum) 0;
}
/*
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 39b2b317e8..82fdc0e26f 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10464,10 +10464,10 @@ drop cascades to foreign table ft7
-- should be output as invalid connections. Also the server name for
-- loopback3 should be NULL because the server was dropped.
SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid
--------------+-------
- loopback | f
- | f
+ server_name | valid | used_in_xact
+-------------+-------+--------------
+ loopback | f | t
+ | f | t
(2 rows)
-- The invalid connections get closed in pgfdw_xact_callback during commit.
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index f0803ee077..3014086ba6 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..0c65bf2e14
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,16 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+/* First we have to remove it from the extension */
+ALTER EXTENSION postgres_fdw DROP FUNCTION postgres_fdw_get_connections ();
+
+/* Then we can drop it */
+DROP FUNCTION postgres_fdw_get_connections ();
+
+CREATE FUNCTION postgres_fdw_get_connections (OUT server_name text,
+ OUT valid boolean, OUT used_in_xact boolean)
+RETURNS SETOF record
+AS 'MODULE_PATHNAME', 'postgres_fdw_get_connections_1_2'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index c7e0a7d2a6..819dca3e00 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -777,7 +777,9 @@ OPTIONS (ADD password_required 'false');
<variablelist>
<varlistentry>
- <term><function>postgres_fdw_get_connections(OUT server_name text, OUT valid boolean) returns setof record</function></term>
+ <term><function>postgres_fdw_get_connections(OUT server_name text,
+ OUT valid boolean, OUT used_in_xact boolean)
+ returns setof record</function></term>
<listitem>
<para>
This function returns information about all open connections that
@@ -785,11 +787,11 @@ OPTIONS (ADD password_required 'false');
If there are no open connections, no records are returned.
Example usage of the function:
<screen>
-postgres=# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid
--------------+-------
- loopback1 | t
- loopback2 | f
+postgres=*# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | valid | used_in_xact
+-------------+-------+--------------
+ loopback1 | t | t
+ loopback2 | f | t
</screen>
The output columns are described in
<xref linkend="postgres-fdw-get-connections-columns"/>.
@@ -827,6 +829,13 @@ postgres=# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
the transaction. True is returned otherwise.
</entry>
</row>
+ <row>
+ <entry><structfield>used_in_xact</structfield></entry>
+ <entry><type>boolean</type></entry>
+ <entry>
+ True if this connection is used in the current transaction.
+ </entry>
+ </row>
</tbody>
</tgroup>
</table>
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index b4d7f9217c..508c74a22b 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -3731,6 +3731,7 @@ pg_wc_probefunc
pg_wchar
pg_wchar_tbl
pgp_armor_headers_state
+pgfdwVersion
pgsocket
pgsql_thing_t
pgssEntry
--
2.45.2
v43-0003-postgres_fdw-Add-connection-status-check-to-post.patchtext/plain; charset=UTF-8; name=v43-0003-postgres_fdw-Add-connection-status-check-to-post.patchDownload
From fe98ccbf0a60e6c95272d3d837df7bc9cb7cf1f2 Mon Sep 17 00:00:00 2001
From: Fujii Masao <fujii@postgresql.org>
Date: Fri, 26 Jul 2024 03:05:53 +0900
Subject: [PATCH v43 3/3] postgres_fdw: Add connection status check to
postgres_fdw_get_connections().
This commit extends the postgres_fdw_get_connections() function
to check if connections are closed. This is useful for detecting closed
postgres_fdw connections that could prevent successful transaction
commits. Users can roll back transactions immediately upon detecting
closed connections, avoiding unnecessary processing of failed
transactions.
This feature is available only on systems supporting the non-standard
POLLRDHUP extension to the poll system call, including Linux.
---
contrib/postgres_fdw/connection.c | 84 +++++++++++++++++--
.../postgres_fdw/expected/postgres_fdw.out | 54 +++++++++++-
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 5 +-
contrib/postgres_fdw/sql/postgres_fdw.sql | 33 ++++++++
doc/src/sgml/postgres-fdw.sgml | 41 +++++++--
5 files changed, 199 insertions(+), 18 deletions(-)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 2e587de023..7ce29ea768 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -12,6 +12,10 @@
*/
#include "postgres.h"
+#if HAVE_POLL_H
+#include <poll.h>
+#endif
+
#include "access/htup_details.h"
#include "access/xact.h"
#include "catalog/pg_user_mapping.h"
@@ -171,6 +175,8 @@ static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
static void postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
pgfdwVersion api_version);
+static int pgfdw_conn_check(PGconn *conn);
+static bool pgfdw_conn_checkable(void);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1991,14 +1997,14 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
/* Number of output arguments (columns) for various API versions */
#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_1 2
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 3
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 3 /* maximum of above */
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 4
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 4 /* maximum of above */
/*
* Internal function used by postgres_fdw_get_connections variants.
*
- * For API version 1.1, this function returns a set of records with
- * the following values:
+ * For API version 1.1, this function takes no input parameter and
+ * returns a set of records with the following values:
*
* - server_name - server name of active connection. In case the foreign server
* is dropped but still the connection is active, then the server name will
@@ -2006,10 +2012,12 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
* - valid - true/false representing whether the connection is valid or not.
* Note that connections can become invalid in pgfdw_inval_callback.
*
- * For API version 1.2 and later, this function returns the following
- * additional value along with the two values from version 1.1:
+ * For API version 1.2 and later, this function takes an input parameter
+ * to check a connection status and returns the following
+ * additional values along with the two values from version 1.1:
*
* - used_in_xact - true if the connection is used in the current transaction.
+ * - closed: true if the connection is closed.
*
* No records are returned when there are no cached connections at all.
*/
@@ -2101,8 +2109,19 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
if (api_version >= PGFDW_V1_2)
{
+ bool check_conn = PG_GETARG_BOOL(0);
+
/* Is this connection used in the current transaction? */
values[2] = BoolGetDatum(entry->xact_depth > 0);
+
+ /*
+ * If a connection status check is requested and supported, return
+ * whether the connection is closed. Otherwise, return NULL.
+ */
+ if (check_conn && pgfdw_conn_checkable())
+ values[3] = BoolGetDatum(pgfdw_conn_check(entry->conn) != 0);
+ else
+ nulls[3] = true;
}
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
@@ -2258,3 +2277,56 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Check if the remote server closed the connection.
+ *
+ * Returns 1 if the connection is closed, -1 if an error occurred,
+ * and 0 if it's not closed or if the connection check is unavailable
+ * on this platform.
+ */
+static int
+pgfdw_conn_check(PGconn *conn)
+{
+ int sock = PQsocket(conn);
+
+ if (PQstatus(conn) != CONNECTION_OK || sock == -1)
+ return -1;
+
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ {
+ struct pollfd input_fd;
+ int result;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP;
+ input_fd.revents = 0;
+
+ do
+ result = poll(&input_fd, 1, 0);
+ while (result < 0 && errno == EINTR);
+
+ if (result < 0)
+ return -1;
+
+ return (input_fd.revents & POLLRDHUP) ? 1 : 0;
+ }
+#else
+ return 0;
+#endif
+}
+
+/*
+ * Check if connection status checking is available on this platform.
+ *
+ * Returns true if available, false otherwise.
+ */
+static bool
+pgfdw_conn_checkable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 82fdc0e26f..212434711e 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10464,10 +10464,10 @@ drop cascades to foreign table ft7
-- should be output as invalid connections. Also the server name for
-- loopback3 should be NULL because the server was dropped.
SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid | used_in_xact
--------------+-------+--------------
- loopback | f | t
- | f | t
+ server_name | valid | used_in_xact | closed
+-------------+-------+--------------+--------
+ loopback | f | t |
+ | f | t |
(2 rows)
-- The invalid connections get closed in pgfdw_xact_callback during commit.
@@ -12286,3 +12286,49 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_get_connections function with check_conn = true
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'fdw_conn_check');
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Since the remote server is still connected, "closed" should be FALSE,
+-- or NULL if the connection status check is not available.
+SELECT CASE WHEN closed IS NOT true THEN 1 ELSE 0 END
+ FROM postgres_fdw_get_connections(true);
+ case
+------
+ 1
+(1 row)
+
+-- After terminating the remote backend, since the connection is closed,
+-- "closed" should be TRUE, or NULL if the connection status check
+-- is not available.
+DO $$ BEGIN
+PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_conn_check';
+END $$;
+SELECT CASE WHEN closed IS NOT false THEN 1 ELSE 0 END
+ FROM postgres_fdw_get_connections(true);
+ case
+------
+ 1
+(1 row)
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
index 0c65bf2e14..0d406c6028 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -9,8 +9,9 @@ ALTER EXTENSION postgres_fdw DROP FUNCTION postgres_fdw_get_connections ();
/* Then we can drop it */
DROP FUNCTION postgres_fdw_get_connections ();
-CREATE FUNCTION postgres_fdw_get_connections (OUT server_name text,
- OUT valid boolean, OUT used_in_xact boolean)
+CREATE FUNCTION postgres_fdw_get_connections (
+ IN check_conn boolean DEFAULT false, OUT server_name text,
+ OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
RETURNS SETOF record
AS 'MODULE_PATHNAME', 'postgres_fdw_get_connections_1_2'
LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 8be9f99c19..371e131933 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -4235,3 +4235,36 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_get_connections function with check_conn = true
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'fdw_conn_check');
+SELECT 1 FROM ft1 LIMIT 1;
+
+-- Since the remote server is still connected, "closed" should be FALSE,
+-- or NULL if the connection status check is not available.
+SELECT CASE WHEN closed IS NOT true THEN 1 ELSE 0 END
+ FROM postgres_fdw_get_connections(true);
+
+-- After terminating the remote backend, since the connection is closed,
+-- "closed" should be TRUE, or NULL if the connection status check
+-- is not available.
+DO $$ BEGIN
+PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_conn_check';
+END $$;
+SELECT CASE WHEN closed IS NOT false THEN 1 ELSE 0 END
+ FROM postgres_fdw_get_connections(true);
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 819dca3e00..9f3151f647 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -777,21 +777,40 @@ OPTIONS (ADD password_required 'false');
<variablelist>
<varlistentry>
- <term><function>postgres_fdw_get_connections(OUT server_name text,
- OUT valid boolean, OUT used_in_xact boolean)
+ <term><function>postgres_fdw_get_connections(
+ IN check_conn boolean DEFAULT false, OUT server_name text,
+ OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
returns setof record</function></term>
<listitem>
<para>
This function returns information about all open connections that
postgres_fdw has established from the local session to foreign servers.
If there are no open connections, no records are returned.
+ </para>
+ <para>
+ If <literal>check_conn</literal> is set to <literal>true</literal>,
+ the function checks the status of each connection and shows
+ the result in the <literal>closed</literal> column.
+ This feature is currently available only on systems that support
+ the non-standard <symbol>POLLRDHUP</symbol> extension to
+ the <symbol>poll</symbol> system call, including Linux.
+ This is useful to check if all connections used within
+ a transaction are still open. If any connections are closed,
+ the transaction cannot be committed successfully,
+ so it is better to roll back as soon as a closed connection is detected,
+ rather than continuing to the end. Users can roll back the transaction
+ immediately if the function reports connections where both
+ <literal>used_in_xact</literal> and <literal>closed</literal> are
+ <literal>true</literal>.
+ </para>
+ <para>
Example usage of the function:
<screen>
postgres=*# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid | used_in_xact
--------------+-------+--------------
- loopback1 | t | t
- loopback2 | f | t
+ server_name | valid | used_in_xact | closed
+-------------+-------+--------------+--------
+ loopback1 | t | t |
+ loopback2 | f | t |
</screen>
The output columns are described in
<xref linkend="postgres-fdw-get-connections-columns"/>.
@@ -836,6 +855,16 @@ postgres=*# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
True if this connection is used in the current transaction.
</entry>
</row>
+ <row>
+ <entry><structfield>closed</structfield></entry>
+ <entry><type>boolean</type></entry>
+ <entry>
+ True if this connection is closed, false otherwise.
+ <literal>NULL</literal> is returned if <literal>check_conn</literal>
+ is set to <literal>false</literal> or if the connection status check
+ is not available on this platform.
+ </entry>
+ </row>
</tbody>
</tgroup>
</table>
--
2.45.2
Dear Fujii-san,
Thanks for updating the patches!
I’ve created a new base patch and split the v42-0001 patch into two parts
to implement the feature and improvements step by step. After pushing these
patches, I’ll focus on the v42-0002 patch next.
Best regards,
Hayato Kuroda
FUJITSU LIMITED
Show quoted text
I’ve attached the three patches.
v43-0001:
This new patch enhances documentation for postgres_fdw_get_connections()
output columns. The output columns were documented in text format,
which is manageable for the current two columns. However, upcoming patches
will add new columns, making text descriptions less readable.
This patch updates the documentation to use a table format,
making it easier for users to understand each output column.v43-0002:
This patch adds the "used_in_xact" column to postgres_fdw_get_connections().
It separates this change from the original v42-0001 patch for clarity.v43-0003
This patch adds the "closed" column to postgres_fdw_get_connections().I’ve also made several code improvements, for example adding a typedef for
pgfdwVersion to simplify its usage, and updated typedefs.list.+enum pgfdwVersion +{ + PGFDW_V1_0 = 0, + PGFDW_V1_2, +} pgfdwVersion;Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
I apologize to post incomplete message, here is a correct version.
Dear Fujii-san,
Thanks for updating the patches!
I’ve created a new base patch and split the v42-0001 patch into two parts
to implement the feature and improvements step by step. After pushing these
patches, I’ll focus on the v42-0002 patch next.
+1.
I’ve attached the three patches.
v43-0001:
This new patch enhances documentation for postgres_fdw_get_connections()
output columns. The output columns were documented in text format,
which is manageable for the current two columns. However, upcoming patches
will add new columns, making text descriptions less readable.
This patch updates the documentation to use a table format,
making it easier for users to understand each output column.
Agreed to add the table. I ran a proofreading tool, and it said below points.
You can revise if they are acceptable.
```
+ This function returns information about all open connections that
```
-> "that" can be removed.
```
+ the current transaction but its foreign server or
```
-> can add comma before "but".
I’ve also made several code improvements, for example adding a typedef for
pgfdwVersion to simplify its usage, and updated typedefs.list.+enum pgfdwVersion +{ + PGFDW_V1_0 = 0, + PGFDW_V1_2, +} pgfdwVersion;
It was intentionally not added, because while developing pg_createsubscriber,
I got a comment that local-use data have not have to be typedef'd [1]:
```
- src/bin/pg_basebackup/pg_createsubscriber.c
+typedef struct CreateSubscriberOptions
+typedef struct LogicalRepInfo
I think these kinds of local-use struct don't need to be typedef'ed.
(Then you also don't need to update typdefs.list.)
```
A comment for 0002.
```
+Datum
+postgres_fdw_get_connections_1_2(PG_FUNCTION_ARGS)
+{
+ postgres_fdw_get_connections_internal(fcinfo, PGFDW_V1_2);
+
+ return (Datum) 0;
+}
```
I know they have a same meaning, but can you clarify why (Datun) 0
is returned instead of PG_RETURN_VOID()?
[1]: /messages/by-id/3ee79f2c-e8b3-4342-857c-a31b87e1afda@eisentraut.org
Best regards,
Hayato Kuroda
FUJITSU LIMITED
On 2024/07/26 12:15, Hayato Kuroda (Fujitsu) wrote:
Agreed to add the table. I ran a proofreading tool, and it said below points.
You can revise if they are acceptable.
Yes, I'm okay with these changes. Thanks for the review!
I’ve also made several code improvements, for example adding a typedef for
pgfdwVersion to simplify its usage, and updated typedefs.list.+enum pgfdwVersion +{ + PGFDW_V1_0 = 0, + PGFDW_V1_2, +} pgfdwVersion;It was intentionally not added, because while developing pg_createsubscriber,
I got a comment that local-use data have not have to be typedef'd [1]:
I didn't know about the rule regarding local-use enums without typedef,
as there are examples like pgssVersion and pgssStoreKind in pg_stat_statements.c.
However, I guess that keeping typedefs.list small is better.
So, I'm fine with removing the typedef from that enum definition
and updating typedefs.list accordingly.
``` +Datum +postgres_fdw_get_connections_1_2(PG_FUNCTION_ARGS) +{ + postgres_fdw_get_connections_internal(fcinfo, PGFDW_V1_2); + + return (Datum) 0; +} ```I know they have a same meaning, but can you clarify why (Datun) 0
is returned instead of PG_RETURN_VOID()?
You're right. I made the change for readability, as similar
functions in pg_stat_statements are implemented that way.
However, it's not essential. I'm okay with reverting it.
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Fujii-san,
Just in case - based on the agreement in [1]/messages/by-id/768032ee-fb57-494b-b674-1ccb65b6f969@oss.nttdata.com, I updated patches to keep them
consistent. We can use same pictures for further discussions...
IIUC, the patch which adds user_name attribute to get_connection() can be discussed
in later stage, is it right?
[1]: /messages/by-id/768032ee-fb57-494b-b674-1ccb65b6f969@oss.nttdata.com
Best regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v44-0001-doc-Enhance-documentation-for-postgres_fdw_get_c.patchapplication/octet-stream; name=v44-0001-doc-Enhance-documentation-for-postgres_fdw_get_c.patchDownload
From 580c88c841cbc8eafc087fdee89ac2c055e28010 Mon Sep 17 00:00:00 2001
From: Fujii Masao <fujii@postgresql.org>
Date: Thu, 25 Jul 2024 20:35:12 +0900
Subject: [PATCH v44 1/3] doc: Enhance documentation for
postgres_fdw_get_connections() output columns.
The documentation previously described the output columns of
postgres_fdw_get_connections() in text format, which was manageable
for the original two columns. However, upcoming patches will add
new columns, making text descriptions less readable.
This commit updates the documentation to use a table format,
making it easier for users to understand each output column.
---
doc/src/sgml/postgres-fdw.sgml | 53 +++++++++++++++++++++++++++-------
1 file changed, 42 insertions(+), 11 deletions(-)
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 1a600382e2..e0eac6705f 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -780,17 +780,9 @@ OPTIONS (ADD password_required 'false');
<term><function>postgres_fdw_get_connections(OUT server_name text, OUT valid boolean) returns setof record</function></term>
<listitem>
<para>
- This function returns the foreign server names of all the open
- connections that <filename>postgres_fdw</filename> established from
- the local session to the foreign servers. It also returns whether
- each connection is valid or not. <literal>false</literal> is returned
- if the foreign server connection is used in the current local
- transaction but its foreign server or user mapping is changed or
- dropped (Note that server name of an invalid connection will be
- <literal>NULL</literal> if the server is dropped),
- and then such invalid connection will be closed at
- the end of that transaction. <literal>true</literal> is returned
- otherwise. If there are no open connections, no record is returned.
+ This function returns information about all open connections postgres_fdw
+ has established from the local session to foreign servers. If there are
+ no open connections, no records are returned.
Example usage of the function:
<screen>
postgres=# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
@@ -799,7 +791,46 @@ postgres=# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
loopback1 | t
loopback2 | f
</screen>
+ The output columns are described in
+ <xref linkend="postgres-fdw-get-connections-columns"/>.
</para>
+
+ <table id="postgres-fdw-get-connections-columns">
+ <title><function>postgres_fdw_get_connections</function> Output Columns</title>
+ <tgroup cols="3">
+ <thead>
+ <row>
+ <entry>Column</entry>
+ <entry>Type</entry>
+ <entry>Description</entry>
+ </row>
+ </thead>
+
+ <tbody>
+ <row>
+ <entry><structfield>server_name</structfield></entry>
+ <entry><type>text</type></entry>
+ <entry>
+ The foreign server name of this connection. If the server is
+ dropped but the connection remains open (i.e., marked as
+ invalid), this will be <literal>NULL</literal>.
+ </entry>
+ </row>
+ <row>
+ <entry><structfield>valid</structfield></entry>
+ <entry><type>boolean</type></entry>
+ <entry>
+ False if this connection is invalid, meaning it is used in
+ the current transaction, but its foreign server or
+ user mapping has been changed or dropped.
+ The invalid connection will be closed at the end of
+ the transaction. True is returned otherwise.
+ </entry>
+ </row>
+ </tbody>
+ </tgroup>
+ </table>
+
</listitem>
</varlistentry>
--
2.43.0
v44-0002-postgres_fdw-Add-used_in_xact-column-to-postgres.patchapplication/octet-stream; name=v44-0002-postgres_fdw-Add-used_in_xact-column-to-postgres.patchDownload
From 88db89d7cf172eea9607adac082ba8e53437e50f Mon Sep 17 00:00:00 2001
From: Fujii Masao <fujii@postgresql.org>
Date: Thu, 25 Jul 2024 20:42:00 +0900
Subject: [PATCH v44 2/3] postgres_fdw: Add "used_in_xact" column to
postgres_fdw_get_connections().
This commit extends the postgres_fdw_get_connections() function to
include a new used_in_xact column, indicating whether each connection
is used in the current transaction.
This addition is particularly useful for the upcoming feature that
will check if connections are closed. By using those information,
users can verify if postgres_fdw connections used in a transaction
remain open. If any connection is closed, the transaction cannot
be committed successfully. In this case users can roll back it
immediately without waiting for transaction end.
The SQL API for postgres_fdw_get_connections() is updated by
this commit and may change in the future. To handle compatibility
with older SQL declarations, an API versioning system is introduced,
allowing the function to behave differently based on the API version.
---
contrib/postgres_fdw/Makefile | 2 +-
contrib/postgres_fdw/connection.c | 82 +++++++++++++++++--
.../postgres_fdw/expected/postgres_fdw.out | 8 +-
contrib/postgres_fdw/meson.build | 1 +
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 16 ++++
contrib/postgres_fdw/postgres_fdw.control | 2 +-
doc/src/sgml/postgres-fdw.sgml | 21 +++--
7 files changed, 112 insertions(+), 20 deletions(-)
create mode 100644 contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
diff --git a/contrib/postgres_fdw/Makefile b/contrib/postgres_fdw/Makefile
index b9fa699305..88fdce40d6 100644
--- a/contrib/postgres_fdw/Makefile
+++ b/contrib/postgres_fdw/Makefile
@@ -14,7 +14,7 @@ PG_CPPFLAGS = -I$(libpq_srcdir)
SHLIB_LINK_INTERNAL = $(libpq)
EXTENSION = postgres_fdw
-DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql
+DATA = postgres_fdw--1.0.sql postgres_fdw--1.0--1.1.sql postgres_fdw--1.1--1.2.sql
REGRESS = postgres_fdw query_cancel
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 33e8054f64..c98660f017 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -107,10 +107,20 @@ static uint32 pgfdw_we_get_result = 0;
(entry)->xact_depth, (entry)->xact_depth); \
} while(0)
+/*
+ * Extension version number, for supporting older extension versions' objects
+ */
+enum pgfdwVersion
+{
+ PGFDW_V1_1 = 0,
+ PGFDW_V1_2,
+} pgfdwVersion;
+
/*
* SQL functions
*/
PG_FUNCTION_INFO_V1(postgres_fdw_get_connections);
+PG_FUNCTION_INFO_V1(postgres_fdw_get_connections_1_2);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect);
PG_FUNCTION_INFO_V1(postgres_fdw_disconnect_all);
@@ -159,6 +169,8 @@ static void pgfdw_security_check(const char **keywords, const char **values,
UserMapping *user, PGconn *conn);
static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
+static void postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
+ enum pgfdwVersion api_version);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1977,23 +1989,34 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
}
}
+/* Number of output arguments (columns) for various API versions */
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_1 2
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 3
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 3 /* maximum of above */
+
/*
- * List active foreign server connections.
+ * Internal function used by postgres_fdw_get_connections variants.
+ *
+ * For API version 1.1, this function returns a set of records with
+ * the following values:
*
- * This function takes no input parameter and returns setof record made of
- * following values:
* - server_name - server name of active connection. In case the foreign server
* is dropped but still the connection is active, then the server name will
* be NULL in output.
* - valid - true/false representing whether the connection is valid or not.
- * Note that the connections can get invalidated in pgfdw_inval_callback.
+ * Note that connections can become invalid in pgfdw_inval_callback.
+ *
+ * For API version 1.2 and later, this function returns the following
+ * additional value along with the two values from version 1.1:
+ *
+ * - used_in_xact - true if the connection is used in the current transaction.
*
* No records are returned when there are no cached connections at all.
*/
-Datum
-postgres_fdw_get_connections(PG_FUNCTION_ARGS)
+static void
+postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
+ enum pgfdwVersion api_version)
{
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 2
ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
HASH_SEQ_STATUS scan;
ConnCacheEntry *entry;
@@ -2002,7 +2025,22 @@ postgres_fdw_get_connections(PG_FUNCTION_ARGS)
/* If cache doesn't exist, we return no records */
if (!ConnectionHash)
- PG_RETURN_VOID();
+ return;
+
+ /* Check we have the expected number of output arguments */
+ switch (rsinfo->setDesc->natts)
+ {
+ case POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_1:
+ if (api_version != PGFDW_V1_1)
+ elog(ERROR, "incorrect number of output arguments");
+ break;
+ case POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2:
+ if (api_version != PGFDW_V1_2)
+ elog(ERROR, "incorrect number of output arguments");
+ break;
+ default:
+ elog(ERROR, "incorrect number of output arguments");
+ }
hash_seq_init(&scan, ConnectionHash);
while ((entry = (ConnCacheEntry *) hash_seq_search(&scan)))
@@ -2061,8 +2099,36 @@ postgres_fdw_get_connections(PG_FUNCTION_ARGS)
values[1] = BoolGetDatum(!entry->invalidated);
+ if (api_version >= PGFDW_V1_2)
+ {
+ /* Is this connection used in the current transaction? */
+ values[2] = BoolGetDatum(entry->xact_depth > 0);
+ }
+
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
}
+}
+
+/*
+ * List active foreign server connections.
+ *
+ * The SQL API of this function has changed multiple times, and will likely
+ * do so again in future. To support the case where a newer version of this
+ * loadable module is being used with an old SQL declaration of the function,
+ * we continue to support the older API versions.
+ */
+Datum
+postgres_fdw_get_connections_1_2(PG_FUNCTION_ARGS)
+{
+ postgres_fdw_get_connections_internal(fcinfo, PGFDW_V1_2);
+
+ PG_RETURN_VOID();
+}
+
+Datum
+postgres_fdw_get_connections(PG_FUNCTION_ARGS)
+{
+ postgres_fdw_get_connections_internal(fcinfo, PGFDW_V1_1);
PG_RETURN_VOID();
}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 39b2b317e8..82fdc0e26f 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10464,10 +10464,10 @@ drop cascades to foreign table ft7
-- should be output as invalid connections. Also the server name for
-- loopback3 should be NULL because the server was dropped.
SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid
--------------+-------
- loopback | f
- | f
+ server_name | valid | used_in_xact
+-------------+-------+--------------
+ loopback | f | t
+ | f | t
(2 rows)
-- The invalid connections get closed in pgfdw_xact_callback during commit.
diff --git a/contrib/postgres_fdw/meson.build b/contrib/postgres_fdw/meson.build
index f0803ee077..3014086ba6 100644
--- a/contrib/postgres_fdw/meson.build
+++ b/contrib/postgres_fdw/meson.build
@@ -26,6 +26,7 @@ install_data(
'postgres_fdw.control',
'postgres_fdw--1.0.sql',
'postgres_fdw--1.0--1.1.sql',
+ 'postgres_fdw--1.1--1.2.sql',
kwargs: contrib_data_args,
)
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
new file mode 100644
index 0000000000..0c65bf2e14
--- /dev/null
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -0,0 +1,16 @@
+/* contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION postgres_fdw UPDATE TO '1.2'" to load this file. \quit
+
+/* First we have to remove it from the extension */
+ALTER EXTENSION postgres_fdw DROP FUNCTION postgres_fdw_get_connections ();
+
+/* Then we can drop it */
+DROP FUNCTION postgres_fdw_get_connections ();
+
+CREATE FUNCTION postgres_fdw_get_connections (OUT server_name text,
+ OUT valid boolean, OUT used_in_xact boolean)
+RETURNS SETOF record
+AS 'MODULE_PATHNAME', 'postgres_fdw_get_connections_1_2'
+LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/contrib/postgres_fdw/postgres_fdw.control b/contrib/postgres_fdw/postgres_fdw.control
index d489382064..a4b800be4f 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.1'
+default_version = '1.2'
module_pathname = '$libdir/postgres_fdw'
relocatable = true
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index e0eac6705f..b904f7a33e 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -777,7 +777,9 @@ OPTIONS (ADD password_required 'false');
<variablelist>
<varlistentry>
- <term><function>postgres_fdw_get_connections(OUT server_name text, OUT valid boolean) returns setof record</function></term>
+ <term><function>postgres_fdw_get_connections(OUT server_name text,
+ OUT valid boolean, OUT used_in_xact boolean)
+ returns setof record</function></term>
<listitem>
<para>
This function returns information about all open connections postgres_fdw
@@ -785,11 +787,11 @@ OPTIONS (ADD password_required 'false');
no open connections, no records are returned.
Example usage of the function:
<screen>
-postgres=# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid
--------------+-------
- loopback1 | t
- loopback2 | f
+postgres=*# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | valid | used_in_xact
+-------------+-------+--------------
+ loopback1 | t | t
+ loopback2 | f | t
</screen>
The output columns are described in
<xref linkend="postgres-fdw-get-connections-columns"/>.
@@ -827,6 +829,13 @@ postgres=# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
the transaction. True is returned otherwise.
</entry>
</row>
+ <row>
+ <entry><structfield>used_in_xact</structfield></entry>
+ <entry><type>boolean</type></entry>
+ <entry>
+ True if this connection is used in the current transaction.
+ </entry>
+ </row>
</tbody>
</tgroup>
</table>
--
2.43.0
v44-0003-postgres_fdw-Add-connection-status-check-to-post.patchapplication/octet-stream; name=v44-0003-postgres_fdw-Add-connection-status-check-to-post.patchDownload
From cc0aa7d174b44fc2bc75960b3465769cd5f98279 Mon Sep 17 00:00:00 2001
From: Fujii Masao <fujii@postgresql.org>
Date: Fri, 26 Jul 2024 03:05:53 +0900
Subject: [PATCH v44 3/3] postgres_fdw: Add connection status check to
postgres_fdw_get_connections().
This commit extends the postgres_fdw_get_connections() function
to check if connections are closed. This is useful for detecting closed
postgres_fdw connections that could prevent successful transaction
commits. Users can roll back transactions immediately upon detecting
closed connections, avoiding unnecessary processing of failed
transactions.
This feature is available only on systems supporting the non-standard
POLLRDHUP extension to the poll system call, including Linux.
---
contrib/postgres_fdw/connection.c | 84 +++++++++++++++++--
.../postgres_fdw/expected/postgres_fdw.out | 54 +++++++++++-
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 5 +-
contrib/postgres_fdw/sql/postgres_fdw.sql | 33 ++++++++
doc/src/sgml/postgres-fdw.sgml | 42 ++++++++--
5 files changed, 199 insertions(+), 19 deletions(-)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index c98660f017..ce658f7187 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -12,6 +12,10 @@
*/
#include "postgres.h"
+#if HAVE_POLL_H
+#include <poll.h>
+#endif
+
#include "access/htup_details.h"
#include "access/xact.h"
#include "catalog/pg_user_mapping.h"
@@ -171,6 +175,8 @@ static bool UserMappingPasswordRequired(UserMapping *user);
static bool disconnect_cached_connections(Oid serverid);
static void postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
enum pgfdwVersion api_version);
+static int pgfdw_conn_check(PGconn *conn);
+static bool pgfdw_conn_checkable(void);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1991,14 +1997,14 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
/* Number of output arguments (columns) for various API versions */
#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_1 2
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 3
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 3 /* maximum of above */
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 4
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 4 /* maximum of above */
/*
* Internal function used by postgres_fdw_get_connections variants.
*
- * For API version 1.1, this function returns a set of records with
- * the following values:
+ * For API version 1.1, this function takes no input parameter and
+ * returns a set of records with the following values:
*
* - server_name - server name of active connection. In case the foreign server
* is dropped but still the connection is active, then the server name will
@@ -2006,10 +2012,12 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
* - valid - true/false representing whether the connection is valid or not.
* Note that connections can become invalid in pgfdw_inval_callback.
*
- * For API version 1.2 and later, this function returns the following
- * additional value along with the two values from version 1.1:
+ * For API version 1.2 and later, this function takes an input parameter
+ * to check a connection status and returns the following
+ * additional values along with the two values from version 1.1:
*
* - used_in_xact - true if the connection is used in the current transaction.
+ * - closed: true if the connection is closed.
*
* No records are returned when there are no cached connections at all.
*/
@@ -2101,8 +2109,19 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
if (api_version >= PGFDW_V1_2)
{
+ bool check_conn = PG_GETARG_BOOL(0);
+
/* Is this connection used in the current transaction? */
values[2] = BoolGetDatum(entry->xact_depth > 0);
+
+ /*
+ * If a connection status check is requested and supported, return
+ * whether the connection is closed. Otherwise, return NULL.
+ */
+ if (check_conn && pgfdw_conn_checkable())
+ values[3] = BoolGetDatum(pgfdw_conn_check(entry->conn) != 0);
+ else
+ nulls[3] = true;
}
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
@@ -2258,3 +2277,56 @@ disconnect_cached_connections(Oid serverid)
return result;
}
+
+/*
+ * Check if the remote server closed the connection.
+ *
+ * Returns 1 if the connection is closed, -1 if an error occurred,
+ * and 0 if it's not closed or if the connection check is unavailable
+ * on this platform.
+ */
+static int
+pgfdw_conn_check(PGconn *conn)
+{
+ int sock = PQsocket(conn);
+
+ if (PQstatus(conn) != CONNECTION_OK || sock == -1)
+ return -1;
+
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ {
+ struct pollfd input_fd;
+ int result;
+
+ input_fd.fd = sock;
+ input_fd.events = POLLRDHUP;
+ input_fd.revents = 0;
+
+ do
+ result = poll(&input_fd, 1, 0);
+ while (result < 0 && errno == EINTR);
+
+ if (result < 0)
+ return -1;
+
+ return (input_fd.revents & POLLRDHUP) ? 1 : 0;
+ }
+#else
+ return 0;
+#endif
+}
+
+/*
+ * Check if connection status checking is available on this platform.
+ *
+ * Returns true if available, false otherwise.
+ */
+static bool
+pgfdw_conn_checkable(void)
+{
+#if (defined(HAVE_POLL) && defined(POLLRDHUP))
+ return true;
+#else
+ return false;
+#endif
+}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 82fdc0e26f..212434711e 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10464,10 +10464,10 @@ drop cascades to foreign table ft7
-- should be output as invalid connections. Also the server name for
-- loopback3 should be NULL because the server was dropped.
SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid | used_in_xact
--------------+-------+--------------
- loopback | f | t
- | f | t
+ server_name | valid | used_in_xact | closed
+-------------+-------+--------------+--------
+ loopback | f | t |
+ | f | t |
(2 rows)
-- The invalid connections get closed in pgfdw_xact_callback during commit.
@@ -12286,3 +12286,49 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+-- ===================================================================
+-- test for postgres_fdw_get_connections function with check_conn = true
+-- ===================================================================
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ ?column?
+----------
+ 1
+(1 row)
+
+ALTER SERVER loopback OPTIONS (SET application_name 'fdw_conn_check');
+SELECT 1 FROM ft1 LIMIT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+-- Since the remote server is still connected, "closed" should be FALSE,
+-- or NULL if the connection status check is not available.
+SELECT CASE WHEN closed IS NOT true THEN 1 ELSE 0 END
+ FROM postgres_fdw_get_connections(true);
+ case
+------
+ 1
+(1 row)
+
+-- After terminating the remote backend, since the connection is closed,
+-- "closed" should be TRUE, or NULL if the connection status check
+-- is not available.
+DO $$ BEGIN
+PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_conn_check';
+END $$;
+SELECT CASE WHEN closed IS NOT false THEN 1 ELSE 0 END
+ FROM postgres_fdw_get_connections(true);
+ case
+------
+ 1
+(1 row)
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
index 0c65bf2e14..0d406c6028 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -9,8 +9,9 @@ ALTER EXTENSION postgres_fdw DROP FUNCTION postgres_fdw_get_connections ();
/* Then we can drop it */
DROP FUNCTION postgres_fdw_get_connections ();
-CREATE FUNCTION postgres_fdw_get_connections (OUT server_name text,
- OUT valid boolean, OUT used_in_xact boolean)
+CREATE FUNCTION postgres_fdw_get_connections (
+ IN check_conn boolean DEFAULT false, OUT server_name text,
+ OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
RETURNS SETOF record
AS 'MODULE_PATHNAME', 'postgres_fdw_get_connections_1_2'
LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 8be9f99c19..371e131933 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -4235,3 +4235,36 @@ ANALYZE analyze_table;
-- cleanup
DROP FOREIGN TABLE analyze_ftable;
DROP TABLE analyze_table;
+
+-- ===================================================================
+-- test for postgres_fdw_get_connections function with check_conn = true
+-- ===================================================================
+
+-- Disable debug_discard_caches in order to manage remote connections
+SET debug_discard_caches TO '0';
+
+-- The text of the error might vary across platforms, so only show SQLSTATE.
+\set VERBOSITY sqlstate
+
+SELECT 1 FROM postgres_fdw_disconnect_all();
+ALTER SERVER loopback OPTIONS (SET application_name 'fdw_conn_check');
+SELECT 1 FROM ft1 LIMIT 1;
+
+-- Since the remote server is still connected, "closed" should be FALSE,
+-- or NULL if the connection status check is not available.
+SELECT CASE WHEN closed IS NOT true THEN 1 ELSE 0 END
+ FROM postgres_fdw_get_connections(true);
+
+-- After terminating the remote backend, since the connection is closed,
+-- "closed" should be TRUE, or NULL if the connection status check
+-- is not available.
+DO $$ BEGIN
+PERFORM pg_terminate_backend(pid, 180000) FROM pg_stat_activity
+ WHERE application_name = 'fdw_conn_check';
+END $$;
+SELECT CASE WHEN closed IS NOT false THEN 1 ELSE 0 END
+ FROM postgres_fdw_get_connections(true);
+
+-- Clean up
+\set VERBOSITY default
+RESET debug_discard_caches;
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index b904f7a33e..90969f63ca 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -777,21 +777,39 @@ OPTIONS (ADD password_required 'false');
<variablelist>
<varlistentry>
- <term><function>postgres_fdw_get_connections(OUT server_name text,
- OUT valid boolean, OUT used_in_xact boolean)
+ <term><function>postgres_fdw_get_connections(
+ IN check_conn boolean DEFAULT false, OUT server_name text,
+ OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
returns setof record</function></term>
<listitem>
<para>
This function returns information about all open connections postgres_fdw
has established from the local session to foreign servers. If there are
no open connections, no records are returned.
+ </para>
+ <para>
+ If <literal>check_conn</literal> is set to <literal>true</literal>,
+ the function checks the status of each connection and shows
+ the result in the <literal>closed</literal> column.
+ This feature is currently available only on systems that support
+ the non-standard <symbol>POLLRDHUP</symbol> extension to
+ the <symbol>poll</symbol> system call, including Linux.
+ This is useful to check if all connections used within
+ a transaction are still open. If any connections are closed,
+ the transaction cannot be committed successfully,
+ so it is better to roll back as soon as a closed connection is detected,
+ rather than continuing to the end. Users can roll back the transaction
+ immediately if the function reports connections where both
+ <literal>used_in_xact</literal> and <literal>closed</literal> are
+ <literal>true</literal>.
+ </para>
+ <para>
Example usage of the function:
<screen>
-postgres=*# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid | used_in_xact
--------------+-------+--------------
- loopback1 | t | t
- loopback2 | f | t
+ server_name | valid | used_in_xact | closed
+-------------+-------+--------------+--------
+ loopback1 | t | t |
+ loopback2 | f | t |
</screen>
The output columns are described in
<xref linkend="postgres-fdw-get-connections-columns"/>.
@@ -836,6 +854,16 @@ postgres=*# SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
True if this connection is used in the current transaction.
</entry>
</row>
+ <row>
+ <entry><structfield>closed</structfield></entry>
+ <entry><type>boolean</type></entry>
+ <entry>
+ True if this connection is closed, false otherwise.
+ <literal>NULL</literal> is returned if <literal>check_conn</literal>
+ is set to <literal>false</literal> or if the connection status check
+ is not available on this platform.
+ </entry>
+ </row>
</tbody>
</tgroup>
</table>
--
2.43.0
On 2024/07/26 17:07, Hayato Kuroda (Fujitsu) wrote:
Dear Fujii-san,
Just in case - based on the agreement in [1], I updated patches to keep them
consistent. We can use same pictures for further discussions...
Thanks for updating the patches! I pushed them.
IIUC, the patch which adds user_name attribute to get_connection() can be discussed
in later stage, is it right?
No, let's work on the patch at this stage :)
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
On 2024/07/26 22:44, Fujii Masao wrote:
On 2024/07/26 17:07, Hayato Kuroda (Fujitsu) wrote:
Dear Fujii-san,
Just in case - based on the agreement in [1], I updated patches to keep them
consistent. We can use same pictures for further discussions...Thanks for updating the patches! I pushed them.
The buildfarm member "hake" reported a failure in the postgres_fdw regression test.
diff -U3 /export/home/elmer/c15x/buildroot/HEAD/pgsql.build/contrib/postgres_fdw/expected/postgres_fdw.out /export/home/elmer/c15x/buildroot/HEAD/pgsql.build/contrib/postgres_fdw/results/postgres_fdw.out
--- /export/home/elmer/c15x/buildroot/HEAD/pgsql.build/contrib/postgres_fdw/expected/postgres_fdw.out Fri Jul 26 19:16:29 2024
+++ /export/home/elmer/c15x/buildroot/HEAD/pgsql.build/contrib/postgres_fdw/results/postgres_fdw.out Fri Jul 26 19:31:12 2024
@@ -12326,7 +12326,7 @@
FROM postgres_fdw_get_connections(true);
case
------
- 1
+ 0
(1 row)
-- Clean up
The regression.diffs shows that pgfdw_conn_check returned 0 even though pgfdw_conn_checkable()
returned true. This can happen if the "revents" from poll() indicates something other than
POLLRDHUP. I think that "revents" could indicate POLLHUP, POLLERR, or POLLNVAL. Therefore,
IMO pgfdw_conn_check() should be updated as follows. I will test this change.
- return (input_fd.revents & POLLRDHUP) ? 1 : 0;
+ return (input_fd.revents &
+ (POLLRDHUP | POLLHUP | POLLERR | POLLNVAL)) ? 1 : 0;
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Fujii-san,
Thanks for pushing and analyzing the failure!
The regression.diffs shows that pgfdw_conn_check returned 0 even though
pgfdw_conn_checkable()
returned true. This can happen if the "revents" from poll() indicates something
other than
POLLRDHUP. I think that "revents" could indicate POLLHUP, POLLERR, or
POLLNVAL. Therefore,
IMO pgfdw_conn_check() should be updated as follows. I will test this change.- return (input_fd.revents & POLLRDHUP) ? 1 : 0; + return (input_fd.revents & + (POLLRDHUP | POLLHUP | POLLERR | POLLNVAL)) ? 1 : 0;
I think you are right.
According to the man page, the input socket is invalid or disconnected if revents
has such bits. So such cases should be also regarded as *failure*.
After the fix, the animal said OK. Great works!
Best regards,
Hayato Kuroda
FUJITSU LIMITED
Dear Fujii-san,
IIUC, the patch which adds user_name attribute to get_connection() can be
discussed
in later stage, is it right?
No, let's work on the patch at this stage :)
OK, here is a rebased patch.
- Changed the name of new API from `GetUserMappingFromOid` to `GetUserMappingByOid`
to keep the name consistent with others.
- Comments and docs were updated.
Best regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
0001-Extend-postgres_fdw_get_connections-to-return-user-n.patchapplication/octet-stream; name=0001-Extend-postgres_fdw_get_connections-to-return-user-n.patchDownload
From 21fa6f37bd3397b7ae4c920f4234754420c710ea Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Thu, 18 Jul 2024 10:11:03 +0000
Subject: [PATCH] Extend postgres_fdw_get_connections to return user name
---
contrib/postgres_fdw/connection.c | 48 +++++++++++++++----
.../postgres_fdw/expected/postgres_fdw.out | 16 ++++---
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 3 +-
contrib/postgres_fdw/sql/postgres_fdw.sql | 8 ++--
doc/src/sgml/fdwhandler.sgml | 11 +++++
doc/src/sgml/postgres-fdw.sgml | 17 +++++--
src/backend/foreign/foreign.c | 34 +++++++++++++
src/include/foreign/foreign.h | 1 +
8 files changed, 113 insertions(+), 25 deletions(-)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 12d1fec0e8..9ea7db9f49 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -1997,8 +1997,8 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
/* Number of output arguments (columns) for various API versions */
#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_1 2
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 4
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 4 /* maximum of above */
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 5
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 5 /* maximum of above */
/*
* Internal function used by postgres_fdw_get_connections variants.
@@ -2014,10 +2014,13 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
*
* For API version 1.2 and later, this function takes an input parameter
* to check a connection status and returns the following
- * additional values along with the two values from version 1.1:
+ * additional values along with the three values from version 1.1:
*
+ * - user_name - the local user name of the active connection. In case the
+ * user mapping is dropped but the connection is still active, then the
+ * user name will be NULL in the output.
* - used_in_xact - true if the connection is used in the current transaction.
- * - closed: true if the connection is closed.
+ * - closed - true if the connection is closed.
*
* No records are returned when there are no cached connections at all.
*/
@@ -2056,6 +2059,7 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
ForeignServer *server;
Datum values[POSTGRES_FDW_GET_CONNECTIONS_COLS] = {0};
bool nulls[POSTGRES_FDW_GET_CONNECTIONS_COLS] = {0};
+ int i = 0;
/* We only look for open remote connections */
if (!entry->conn)
@@ -2100,28 +2104,52 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
Assert(entry->conn && entry->xact_depth > 0 && entry->invalidated);
/* Show null, if no server name was found */
- nulls[0] = true;
+ nulls[i++] = true;
}
else
- values[0] = CStringGetTextDatum(server->servername);
+ values[i++] = CStringGetTextDatum(server->servername);
- values[1] = BoolGetDatum(!entry->invalidated);
+ if (api_version >= PGFDW_V1_2)
+ {
+ UserMapping *user = GetUserMappingByOid(entry->key, true);
+
+ /*
+ * Just like in the foreign server case, user mappings can also
+ * be dropped in the current explicit transaction. Therefore, the
+ * same check as in the server case is required.
+ */
+ if (!user)
+ {
+ /*
+ * If we reach here, this entry must have been invalidated in
+ * pgfdw_inval_callback, same as in the server case.
+ */
+ Assert(entry->conn && entry->xact_depth > 0 &&
+ entry->invalidated);
+
+ nulls[i++] = true;
+ }
+ else
+ values[i++] = CStringGetTextDatum(MappingUserName(user->userid));
+ }
+
+ values[i++] = BoolGetDatum(!entry->invalidated);
if (api_version >= PGFDW_V1_2)
{
bool check_conn = PG_GETARG_BOOL(0);
/* Is this connection used in the current transaction? */
- values[2] = BoolGetDatum(entry->xact_depth > 0);
+ values[i++] = BoolGetDatum(entry->xact_depth > 0);
/*
* If a connection status check is requested and supported, return
* whether the connection is closed. Otherwise, return NULL.
*/
if (check_conn && pgfdw_conn_checkable())
- values[3] = BoolGetDatum(pgfdw_conn_check(entry->conn) != 0);
+ values[i++] = BoolGetDatum(pgfdw_conn_check(entry->conn) != 0);
else
- nulls[3] = true;
+ nulls[i++] = true;
}
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 212434711e..30d789f582 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10461,13 +10461,15 @@ NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to user mapping for public on server loopback3
drop cascades to foreign table ft7
-- List all the existing cached connections. loopback and loopback3
--- should be output as invalid connections. Also the server name for
--- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid | used_in_xact | closed
--------------+-------+--------------+--------
- loopback | f | t |
- | f | t |
+-- should be output as invalid connections. Also the server name and user name
+-- for loopback3 should be NULL because both server and user mapping were
+-- dropped.
+SELECT server_name, user_name = CURRENT_USER as "user_name = CURRENT_USER", valid, used_in_xact, closed
+FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | user_name = CURRENT_USER | valid | used_in_xact | closed
+-------------+--------------------------+-------+--------------+--------
+ loopback | t | f | t |
+ | | f | t |
(2 rows)
-- The invalid connections get closed in pgfdw_xact_callback during commit.
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
index 0d406c6028..81aad4fcda 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -11,7 +11,8 @@ DROP FUNCTION postgres_fdw_get_connections ();
CREATE FUNCTION postgres_fdw_get_connections (
IN check_conn boolean DEFAULT false, OUT server_name text,
- OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
+ OUT user_name text, OUT valid boolean, OUT used_in_xact boolean,
+ OUT closed boolean)
RETURNS SETOF record
AS 'MODULE_PATHNAME', 'postgres_fdw_get_connections_1_2'
LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 371e131933..d06b34cff5 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3374,9 +3374,11 @@ SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
DROP SERVER loopback3 CASCADE;
-- List all the existing cached connections. loopback and loopback3
--- should be output as invalid connections. Also the server name for
--- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+-- should be output as invalid connections. Also the server name and user name
+-- for loopback3 should be NULL because both server and user mapping were
+-- dropped.
+SELECT server_name, user_name = CURRENT_USER as "user_name = CURRENT_USER", valid, used_in_xact, closed
+FROM postgres_fdw_get_connections() ORDER BY 1;
-- The invalid connections get closed in pgfdw_xact_callback during commit.
COMMIT;
-- All cached connections were closed while committing above xact, so no
diff --git a/doc/src/sgml/fdwhandler.sgml b/doc/src/sgml/fdwhandler.sgml
index b80320504d..89e6d30ced 100644
--- a/doc/src/sgml/fdwhandler.sgml
+++ b/doc/src/sgml/fdwhandler.sgml
@@ -1773,6 +1773,17 @@ GetUserMapping(Oid userid, Oid serverid);
<para>
<programlisting>
+UserMapping *
+GetUserMappingByOid(Oid usermappigid, bool missing_ok);
+</programlisting>
+
+ This function returns a <structname>UserMapping</structname> object for
+ the user mapping with the given OID. If the user mapping is not found,
+ return NULL if missing_ok is true, otherwise raise an error.
+ </para>
+
+ <para>
+<programlisting>
ForeignTable *
GetForeignTable(Oid relid);
</programlisting>
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 90969f63ca..7b19fddb0b 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -806,10 +806,10 @@ OPTIONS (ADD password_required 'false');
<para>
Example usage of the function:
<screen>
- server_name | valid | used_in_xact | closed
--------------+-------+--------------+--------
- loopback1 | t | t |
- loopback2 | f | t |
+ server_name | user_name | valid | used_in_xact | closed
+-------------+-----------+-------+--------------+--------
+ loopback1 | postgres | t | t |
+ loopback2 | postgres | t | t |
</screen>
The output columns are described in
<xref linkend="postgres-fdw-get-connections-columns"/>.
@@ -836,6 +836,15 @@ OPTIONS (ADD password_required 'false');
invalid), this will be <literal>NULL</literal>.
</entry>
</row>
+ <row>
+ <entry><structfield>user_name</structfield></entry>
+ <entry><type>text</type></entry>
+ <entry>
+ The local user name of this connection. If the user mapping is
+ dropped but the connection remains open (i.e., marked as
+ invalid), this will be <literal>NULL</literal>.
+ </entry>
+ </row>
<row>
<entry><structfield>valid</structfield></entry>
<entry><type>boolean</type></entry>
diff --git a/src/backend/foreign/foreign.c b/src/backend/foreign/foreign.c
index f4f35728b4..d275d56569 100644
--- a/src/backend/foreign/foreign.c
+++ b/src/backend/foreign/foreign.c
@@ -246,6 +246,40 @@ GetUserMapping(Oid userid, Oid serverid)
}
+/*
+ * GetUserMappingByOid - look up the user mapping by its oid.
+ */
+UserMapping *
+GetUserMappingByOid(Oid usermappigid, bool missing_ok)
+{
+ HeapTuple tp;
+ UserMapping *um;
+ Form_pg_user_mapping umform;
+
+ tp = SearchSysCache1(USERMAPPINGOID, ObjectIdGetDatum(usermappigid));
+
+ if (!HeapTupleIsValid(tp))
+ {
+ if (!missing_ok)
+ elog(ERROR, "cache lookup failed for user mapping %u",
+ usermappigid);
+
+ return NULL;
+ }
+
+ umform = ((Form_pg_user_mapping) GETSTRUCT(tp));
+
+ um = (UserMapping *) palloc(sizeof(UserMapping));
+ um->umid = umform->oid;
+ um->userid = umform->umuser;
+ um->serverid = umform->umserver;
+
+ ReleaseSysCache(tp);
+
+ return um;
+}
+
+
/*
* GetForeignTable - look up the foreign table definition by relation oid.
*/
diff --git a/src/include/foreign/foreign.h b/src/include/foreign/foreign.h
index 82b8153100..863d388664 100644
--- a/src/include/foreign/foreign.h
+++ b/src/include/foreign/foreign.h
@@ -71,6 +71,7 @@ extern ForeignServer *GetForeignServerByName(const char *srvname,
bool missing_ok);
extern UserMapping *GetUserMapping(Oid userid, Oid serverid);
extern ForeignDataWrapper *GetForeignDataWrapper(Oid fdwid);
+extern UserMapping *GetUserMappingByOid(Oid usermappigid, bool missing_ok);
extern ForeignDataWrapper *GetForeignDataWrapperExtended(Oid fdwid,
bits16 flags);
extern ForeignDataWrapper *GetForeignDataWrapperByName(const char *fdwname,
--
2.43.0
On 2024/07/29 12:58, Hayato Kuroda (Fujitsu) wrote:
Dear Fujii-san,
IIUC, the patch which adds user_name attribute to get_connection() can be
discussed
in later stage, is it right?
No, let's work on the patch at this stage :)
OK, here is a rebased patch.
Thanks for updating the patch!
- Changed the name of new API from `GetUserMappingFromOid` to `GetUserMappingByOid`
to keep the name consistent with others.
If we expose this function as an FDW helper function, it should return
a complete UserMapping object, including umoptions.
However, if postgres_fdw_get_connections() is the only user of this function,
I'm not inclined to expose it as an FDW helper. Instead, we can either get
the user ID by user mapping OID directly in connection.c using SearchSysCache(),
or add the user ID to ConnCacheEntry and use it in postgres_fdw_get_connections().
Thought?
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Fujii-san,
Thanks for updating the patch!
- Changed the name of new API from `GetUserMappingFromOid` to
`GetUserMappingByOid`
to keep the name consistent with others.
If we expose this function as an FDW helper function, it should return
a complete UserMapping object, including umoptions.However, if postgres_fdw_get_connections() is the only user of this function,
I'm not inclined to expose it as an FDW helper.
One reason is that the function does not handle any specific data for postgres_fdw,
however, there are no users and requirests from other projects. Based on that, ok,
we can move it to connection.c. If needed, we can export it again.
Instead, we can either get
the user ID by user mapping OID directly in connection.c using SearchSysCache(),
or add the user ID to ConnCacheEntry and use it in
postgres_fdw_get_connections().
Thought?
I moved the function to connection.c, which uses the SearchSysCache1().
I've tried both ways, and they worked well. One difference is that when we use
the extended ConnCacheEntry approach and the entry has been invalidated, we cannot
distinguish the reason. For example, in the below case, the entry is invalidated,
so the user_name of the output record will be NULL, whereas the user mapping is
actually still valid. We may be able to add the reason for invalidation, but
I'm not very motivated to modify the part.
```
BEGIN;
SELECT 1 FROM ft1 LIMIT 1; -- ft1 is at server "loopback"
...
ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
...
SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
-> {"loopback", NULL, ....} will be returned
```
Another reason is that we can keep the code consistent with the server case.
The part does not read data from the entry, and we can follow.
Best regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v2-0001-Extend-postgres_fdw_get_connections-to-return-use.patchapplication/octet-stream; name=v2-0001-Extend-postgres_fdw_get_connections-to-return-use.patchDownload
From c128ce29bbe70676a338a8d7bab7f7209e47836f Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Thu, 18 Jul 2024 10:11:03 +0000
Subject: [PATCH v2] Extend postgres_fdw_get_connections to return user name
---
contrib/postgres_fdw/connection.c | 82 ++++++++++++++++---
.../postgres_fdw/expected/postgres_fdw.out | 16 ++--
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 3 +-
contrib/postgres_fdw/sql/postgres_fdw.sql | 8 +-
doc/src/sgml/fdwhandler.sgml | 12 ---
doc/src/sgml/postgres-fdw.sgml | 17 +++-
6 files changed, 101 insertions(+), 37 deletions(-)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 12d1fec0e8..9e17f74a2d 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -177,6 +177,7 @@ static void postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
enum pgfdwVersion api_version);
static int pgfdw_conn_check(PGconn *conn);
static bool pgfdw_conn_checkable(void);
+static UserMapping *GetUserMappingByOid(Oid umid, bool missing_ok);
/*
* Get a PGconn which can be used to execute queries on the remote PostgreSQL
@@ -1997,8 +1998,8 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
/* Number of output arguments (columns) for various API versions */
#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_1 2
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 4
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 4 /* maximum of above */
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 5
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 5 /* maximum of above */
/*
* Internal function used by postgres_fdw_get_connections variants.
@@ -2014,10 +2015,13 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
*
* For API version 1.2 and later, this function takes an input parameter
* to check a connection status and returns the following
- * additional values along with the two values from version 1.1:
+ * additional values along with the three values from version 1.1:
*
+ * - user_name - the local user name of the active connection. In case the
+ * user mapping is dropped but the connection is still active, then the
+ * user name will be NULL in the output.
* - used_in_xact - true if the connection is used in the current transaction.
- * - closed: true if the connection is closed.
+ * - closed - true if the connection is closed.
*
* No records are returned when there are no cached connections at all.
*/
@@ -2056,6 +2060,7 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
ForeignServer *server;
Datum values[POSTGRES_FDW_GET_CONNECTIONS_COLS] = {0};
bool nulls[POSTGRES_FDW_GET_CONNECTIONS_COLS] = {0};
+ int i = 0;
/* We only look for open remote connections */
if (!entry->conn)
@@ -2100,28 +2105,52 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
Assert(entry->conn && entry->xact_depth > 0 && entry->invalidated);
/* Show null, if no server name was found */
- nulls[0] = true;
+ nulls[i++] = true;
}
else
- values[0] = CStringGetTextDatum(server->servername);
+ values[i++] = CStringGetTextDatum(server->servername);
- values[1] = BoolGetDatum(!entry->invalidated);
+ if (api_version >= PGFDW_V1_2)
+ {
+ UserMapping *user = GetUserMappingByOid(entry->key, true);
+
+ /*
+ * Just like in the foreign server case, user mappings can also
+ * be dropped in the current explicit transaction. Therefore, the
+ * same check as in the server case is required.
+ */
+ if (!user)
+ {
+ /*
+ * If we reach here, this entry must have been invalidated in
+ * pgfdw_inval_callback, same as in the server case.
+ */
+ Assert(entry->conn && entry->xact_depth > 0 &&
+ entry->invalidated);
+
+ nulls[i++] = true;
+ }
+ else
+ values[i++] = CStringGetTextDatum(MappingUserName(user->userid));
+ }
+
+ values[i++] = BoolGetDatum(!entry->invalidated);
if (api_version >= PGFDW_V1_2)
{
bool check_conn = PG_GETARG_BOOL(0);
/* Is this connection used in the current transaction? */
- values[2] = BoolGetDatum(entry->xact_depth > 0);
+ values[i++] = BoolGetDatum(entry->xact_depth > 0);
/*
* If a connection status check is requested and supported, return
* whether the connection is closed. Otherwise, return NULL.
*/
if (check_conn && pgfdw_conn_checkable())
- values[3] = BoolGetDatum(pgfdw_conn_check(entry->conn) != 0);
+ values[i++] = BoolGetDatum(pgfdw_conn_check(entry->conn) != 0);
else
- nulls[3] = true;
+ nulls[i++] = true;
}
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
@@ -2331,3 +2360,36 @@ pgfdw_conn_checkable(void)
return false;
#endif
}
+
+/*
+ * GetUserMappingByOid - look up the user mapping by its oid.
+ */
+UserMapping *
+GetUserMappingByOid(Oid umid, bool missing_ok)
+{
+ HeapTuple tp;
+ UserMapping *um;
+ Form_pg_user_mapping umform;
+
+ tp = SearchSysCache1(USERMAPPINGOID, ObjectIdGetDatum(umid));
+
+ if (!HeapTupleIsValid(tp))
+ {
+ if (!missing_ok)
+ elog(ERROR, "cache lookup failed for user mapping %u",
+ umid);
+
+ return NULL;
+ }
+
+ umform = ((Form_pg_user_mapping) GETSTRUCT(tp));
+
+ um = (UserMapping *) palloc(sizeof(UserMapping));
+ um->umid = umform->oid;
+ um->userid = umform->umuser;
+ um->serverid = umform->umserver;
+
+ ReleaseSysCache(tp);
+
+ return um;
+}
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index 212434711e..30d789f582 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10461,13 +10461,15 @@ NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to user mapping for public on server loopback3
drop cascades to foreign table ft7
-- List all the existing cached connections. loopback and loopback3
--- should be output as invalid connections. Also the server name for
--- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid | used_in_xact | closed
--------------+-------+--------------+--------
- loopback | f | t |
- | f | t |
+-- should be output as invalid connections. Also the server name and user name
+-- for loopback3 should be NULL because both server and user mapping were
+-- dropped.
+SELECT server_name, user_name = CURRENT_USER as "user_name = CURRENT_USER", valid, used_in_xact, closed
+FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | user_name = CURRENT_USER | valid | used_in_xact | closed
+-------------+--------------------------+-------+--------------+--------
+ loopback | t | f | t |
+ | | f | t |
(2 rows)
-- The invalid connections get closed in pgfdw_xact_callback during commit.
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
index 0d406c6028..81aad4fcda 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -11,7 +11,8 @@ DROP FUNCTION postgres_fdw_get_connections ();
CREATE FUNCTION postgres_fdw_get_connections (
IN check_conn boolean DEFAULT false, OUT server_name text,
- OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
+ OUT user_name text, OUT valid boolean, OUT used_in_xact boolean,
+ OUT closed boolean)
RETURNS SETOF record
AS 'MODULE_PATHNAME', 'postgres_fdw_get_connections_1_2'
LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 371e131933..d06b34cff5 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3374,9 +3374,11 @@ SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
DROP SERVER loopback3 CASCADE;
-- List all the existing cached connections. loopback and loopback3
--- should be output as invalid connections. Also the server name for
--- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+-- should be output as invalid connections. Also the server name and user name
+-- for loopback3 should be NULL because both server and user mapping were
+-- dropped.
+SELECT server_name, user_name = CURRENT_USER as "user_name = CURRENT_USER", valid, used_in_xact, closed
+FROM postgres_fdw_get_connections() ORDER BY 1;
-- The invalid connections get closed in pgfdw_xact_callback during commit.
COMMIT;
-- All cached connections were closed while committing above xact, so no
diff --git a/doc/src/sgml/fdwhandler.sgml b/doc/src/sgml/fdwhandler.sgml
index b80320504d..1f123c1caa 100644
--- a/doc/src/sgml/fdwhandler.sgml
+++ b/doc/src/sgml/fdwhandler.sgml
@@ -1773,18 +1773,6 @@ GetUserMapping(Oid userid, Oid serverid);
<para>
<programlisting>
-ForeignTable *
-GetForeignTable(Oid relid);
-</programlisting>
-
- This function returns a <structname>ForeignTable</structname> object for
- the foreign table with the given OID. A
- <structname>ForeignTable</structname> object contains properties of the
- foreign table (see <filename>foreign/foreign.h</filename> for details).
- </para>
-
- <para>
-<programlisting>
List *
GetForeignColumnOptions(Oid relid, AttrNumber attnum);
</programlisting>
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 90969f63ca..7b19fddb0b 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -806,10 +806,10 @@ OPTIONS (ADD password_required 'false');
<para>
Example usage of the function:
<screen>
- server_name | valid | used_in_xact | closed
--------------+-------+--------------+--------
- loopback1 | t | t |
- loopback2 | f | t |
+ server_name | user_name | valid | used_in_xact | closed
+-------------+-----------+-------+--------------+--------
+ loopback1 | postgres | t | t |
+ loopback2 | postgres | t | t |
</screen>
The output columns are described in
<xref linkend="postgres-fdw-get-connections-columns"/>.
@@ -836,6 +836,15 @@ OPTIONS (ADD password_required 'false');
invalid), this will be <literal>NULL</literal>.
</entry>
</row>
+ <row>
+ <entry><structfield>user_name</structfield></entry>
+ <entry><type>text</type></entry>
+ <entry>
+ The local user name of this connection. If the user mapping is
+ dropped but the connection remains open (i.e., marked as
+ invalid), this will be <literal>NULL</literal>.
+ </entry>
+ </row>
<row>
<entry><structfield>valid</structfield></entry>
<entry><type>boolean</type></entry>
--
2.43.0
On 2024/08/02 14:56, Hayato Kuroda (Fujitsu) wrote:
I moved the function to connection.c, which uses the SearchSysCache1().
I've tried both ways, and they worked well. One difference is that when we use
the extended ConnCacheEntry approach and the entry has been invalidated, we cannot
distinguish the reason. For example, in the below case, the entry is invalidated,
so the user_name of the output record will be NULL, whereas the user mapping is
actually still valid. We may be able to add the reason for invalidation, but
I'm not very motivated to modify the part.
Understood. Also thanks for updating the patch!
<term><function>postgres_fdw_get_connections(
IN check_conn boolean DEFAULT false, OUT server_name text,
OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
returns setof record</function></term>
In the documentation, this part should be updated to include the user_name output column.
+ <entry><structfield>user_name</structfield></entry>
+ <entry><type>text</type></entry>
+ <entry>
+ The local user name of this connection. If the user mapping is
+ dropped but the connection remains open (i.e., marked as
+ invalid), this will be <literal>NULL</literal>.
How about changing the first description to "Name of the local user mapped to the foreign server of this connection, or "public" if a public mapping is used." for more precision?
- server_name | valid | used_in_xact | closed
--------------+-------+--------------+--------
- loopback1 | t | t |
- loopback2 | f | t |
+ server_name | user_name | valid | used_in_xact | closed
+-------------+-----------+-------+--------------+--------
+ loopback1 | postgres | t | t |
+ loopback2 | postgres | t | t |
How about displaying the record with loopback2 and valid=false like the previous usage example?
+UserMapping *
+GetUserMappingByOid(Oid umid, bool missing_ok)
postgres_fdw doesn't need a generic function to return UserMapping. How about simplifying the function by removing unnecessary code, e.g., as follows?
----------
tp = SearchSysCache1(USERMAPPINGOID, ObjectIdGetDatum(umid));
if (!HeapTupleIsValid(tp))
nulls[i++] = true;
else
{
Oid userid = ((Form_pg_user_mapping) GETSTRUCT(tp))->userid;
values[i++] = CStringGetTextDatum(MappingUserName(userid));
ReleaseSysCache(tp);
}
----------
-ForeignTable *
-GetForeignTable(Oid relid);
-</programlisting>
-
- This function returns a <structname>ForeignTable</structname> object for
- the foreign table with the given OID. A
- <structname>ForeignTable</structname> object contains properties of the
- foreign table (see <filename>foreign/foreign.h</filename> for details).
- </para>
-
- <para>
-<programlisting>
Why did you remove these code? Just mistake?
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Dear Fujii-san,
Thanks for reviewing! PSA new version.
<term><function>postgres_fdw_get_connections(
IN check_conn boolean DEFAULT false, OUT server_name text,
OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
returns setof record</function></term>In the documentation, this part should be updated to include the user_name output
column.
Right, fixed.
+ <entry><structfield>user_name</structfield></entry> + <entry><type>text</type></entry> + <entry> + The local user name of this connection. If the user mapping is + dropped but the connection remains open (i.e., marked as + invalid), this will be <literal>NULL</literal>.How about changing the first description to "Name of the local user mapped to the
foreign server of this connection, or "public" if a public mapping is used." for more
precision?
Added. I ran Grammarly and it said OK.
- server_name | valid | used_in_xact | closed --------------+-------+--------------+-------- - loopback1 | t | t | - loopback2 | f | t | + server_name | user_name | valid | used_in_xact | closed +-------------+-----------+-------+--------------+-------- + loopback1 | postgres | t | t | + loopback2 | postgres | t | t |How about displaying the record with loopback2 and valid=false like the previous
usage example?
I did not done that be cause either of server_name or user_name is NULL and
it might be strange. But yes, the example should have more information.
Based on that, I added a tuple so that the example has below. Thought?
loopback1 - user is "postgres", valid
loopback2 - user is "public", valid
loopback3 - user is NULL, invalid
+UserMapping * +GetUserMappingByOid(Oid umid, bool missing_ok)postgres_fdw doesn't need a generic function to return UserMapping. How about
simplifying the function by removing unnecessary code, e.g., as follows?----------
tp = SearchSysCache1(USERMAPPINGOID, ObjectIdGetDatum(umid));
if (!HeapTupleIsValid(tp))
nulls[i++] = true;
else
{
Oid userid = ((Form_pg_user_mapping) GETSTRUCT(tp))->userid;
values[i++] = CStringGetTextDatum(MappingUserName(userid));
ReleaseSysCache(tp);
}
----------
Largely agreed, but some comments and Assertion() may be needed. Done.
-ForeignTable *
-GetForeignTable(Oid relid);
-</programlisting>
-
- This function returns a <structname>ForeignTable</structname> object
for
- the foreign table with the given OID. A
- <structname>ForeignTable</structname> object contains properties of
the
- foreign table (see <filename>foreign/foreign.h</filename> for details).
- </para>
-
- <para>
-<programlisting>Why did you remove these code? Just mistake?
Oh, my fault. I tried to remove GetUserMappingByOid() and the entry was also
Removed at that time. Restored.
Best regards,
Hayato Kuroda
FUJITSU LIMITED
Attachments:
v3-0001-Extend-postgres_fdw_get_connections-to-return-use.patchapplication/octet-stream; name=v3-0001-Extend-postgres_fdw_get_connections-to-return-use.patchDownload
From ec14a04ba860a449abe2d534f9b2f10308f4bb00 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Thu, 18 Jul 2024 10:11:03 +0000
Subject: [PATCH v3] Extend postgres_fdw_get_connections to return user name
---
contrib/postgres_fdw/connection.c | 57 +++++++++++++++----
.../postgres_fdw/expected/postgres_fdw.out | 16 +++---
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 3 +-
contrib/postgres_fdw/sql/postgres_fdw.sql | 8 ++-
doc/src/sgml/postgres-fdw.sgml | 22 +++++--
5 files changed, 80 insertions(+), 26 deletions(-)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 12d1fec0e8..2e5303eac1 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -1997,8 +1997,8 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
/* Number of output arguments (columns) for various API versions */
#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_1 2
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 4
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 4 /* maximum of above */
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 5
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 5 /* maximum of above */
/*
* Internal function used by postgres_fdw_get_connections variants.
@@ -2014,10 +2014,13 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
*
* For API version 1.2 and later, this function takes an input parameter
* to check a connection status and returns the following
- * additional values along with the two values from version 1.1:
+ * additional values along with the three values from version 1.1:
*
+ * - user_name - the local user name of the active connection. In case the
+ * user mapping is dropped but the connection is still active, then the
+ * user name will be NULL in the output.
* - used_in_xact - true if the connection is used in the current transaction.
- * - closed: true if the connection is closed.
+ * - closed - true if the connection is closed.
*
* No records are returned when there are no cached connections at all.
*/
@@ -2056,6 +2059,7 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
ForeignServer *server;
Datum values[POSTGRES_FDW_GET_CONNECTIONS_COLS] = {0};
bool nulls[POSTGRES_FDW_GET_CONNECTIONS_COLS] = {0};
+ int i = 0;
/* We only look for open remote connections */
if (!entry->conn)
@@ -2100,28 +2104,61 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
Assert(entry->conn && entry->xact_depth > 0 && entry->invalidated);
/* Show null, if no server name was found */
- nulls[0] = true;
+ nulls[i++] = true;
}
else
- values[0] = CStringGetTextDatum(server->servername);
+ values[i++] = CStringGetTextDatum(server->servername);
- values[1] = BoolGetDatum(!entry->invalidated);
+ if (api_version >= PGFDW_V1_2)
+ {
+ HeapTuple tp;
+
+ /* Use the system cache to obtain the user mapping */
+ tp = SearchSysCache1(USERMAPPINGOID, ObjectIdGetDatum(entry->key));
+
+ /*
+ * Just like in the foreign server case, user mappings can also be
+ * dropped in the current explicit transaction. Therefore, the
+ * similar check as in the server case is required.
+ */
+ if (!HeapTupleIsValid(tp))
+ {
+ /*
+ * If we reach here, this entry must have been invalidated in
+ * pgfdw_inval_callback, same as in the server case.
+ */
+ Assert(entry->conn && entry->xact_depth > 0 &&
+ entry->invalidated);
+
+ nulls[i++] = true;
+ }
+ else
+ {
+ Oid userid;
+
+ userid = ((Form_pg_user_mapping) GETSTRUCT(tp))->umuser;
+ values[i++] = CStringGetTextDatum(MappingUserName(userid));
+ ReleaseSysCache(tp);
+ }
+ }
+
+ values[i++] = BoolGetDatum(!entry->invalidated);
if (api_version >= PGFDW_V1_2)
{
bool check_conn = PG_GETARG_BOOL(0);
/* Is this connection used in the current transaction? */
- values[2] = BoolGetDatum(entry->xact_depth > 0);
+ values[i++] = BoolGetDatum(entry->xact_depth > 0);
/*
* If a connection status check is requested and supported, return
* whether the connection is closed. Otherwise, return NULL.
*/
if (check_conn && pgfdw_conn_checkable())
- values[3] = BoolGetDatum(pgfdw_conn_check(entry->conn) != 0);
+ values[i++] = BoolGetDatum(pgfdw_conn_check(entry->conn) != 0);
else
- nulls[3] = true;
+ nulls[i++] = true;
}
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index f3eb055e2c..f2bcd6aa98 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10472,13 +10472,15 @@ NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to user mapping for public on server loopback3
drop cascades to foreign table ft7
-- List all the existing cached connections. loopback and loopback3
--- should be output as invalid connections. Also the server name for
--- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid | used_in_xact | closed
--------------+-------+--------------+--------
- loopback | f | t |
- | f | t |
+-- should be output as invalid connections. Also the server name and user name
+-- for loopback3 should be NULL because both server and user mapping were
+-- dropped.
+SELECT server_name, user_name = CURRENT_USER as "user_name = CURRENT_USER", valid, used_in_xact, closed
+FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | user_name = CURRENT_USER | valid | used_in_xact | closed
+-------------+--------------------------+-------+--------------+--------
+ loopback | t | f | t |
+ | | f | t |
(2 rows)
-- The invalid connections get closed in pgfdw_xact_callback during commit.
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
index 0d406c6028..81aad4fcda 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -11,7 +11,8 @@ DROP FUNCTION postgres_fdw_get_connections ();
CREATE FUNCTION postgres_fdw_get_connections (
IN check_conn boolean DEFAULT false, OUT server_name text,
- OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
+ OUT user_name text, OUT valid boolean, OUT used_in_xact boolean,
+ OUT closed boolean)
RETURNS SETOF record
AS 'MODULE_PATHNAME', 'postgres_fdw_get_connections_1_2'
LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 0734716ad9..372fe6dad1 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3382,9 +3382,11 @@ SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
DROP SERVER loopback3 CASCADE;
-- List all the existing cached connections. loopback and loopback3
--- should be output as invalid connections. Also the server name for
--- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+-- should be output as invalid connections. Also the server name and user name
+-- for loopback3 should be NULL because both server and user mapping were
+-- dropped.
+SELECT server_name, user_name = CURRENT_USER as "user_name = CURRENT_USER", valid, used_in_xact, closed
+FROM postgres_fdw_get_connections() ORDER BY 1;
-- The invalid connections get closed in pgfdw_xact_callback during commit.
COMMIT;
-- All cached connections were closed while committing above xact, so no
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 90969f63ca..df39600998 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -779,7 +779,8 @@ OPTIONS (ADD password_required 'false');
<varlistentry>
<term><function>postgres_fdw_get_connections(
IN check_conn boolean DEFAULT false, OUT server_name text,
- OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
+ OUT user_name text, OUT valid boolean, OUT used_in_xact boolean,
+ OUT closed boolean)
returns setof record</function></term>
<listitem>
<para>
@@ -806,10 +807,11 @@ OPTIONS (ADD password_required 'false');
<para>
Example usage of the function:
<screen>
- server_name | valid | used_in_xact | closed
--------------+-------+--------------+--------
- loopback1 | t | t |
- loopback2 | f | t |
+ server_name | user_name | valid | used_in_xact | closed
+-------------+-----------+-------+--------------+--------
+ loopback1 | postgres | t | t | f
+ loopback2 | public | t | t | f
+ loopback3 | | f | t | f
</screen>
The output columns are described in
<xref linkend="postgres-fdw-get-connections-columns"/>.
@@ -836,6 +838,16 @@ OPTIONS (ADD password_required 'false');
invalid), this will be <literal>NULL</literal>.
</entry>
</row>
+ <row>
+ <entry><structfield>user_name</structfield></entry>
+ <entry><type>text</type></entry>
+ <entry>
+ Name of the local user mapped to the foreign server of this
+ connection, or "public" if a public mapping is used. If the user
+ mapping is dropped but the connection remains open (i.e., marked as
+ invalid), this will be <literal>NULL</literal>.
+ </entry>
+ </row>
<row>
<entry><structfield>valid</structfield></entry>
<entry><type>boolean</type></entry>
--
2.43.0
On 2024/08/08 11:38, Hayato Kuroda (Fujitsu) wrote:
Dear Fujii-san,
Thanks for reviewing! PSA new version.
Thanks for updating the patch! LGTM.
I made a couple of small adjustments and attached the updated version.
If that's ok, I'll go ahead and commit it.
+ Name of the local user mapped to the foreign server of this
+ connection, or "public" if a public mapping is used. If the user
I enclosed "public" with <literal> tag, i.e., <literal>public</literal>.
I did not done that be cause either of server_name or user_name is NULL and
it might be strange. But yes, the example should have more information.
Based on that, I added a tuple so that the example has below. Thought?loopback1 - user is "postgres", valid
loopback2 - user is "public", valid
loopback3 - user is NULL, invalid
LGTM.
Also I added the following to the example for clarity:
postgres=# SELECT * FROM postgres_fdw_get_connections(true);
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION
Attachments:
v4-0001-postgres_fdw-Extend-postgres_fdw_get_connections-.patchtext/plain; charset=UTF-8; name=v4-0001-postgres_fdw-Extend-postgres_fdw_get_connections-.patchDownload
From 1b50979b84d2f8718a3af41bd407a76a0d048ea6 Mon Sep 17 00:00:00 2001
From: Hayato Kuroda <kuroda.hayato@fujitsu.com>
Date: Thu, 18 Jul 2024 10:11:03 +0000
Subject: [PATCH v4] postgres_fdw: Extend postgres_fdw_get_connections to
return user name.
This commit adds a "user_name" output column to
the postgres_fdw_get_connections function, returning the name
of the local user mapped to the foreign server for each connection.
If a public mapping is used, it returns "public."
This helps identify postgres_fdw connections more easily,
such as determining which connections are invalid, closed,
or used within the current transaction.
No extension version bump is needed, as commit c297a47c5f
already handled it for v18~.
Author: Hayato Kuroda
Reviewed-by: Fujii Masao
Discussion: https://postgr.es/m/b492a935-6c7e-8c08-e485-3c1d64d7d10f@oss.nttdata.com
---
contrib/postgres_fdw/connection.c | 57 +++++++++++++++----
.../postgres_fdw/expected/postgres_fdw.out | 16 +++---
.../postgres_fdw/postgres_fdw--1.1--1.2.sql | 3 +-
contrib/postgres_fdw/sql/postgres_fdw.sql | 8 ++-
doc/src/sgml/postgres-fdw.sgml | 23 ++++++--
5 files changed, 81 insertions(+), 26 deletions(-)
diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c
index 12d1fec0e8..2e5303eac1 100644
--- a/contrib/postgres_fdw/connection.c
+++ b/contrib/postgres_fdw/connection.c
@@ -1997,8 +1997,8 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
/* Number of output arguments (columns) for various API versions */
#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_1 2
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 4
-#define POSTGRES_FDW_GET_CONNECTIONS_COLS 4 /* maximum of above */
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS_V1_2 5
+#define POSTGRES_FDW_GET_CONNECTIONS_COLS 5 /* maximum of above */
/*
* Internal function used by postgres_fdw_get_connections variants.
@@ -2014,10 +2014,13 @@ pgfdw_finish_abort_cleanup(List *pending_entries, List *cancel_requested,
*
* For API version 1.2 and later, this function takes an input parameter
* to check a connection status and returns the following
- * additional values along with the two values from version 1.1:
+ * additional values along with the three values from version 1.1:
*
+ * - user_name - the local user name of the active connection. In case the
+ * user mapping is dropped but the connection is still active, then the
+ * user name will be NULL in the output.
* - used_in_xact - true if the connection is used in the current transaction.
- * - closed: true if the connection is closed.
+ * - closed - true if the connection is closed.
*
* No records are returned when there are no cached connections at all.
*/
@@ -2056,6 +2059,7 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
ForeignServer *server;
Datum values[POSTGRES_FDW_GET_CONNECTIONS_COLS] = {0};
bool nulls[POSTGRES_FDW_GET_CONNECTIONS_COLS] = {0};
+ int i = 0;
/* We only look for open remote connections */
if (!entry->conn)
@@ -2100,28 +2104,61 @@ postgres_fdw_get_connections_internal(FunctionCallInfo fcinfo,
Assert(entry->conn && entry->xact_depth > 0 && entry->invalidated);
/* Show null, if no server name was found */
- nulls[0] = true;
+ nulls[i++] = true;
}
else
- values[0] = CStringGetTextDatum(server->servername);
+ values[i++] = CStringGetTextDatum(server->servername);
- values[1] = BoolGetDatum(!entry->invalidated);
+ if (api_version >= PGFDW_V1_2)
+ {
+ HeapTuple tp;
+
+ /* Use the system cache to obtain the user mapping */
+ tp = SearchSysCache1(USERMAPPINGOID, ObjectIdGetDatum(entry->key));
+
+ /*
+ * Just like in the foreign server case, user mappings can also be
+ * dropped in the current explicit transaction. Therefore, the
+ * similar check as in the server case is required.
+ */
+ if (!HeapTupleIsValid(tp))
+ {
+ /*
+ * If we reach here, this entry must have been invalidated in
+ * pgfdw_inval_callback, same as in the server case.
+ */
+ Assert(entry->conn && entry->xact_depth > 0 &&
+ entry->invalidated);
+
+ nulls[i++] = true;
+ }
+ else
+ {
+ Oid userid;
+
+ userid = ((Form_pg_user_mapping) GETSTRUCT(tp))->umuser;
+ values[i++] = CStringGetTextDatum(MappingUserName(userid));
+ ReleaseSysCache(tp);
+ }
+ }
+
+ values[i++] = BoolGetDatum(!entry->invalidated);
if (api_version >= PGFDW_V1_2)
{
bool check_conn = PG_GETARG_BOOL(0);
/* Is this connection used in the current transaction? */
- values[2] = BoolGetDatum(entry->xact_depth > 0);
+ values[i++] = BoolGetDatum(entry->xact_depth > 0);
/*
* If a connection status check is requested and supported, return
* whether the connection is closed. Otherwise, return NULL.
*/
if (check_conn && pgfdw_conn_checkable())
- values[3] = BoolGetDatum(pgfdw_conn_check(entry->conn) != 0);
+ values[i++] = BoolGetDatum(pgfdw_conn_check(entry->conn) != 0);
else
- nulls[3] = true;
+ nulls[i++] = true;
}
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out
index f3eb055e2c..f2bcd6aa98 100644
--- a/contrib/postgres_fdw/expected/postgres_fdw.out
+++ b/contrib/postgres_fdw/expected/postgres_fdw.out
@@ -10472,13 +10472,15 @@ NOTICE: drop cascades to 2 other objects
DETAIL: drop cascades to user mapping for public on server loopback3
drop cascades to foreign table ft7
-- List all the existing cached connections. loopback and loopback3
--- should be output as invalid connections. Also the server name for
--- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
- server_name | valid | used_in_xact | closed
--------------+-------+--------------+--------
- loopback | f | t |
- | f | t |
+-- should be output as invalid connections. Also the server name and user name
+-- for loopback3 should be NULL because both server and user mapping were
+-- dropped.
+SELECT server_name, user_name = CURRENT_USER as "user_name = CURRENT_USER", valid, used_in_xact, closed
+FROM postgres_fdw_get_connections() ORDER BY 1;
+ server_name | user_name = CURRENT_USER | valid | used_in_xact | closed
+-------------+--------------------------+-------+--------------+--------
+ loopback | t | f | t |
+ | | f | t |
(2 rows)
-- The invalid connections get closed in pgfdw_xact_callback during commit.
diff --git a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
index 0d406c6028..81aad4fcda 100644
--- a/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
+++ b/contrib/postgres_fdw/postgres_fdw--1.1--1.2.sql
@@ -11,7 +11,8 @@ DROP FUNCTION postgres_fdw_get_connections ();
CREATE FUNCTION postgres_fdw_get_connections (
IN check_conn boolean DEFAULT false, OUT server_name text,
- OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
+ OUT user_name text, OUT valid boolean, OUT used_in_xact boolean,
+ OUT closed boolean)
RETURNS SETOF record
AS 'MODULE_PATHNAME', 'postgres_fdw_get_connections_1_2'
LANGUAGE C STRICT PARALLEL RESTRICTED;
diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql
index 0734716ad9..372fe6dad1 100644
--- a/contrib/postgres_fdw/sql/postgres_fdw.sql
+++ b/contrib/postgres_fdw/sql/postgres_fdw.sql
@@ -3382,9 +3382,11 @@ SELECT server_name FROM postgres_fdw_get_connections() ORDER BY 1;
ALTER SERVER loopback OPTIONS (ADD use_remote_estimate 'off');
DROP SERVER loopback3 CASCADE;
-- List all the existing cached connections. loopback and loopback3
--- should be output as invalid connections. Also the server name for
--- loopback3 should be NULL because the server was dropped.
-SELECT * FROM postgres_fdw_get_connections() ORDER BY 1;
+-- should be output as invalid connections. Also the server name and user name
+-- for loopback3 should be NULL because both server and user mapping were
+-- dropped.
+SELECT server_name, user_name = CURRENT_USER as "user_name = CURRENT_USER", valid, used_in_xact, closed
+FROM postgres_fdw_get_connections() ORDER BY 1;
-- The invalid connections get closed in pgfdw_xact_callback during commit.
COMMIT;
-- All cached connections were closed while committing above xact, so no
diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml
index 468724e94e..627bb5ab5c 100644
--- a/doc/src/sgml/postgres-fdw.sgml
+++ b/doc/src/sgml/postgres-fdw.sgml
@@ -779,7 +779,8 @@ OPTIONS (ADD password_required 'false');
<varlistentry>
<term><function>postgres_fdw_get_connections(
IN check_conn boolean DEFAULT false, OUT server_name text,
- OUT valid boolean, OUT used_in_xact boolean, OUT closed boolean)
+ OUT user_name text, OUT valid boolean, OUT used_in_xact boolean,
+ OUT closed boolean)
returns setof record</function></term>
<listitem>
<para>
@@ -806,10 +807,12 @@ OPTIONS (ADD password_required 'false');
<para>
Example usage of the function:
<screen>
- server_name | valid | used_in_xact | closed
--------------+-------+--------------+--------
- loopback1 | t | t |
- loopback2 | f | t |
+postgres=# SELECT * FROM postgres_fdw_get_connections(true);
+ server_name | user_name | valid | used_in_xact | closed
+-------------+-----------+-------+--------------+--------
+ loopback1 | postgres | t | t | f
+ loopback2 | public | t | t | f
+ loopback3 | | f | t | f
</screen>
The output columns are described in
<xref linkend="postgres-fdw-get-connections-columns"/>.
@@ -836,6 +839,16 @@ OPTIONS (ADD password_required 'false');
invalid), this will be <literal>NULL</literal>.
</entry>
</row>
+ <row>
+ <entry><structfield>user_name</structfield></entry>
+ <entry><type>text</type></entry>
+ <entry>
+ Name of the local user mapped to the foreign server of this
+ connection, or <literal>public</literal> if a public mapping is used.
+ If the user mapping is dropped but the connection remains open
+ (i.e., marked as invalid), this will be <literal>NULL</literal>.
+ </entry>
+ </row>
<row>
<entry><structfield>valid</structfield></entry>
<entry><type>boolean</type></entry>
--
2.45.2
Dear Fujii-san,
Thanks for reviewing!
I made a couple of small adjustments and attached the updated version.
If that's ok, I'll go ahead and commit it.+ Name of the local user mapped to the foreign server of this + connection, or "public" if a public mapping is used. If the userI enclosed "public" with <literal> tag, i.e., <literal>public</literal>.
Right, it should be. I grepped sgml files just in case, but they are tagged by <literal>.
I did not done that be cause either of server_name or user_name is NULL and
it might be strange. But yes, the example should have more information.
Based on that, I added a tuple so that the example has below. Thought?loopback1 - user is "postgres", valid
loopback2 - user is "public", valid
loopback3 - user is NULL, invalidLGTM.
Also I added the following to the example for clarity:postgres=# SELECT * FROM postgres_fdw_get_connections(true);
+1.
Best regards,
Hayato Kuroda
FUJITSU LIMITED
Dear members,
(This mail is just a wrap-up)
I found that the final patch was pushed 2 days ago [1]https://github.com/postgres/postgres/commit/4f08ab55457751308ffd8d33e82155758cd0e304 and BF animals say OK for
now. Therefore, I've closed the CF entry as "committed". We can extend the
feature to other platforms, but I think it could be at another thread later.
Thanks everyone for many efforts!
[1]: https://github.com/postgres/postgres/commit/4f08ab55457751308ffd8d33e82155758cd0e304
Best regards,
Hayato Kuroda
FUJITSU LIMITED
On 2024/09/20 12:00, Hayato Kuroda (Fujitsu) wrote:
Dear members,
(This mail is just a wrap-up)
I found that the final patch was pushed 2 days ago [1] and BF animals say OK for
now. Therefore, I've closed the CF entry as "committed".
Thanks!
We can extend the
feature to other platforms, but I think it could be at another thread later.
Yes.
Thanks everyone for many efforts!
You, too! Many thanks!
Regards,
--
Fujii Masao
Advanced Computing Technology Center
Research and Development Headquarters
NTT DATA CORPORATION