diff --git a/contrib/postgres_fdw/connection.c b/contrib/postgres_fdw/connection.c index 9fa7f7e95cd1..8d18bdee6cae 100644 --- a/contrib/postgres_fdw/connection.c +++ b/contrib/postgres_fdw/connection.c @@ -843,6 +843,9 @@ do_sql_command_end(PGconn *conn, const char *sql, bool consume_input) * those scans. A disadvantage is that we can't provide sane emulation of * READ COMMITTED behavior --- it would be nice if we had some other way to * control which remote queries share a snapshot. + * + * Note that we always start remote transactions with the same read/write + * and deferrable properties as the local (top-level) transaction. */ static void begin_remote_xact(ConnCacheEntry *entry) @@ -852,17 +855,23 @@ begin_remote_xact(ConnCacheEntry *entry) /* Start main transaction if we haven't yet */ if (entry->xact_depth <= 0) { - const char *sql; + StringInfoData sql; elog(DEBUG3, "starting remote transaction on connection %p", entry->conn); + initStringInfo(&sql); + appendStringInfoString(&sql, "START TRANSACTION ISOLATION LEVEL "); if (IsolationIsSerializable()) - sql = "START TRANSACTION ISOLATION LEVEL SERIALIZABLE"; + appendStringInfoString(&sql, "SERIALIZABLE"); else - sql = "START TRANSACTION ISOLATION LEVEL REPEATABLE READ"; + appendStringInfoString(&sql, "REPEATABLE READ"); + if (TopTransactionIsReadOnly()) + appendStringInfoString(&sql, " READ ONLY"); + if (XactDeferrable) + appendStringInfoString(&sql, " DEFERRABLE"); entry->changing_xact_state = true; - do_sql_command(entry->conn, sql); + do_sql_command(entry->conn, sql.data); entry->xact_depth = 1; entry->changing_xact_state = false; } diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out index d1acee5a5fa5..84b907c1c1a3 100644 --- a/contrib/postgres_fdw/expected/postgres_fdw.out +++ b/contrib/postgres_fdw/expected/postgres_fdw.out @@ -12309,6 +12309,78 @@ SELECT count(*) FROM remote_application_name DROP FOREIGN TABLE remote_application_name; DROP VIEW my_application_name; -- =================================================================== +-- test read-only and/or deferrable transactions +-- =================================================================== +CREATE TABLE loct (f1 int, f2 text); +CREATE FUNCTION locf() RETURNS SETOF loct LANGUAGE SQL AS + 'UPDATE public.loct SET f2 = f2 || f2 RETURNING *'; +CREATE VIEW locv AS SELECT t.* FROM locf() t; +CREATE FOREIGN TABLE remt (f1 int, f2 text) + SERVER loopback OPTIONS (table_name 'locv'); +INSERT INTO loct VALUES (1, 'foo'), (2, 'bar'); +SELECT * FROM loct; + f1 | f2 +----+----- + 1 | foo + 2 | bar +(2 rows) + +SELECT * FROM remt; -- should work + f1 | f2 +----+-------- + 1 | foofoo + 2 | barbar +(2 rows) + +SELECT * FROM loct; + f1 | f2 +----+-------- + 1 | foofoo + 2 | barbar +(2 rows) + +START TRANSACTION READ ONLY; +SELECT * FROM remt; -- should fail +ERROR: cannot execute UPDATE in a read-only transaction +CONTEXT: SQL function "locf" statement 1 +remote SQL command: SELECT f1, f2 FROM public.locv +ROLLBACK; +DROP FOREIGN TABLE remt; +CREATE FOREIGN TABLE remt (f1 int, f2 text) + SERVER loopback OPTIONS (table_name 'loct'); +START TRANSACTION ISOLATION LEVEL SERIALIZABLE READ ONLY; +SELECT * FROM remt; + f1 | f2 +----+-------- + 1 | foofoo + 2 | barbar +(2 rows) + +COMMIT; +START TRANSACTION ISOLATION LEVEL SERIALIZABLE DEFERRABLE; +SELECT * FROM remt; + f1 | f2 +----+-------- + 1 | foofoo + 2 | barbar +(2 rows) + +COMMIT; +START TRANSACTION ISOLATION LEVEL SERIALIZABLE READ ONLY DEFERRABLE; +SELECT * FROM remt; + f1 | f2 +----+-------- + 1 | foofoo + 2 | barbar +(2 rows) + +COMMIT; +-- Clean up +DROP FOREIGN TABLE remt; +DROP VIEW locv; +DROP FUNCTION locf(); +DROP TABLE loct; +-- =================================================================== -- test parallel commit and parallel abort -- =================================================================== ALTER SERVER loopback OPTIONS (ADD parallel_commit 'true'); diff --git a/contrib/postgres_fdw/sql/postgres_fdw.sql b/contrib/postgres_fdw/sql/postgres_fdw.sql index ea6287b03fd9..d39b4a157919 100644 --- a/contrib/postgres_fdw/sql/postgres_fdw.sql +++ b/contrib/postgres_fdw/sql/postgres_fdw.sql @@ -4187,6 +4187,48 @@ SELECT count(*) FROM remote_application_name DROP FOREIGN TABLE remote_application_name; DROP VIEW my_application_name; +-- =================================================================== +-- test read-only and/or deferrable transactions +-- =================================================================== +CREATE TABLE loct (f1 int, f2 text); +CREATE FUNCTION locf() RETURNS SETOF loct LANGUAGE SQL AS + 'UPDATE public.loct SET f2 = f2 || f2 RETURNING *'; +CREATE VIEW locv AS SELECT t.* FROM locf() t; +CREATE FOREIGN TABLE remt (f1 int, f2 text) + SERVER loopback OPTIONS (table_name 'locv'); + +INSERT INTO loct VALUES (1, 'foo'), (2, 'bar'); +SELECT * FROM loct; + +SELECT * FROM remt; -- should work +SELECT * FROM loct; + +START TRANSACTION READ ONLY; +SELECT * FROM remt; -- should fail +ROLLBACK; + +DROP FOREIGN TABLE remt; +CREATE FOREIGN TABLE remt (f1 int, f2 text) + SERVER loopback OPTIONS (table_name 'loct'); + +START TRANSACTION ISOLATION LEVEL SERIALIZABLE READ ONLY; +SELECT * FROM remt; +COMMIT; + +START TRANSACTION ISOLATION LEVEL SERIALIZABLE DEFERRABLE; +SELECT * FROM remt; +COMMIT; + +START TRANSACTION ISOLATION LEVEL SERIALIZABLE READ ONLY DEFERRABLE; +SELECT * FROM remt; +COMMIT; + +-- Clean up +DROP FOREIGN TABLE remt; +DROP VIEW locv; +DROP FUNCTION locf(); +DROP TABLE loct; + -- =================================================================== -- test parallel commit and parallel abort -- =================================================================== diff --git a/doc/src/sgml/postgres-fdw.sgml b/doc/src/sgml/postgres-fdw.sgml index 781a01067f7d..863ac426e322 100644 --- a/doc/src/sgml/postgres-fdw.sgml +++ b/doc/src/sgml/postgres-fdw.sgml @@ -1077,6 +1077,22 @@ postgres=# SELECT postgres_fdw_disconnect_all(); PostgreSQL release might modify these rules. + + The remote transaction is opened in the same read/write mode as the local + transaction: if the local transaction has been declared + READ ONLY at the top level, the remote transaction is + opened in READ ONLY mode, otherwise it is opened in + READ WRITE mode. + + + + The remote transaction is also opened in the same deferrable mode as the + local transaction: if the local transaction has been declared + DEFERRABLE at the top level, the remote transaction is + opened in DEFERRABLE mode, otherwise it is opened in + NOT DEFERRABLE mode. + + Note that it is currently not supported by postgres_fdw to prepare the remote transaction for diff --git a/src/backend/access/transam/xact.c b/src/backend/access/transam/xact.c index b885513f7654..46a5b9f66aac 100644 --- a/src/backend/access/transam/xact.c +++ b/src/backend/access/transam/xact.c @@ -1044,6 +1044,27 @@ TransactionStartedDuringRecovery(void) return CurrentTransactionState->startedInRecovery; } +/* + * TopTransactionIsReadOnly + * + * Returns true if the transaction has been declared READ ONLY at the top + * level. + */ +bool +TopTransactionIsReadOnly(void) +{ + TransactionState s = CurrentTransactionState; + + if (s->nestingLevel == 1) + return XactReadOnly; + while (s->nestingLevel > 2) + { + Assert(s->parent != NULL); + s = s->parent; + } + return s->prevXactReadOnly; +} + /* * EnterParallelMode */ diff --git a/src/include/access/xact.h b/src/include/access/xact.h index b2bc10ee0419..0160eb1d91c4 100644 --- a/src/include/access/xact.h +++ b/src/include/access/xact.h @@ -458,6 +458,7 @@ extern TimestampTz GetCurrentTransactionStopTimestamp(void); extern void SetCurrentStatementStartTimestamp(void); extern int GetCurrentTransactionNestLevel(void); extern bool TransactionIdIsCurrentTransactionId(TransactionId xid); +extern bool TopTransactionIsReadOnly(void); extern void CommandCounterIncrement(void); extern void ForceSyncCommit(void); extern void StartTransactionCommand(void);